Expressions, functions, and operators

This page explains BigQuery expressions, including functions and operators.

Function call rules

The following rules apply to all functions unless explicitly indicated otherwise in the function description:

  • For functions that accept numeric types, if one operand is a floating point operand and the other operand is another numeric type, both operands are converted to FLOAT64 before the function is evaluated.
  • If an operand is NULL, the result is NULL, with the exception of the IS operator.
  • For functions that are time zone sensitive (as indicated in the function description), the default time zone, UTC, is used if a time zone is not specified.

SAFE. prefix

Syntax:

SAFE.function_name()

Description

If you begin a function with the SAFE. prefix, it will return NULL instead of an error. The SAFE. prefix only prevents errors from the prefixed function itself: it does not prevent errors that occur while evaluating argument expressions. The SAFE. prefix only prevents errors that occur because of the value of the function inputs, such as "value out of range" errors; other errors, such as internal or system errors, may still occur. If the function does not return an error, SAFE. has no effect on the output.

Operators, such as + and =, do not support the SAFE. prefix. To prevent errors from a division operation, use SAFE_DIVIDE. Some operators, such as IN, ARRAY, and UNNEST, resemble functions, but do not support the SAFE. prefix. The CAST and EXTRACT functions also do not support the SAFE. prefix. To prevent errors from casting, use SAFE_CAST.

Example

In the following example, the first use of the SUBSTR function would normally return an error, because the function does not support length arguments with negative values. However, the SAFE. prefix causes the function to return NULL instead. The second use of the SUBSTR function provides the expected output: the SAFE. prefix has no effect.

SELECT SAFE.SUBSTR('foo', 0, -2) AS safe_output UNION ALL
SELECT SAFE.SUBSTR('bar', 0, 2) AS safe_output;

+-------------+
| safe_output |
+-------------+
| NULL        |
| ba          |
+-------------+

Supported functions

BigQuery supports the use of the SAFE. prefix with most scalar functions that can raise errors, including STRING functions, math functions, DATE functions, DATETIME functions, and TIMESTAMP functions. BigQuery does not support the use of the SAFE. prefix with aggregate, analytic, or user-defined functions.

Calling persistent user-defined functions (UDFs)

After creating a persistent UDF, you can call it as you would any other function, prepended with the name of the dataset in which it is defined as a prefix.

Syntax

[`project_name`].dataset_name.function_name([parameter_value[, ...]])

To call a UDF in a project other than the project that you are using to run the query, project_name is required.

Examples

The following example creates a UDF named multiply_by_three and calls it from the same project.

CREATE FUNCTION my_dataset.multiply_by_three(x INT64) AS (x * 3);

SELECT my_dataset.multiply_by_three(5) AS result; -- returns 15

The following example calls a persistent UDF from a different project.


CREATE `other_project`.other_dataset.other_function(x INT64, y INT64)
  AS (x * y * 2);

SELECT `other_project`.other_dataset.other_function(3, 4); --returns 24

Conversion rules

Conversion includes, but is not limited to, casting, coercion, and supertyping.

  • Casting is explicit conversion and uses the CAST() function.
  • Coercion is implicit conversion, which BigQuery performs automatically under the conditions described below.
  • A supertype is a common type to which two or more expressions can be coerced.

There are also conversions that have their own function names, such as PARSE_DATE(). To learn more about these functions, see Conversion functions

Comparison of casting and coercion

The following table summarizes all possible cast and coercion possibilities for BigQuery data types. The Coerce to column applies to all expressions of a given data type, (for example, a column), but literals and parameters can also be coerced. See literal coercion and parameter coercion for details.

From type Cast to Coerce to
INT64 BOOL
INT64
NUMERIC
BIGNUMERIC
FLOAT64
STRING
NUMERIC
BIGNUMERIC
FLOAT64
NUMERIC INT64
NUMERIC
BIGNUMERIC
FLOAT64
STRING
BIGNUMERIC
FLOAT64
BIGNUMERIC INT64
NUMERIC
BIGNUMERIC
FLOAT64
STRING
FLOAT64
FLOAT64 INT64
NUMERIC
BIGNUMERIC
FLOAT64
STRING
 
BOOL BOOL
INT64
STRING
 
STRING BOOL
INT64
NUMERIC
BIGNUMERIC
FLOAT64
STRING
BYTES
DATE
DATETIME
TIME
TIMESTAMP
 
BYTES STRING
BYTES
 
DATE STRING
DATE
DATETIME
TIMESTAMP
DATETIME
DATETIME STRING
DATE
DATETIME
TIME
TIMESTAMP
 
TIME STRING
TIME
 
TIMESTAMP STRING
DATE
DATETIME
TIME
TIMESTAMP
 
ARRAY ARRAY  
STRUCT STRUCT  

Casting

Most data types can be cast from one type to another with the CAST function. When using CAST, a query can fail if BigQuery is unable to perform the cast. If you want to protect your queries from these types of errors, you can use SAFE_CAST. To learn more about the rules for CAST, SAFE_CAST and other casting functions, see Conversion functions.

Coercion

BigQuery coerces the result type of an argument expression to another type if needed to match function signatures. For example, if function func() is defined to take a single argument of type FLOAT64 and an expression is used as an argument that has a result type of INT64, then the result of the expression will be coerced to FLOAT64 type before func() is computed.

Literal coercion

BigQuery supports the following literal coercions:

Input data type Result data type Notes
STRING literal DATE
DATETIME
TIME
TIMESTAMP

Literal coercion is needed when the actual literal type is different from the type expected by the function in question. For example, if function func() takes a DATE argument, then the expression func("2014-09-27") is valid because the string literal "2014-09-27" is coerced to DATE.

Literal conversion is evaluated at analysis time, and gives an error if the input literal cannot be converted successfully to the target type.

Parameter coercion

BigQuery supports the following parameter coercions:

Input data type Result data type
STRING parameter DATE
DATETIME
TIME
TIMESTAMP

If the parameter value cannot be coerced successfully to the target type, an error is provided.

Supertypes

A supertype is a common type to which two or more expressions can be coerced. Supertypes are used with set operations such as UNION ALL and expressions such as CASE that expect multiple arguments with matching types. Each type has one or more supertypes, including itself, which defines its set of supertypes.

Input type Supertypes
BOOL BOOL
INT64 INT64
FLOAT64
NUMERIC
BIGNUMERIC
FLOAT64 FLOAT64
NUMERIC NUMERIC
BIGNUMERIC
FLOAT64
DECIMAL DECIMAL
BIGDECIMAL
FLOAT64
BIGNUMERIC BIGNUMERIC
FLOAT64
BIGDECIMAL BIGDECIMAL
FLOAT64
STRING STRING
DATE DATE
TIME TIME
DATETIME DATETIME
TIMESTAMP TIMESTAMP
BYTES BYTES
STRUCT STRUCT with the same field position types.
ARRAY ARRAY with the same element types.
GEOGRAPHY GEOGRAPHY

If you want to find the supertype for a set of input types, first determine the intersection of the set of supertypes for each input type. If that set is empty then the input types have no common supertype. If that set is non-empty, then the common supertype is generally the most specific type in that set. Generally, the most specific type is the type with the most restrictive domain.

Examples

Input types Common supertype Returns Notes
INT64
FLOAT64
FLOAT64 FLOAT64 If you apply supertyping to INT64 and FLOAT64, supertyping succeeds because they they share a supertype, FLOAT64.
INT64
BOOL
None Error If you apply supertyping to INT64 and BOOL, supertyping fails because they do not share a common supertype.

Exact and inexact types

Numeric types can be exact or inexact. For supertyping, if all of the input types are exact types, then the resulting supertype can only be an exact type.

The following table contains a list of exact and inexact numeric data types.

Exact types Inexact types
INT64
NUMERIC
BIGNUMERIC
FLOAT64

Examples

Input types Common supertype Returns Notes
INT64
FLOAT64
FLOAT64 FLOAT64 If supertyping is applied to INT64 and DOUBLE, supertyping succeeds because there are exact and inexact numeric types being supertyped.

Types specificity

Each type has a domain of values that it supports. A type with a narrow domain is more specific than a type with a wider domain. Exact types are more specific than inexact types because inexact types have a wider range of domain values that are supported than exact types. For example, INT64 is more specific than FLOAT64.

Supertypes and literals

Supertype rules for literals are more permissive than for normal expressions, and are consistent with implicit coercion rules. The following algorithm is used when the input set of types includes types related to literals:

  • If there exists non-literals in the set, find the set of common supertypes of the non-literals.
  • If there is at least one possible supertype, find the most specific type to which the remaining literal types can be implicitly coerced and return that supertype. Otherwise, there is no supertype.
  • If the set only contains types related to literals, compute the supertype of the literal types.
  • If all input types are related to NULL literals, then the resulting supertype is INT64.
  • If no common supertype is found, an error is produced.

Examples

Input types Common supertype Returns
INT64 literal
UINT64 expression
UINT64 UINT64
TIMESTAMP expression
STRING literal
TIMESTAMP TIMESTAMP
NULL literal
NULL literal
INT64 INT64
BOOL literal
TIMESTAMP literal
None Error

Aggregate functions

An aggregate function is a function that summarizes the rows of a group into a single value. COUNT, MIN and MAX are examples of aggregate functions.

SELECT COUNT(*) as total_count, COUNT(fruit) as non_null_count,
       MIN(fruit) as min, MAX(fruit) as max
FROM (SELECT NULL as fruit UNION ALL
      SELECT "apple" as fruit UNION ALL
      SELECT "pear" as fruit UNION ALL
      SELECT "orange" as fruit)

+-------------+----------------+-------+------+
| total_count | non_null_count | min   | max  |
+-------------+----------------+-------+------+
| 4           | 3              | apple | pear |
+-------------+----------------+-------+------+

When used in conjunction with a GROUP BY clause, the groups summarized typically have at least one row. When the associated SELECT has no GROUP BY clause or when certain aggregate function modifiers filter rows from the group to be summarized it is possible that the aggregate function needs to summarize an empty group. In this case, the COUNT and COUNTIF functions return 0, while all other aggregate functions return NULL.

The following sections describe the aggregate functions that BigQuery supports.

ANY_VALUE

ANY_VALUE(
  expression
)
[OVER (...)]

Description

Returns expression for some row chosen from the group. Which row is chosen is nondeterministic, not random. Returns NULL when the input produces no rows. Returns NULL when expression is NULL for all rows in the group.

ANY_VALUE behaves as if RESPECT NULLS is specified; Rows for which expression is NULL are considered and may be selected.

Supported Argument Types

Any

Optional Clause

OVER: Specifies a window. See Analytic Functions.

Returned Data Types

Matches the input data type.

Examples

SELECT ANY_VALUE(fruit) as any_value
FROM UNNEST(["apple", "banana", "pear"]) as fruit;

+-----------+
| any_value |
+-----------+
| apple     |
+-----------+
SELECT
  fruit,
  ANY_VALUE(fruit) OVER (ORDER BY LENGTH(fruit) ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) AS any_value
FROM UNNEST(["apple", "banana", "pear"]) as fruit;

+--------+-----------+
| fruit  | any_value |
+--------+-----------+
| pear   | pear      |
| apple  | pear      |
| banana | apple     |
+--------+-----------+

ARRAY_AGG

ARRAY_AGG(
  [DISTINCT]
  expression
  [{IGNORE|RESPECT} NULLS]
  [ORDER BY key [{ASC|DESC}] [, ... ]]
  [LIMIT n]
)
[OVER (...)]

Description

Returns an ARRAY of expression values.

Supported Argument Types

All data types except ARRAY.

Optional Clauses

The clauses are applied in the following order:

  1. OVER: Specifies a window. See Analytic Functions. This clause is currently incompatible with all other clauses within ARRAY_AGG().
  2. DISTINCT: Each distinct value of expression is aggregated only once into the result.
  3. IGNORE NULLS or RESPECT NULLS: If IGNORE NULLS is specified, the NULL values are excluded from the result. If RESPECT NULLS is specified, the NULL values are included in the result. If neither is specified, the NULL values are included in the result. An error is raised if an array in the final query result contains a NULL element.
  4. ORDER BY: Specifies the order of the values.
    • For each sort key, the default sort direction is ASC.
    • NULLs: In the context of the ORDER BY clause, NULLs are the minimum possible value; that is, NULLs appear first in ASC sorts and last in DESC sorts.
    • Floating point data types: see Floating Point Semantics on ordering and grouping.
    • If DISTINCT is also specified, then the sort key must be the same as expression.
    • If ORDER BY is not specified, the order of the elements in the output array is non-deterministic, which means you might receive a different result each time you use this function.
  5. LIMIT: Specifies the maximum number of expression inputs in the result. The limit n must be a constant INT64.

Returned Data Types

ARRAY

If there are zero input rows, this function returns NULL.

Examples

SELECT FORMAT("%T", ARRAY_AGG(x)) AS array_agg
FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x;

+-------------------------+
| array_agg               |
+-------------------------+
| [2, 1, -2, 3, -2, 1, 2] |
+-------------------------+
SELECT FORMAT("%T", ARRAY_AGG(DISTINCT x)) AS array_agg
FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x;

+---------------+
| array_agg     |
+---------------+
| [2, 1, -2, 3] |
+---------------+
SELECT FORMAT("%T", ARRAY_AGG(x IGNORE NULLS)) AS array_agg
FROM UNNEST([NULL, 1, -2, 3, -2, 1, NULL]) AS x;

+-------------------+
| array_agg         |
+-------------------+
| [1, -2, 3, -2, 1] |
+-------------------+
SELECT FORMAT("%T", ARRAY_AGG(x ORDER BY ABS(x))) AS array_agg
FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x;

+-------------------------+
| array_agg               |
+-------------------------+
| [1, 1, 2, -2, -2, 2, 3] |
+-------------------------+
SELECT FORMAT("%T", ARRAY_AGG(x LIMIT 5)) AS array_agg
FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x;

+-------------------+
| array_agg         |
+-------------------+
| [2, 1, -2, 3, -2] |
+-------------------+
SELECT FORMAT("%T", ARRAY_AGG(DISTINCT x IGNORE NULLS ORDER BY x LIMIT 2)) AS array_agg
FROM UNNEST([NULL, 1, -2, 3, -2, 1, NULL]) AS x;

+-----------+
| array_agg |
+-----------+
| [-2, 1]   |
+-----------+
SELECT
  x,
  FORMAT("%T", ARRAY_AGG(x) OVER (ORDER BY ABS(x))) AS array_agg
FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x;

+----+-------------------------+
| x  | array_agg               |
+----+-------------------------+
| 1  | [1, 1]                  |
| 1  | [1, 1]                  |
| 2  | [1, 1, 2, -2, -2, 2]    |
| -2 | [1, 1, 2, -2, -2, 2]    |
| -2 | [1, 1, 2, -2, -2, 2]    |
| 2  | [1, 1, 2, -2, -2, 2]    |
| 3  | [1, 1, 2, -2, -2, 2, 3] |
+----+-------------------------+

ARRAY_CONCAT_AGG

ARRAY_CONCAT_AGG(
  expression
  [ORDER BY key [{ASC|DESC}] [, ... ]]
  [LIMIT n]
)

Description

Concatenates elements from expression of type ARRAY, returning a single ARRAY as a result. This function ignores NULL input arrays, but respects the NULL elements in non-NULL input arrays (an error is raised, however, if an array in the final query result contains a NULL element).

Supported Argument Types

ARRAY

Optional Clauses

The clauses are applied in the following order:

  1. ORDER BY: Specifies the order of the values.
    • For each sort key, the default sort direction is ASC.
    • Array ordering is not supported, and thus the sort key cannot be the same as expression.
    • NULLs: In the context of the ORDER BY clause, NULLs are the minimum possible value; that is, NULLs appear first in ASC sorts and last in DESC sorts.
    • Floating point data types: see Floating Point Semantics on ordering and grouping.
    • If ORDER BY is not specified, the order of the elements in the output array is non-deterministic, which means you might receive a different result each time you use this function.
  2. LIMIT: Specifies the maximum number of expression inputs in the result. The limit applies to the number of input arrays, not the number of elements in the arrays. An empty array counts as 1. A NULL array is not counted. The limit n must be a constant INT64.

Returned Data Types

ARRAY

Returns NULL if there are zero input rows or expression evaluates to NULL for all rows.

Examples

SELECT FORMAT("%T", ARRAY_CONCAT_AGG(x)) AS array_concat_agg FROM (
  SELECT [NULL, 1, 2, 3, 4] AS x
  UNION ALL SELECT NULL
  UNION ALL SELECT [5, 6]
  UNION ALL SELECT [7, 8, 9]
);

+-----------------------------------+
| array_concat_agg                  |
+-----------------------------------+
| [NULL, 1, 2, 3, 4, 5, 6, 7, 8, 9] |
+-----------------------------------+
SELECT FORMAT("%T", ARRAY_CONCAT_AGG(x ORDER BY ARRAY_LENGTH(x))) AS array_concat_agg FROM (
  SELECT [1, 2, 3, 4] AS x
  UNION ALL SELECT [5, 6]
  UNION ALL SELECT [7, 8, 9]
);

+-----------------------------------+
| array_concat_agg                  |
+-----------------------------------+
| [5, 6, 7, 8, 9, 1, 2, 3, 4]       |
+-----------------------------------+
SELECT FORMAT("%T", ARRAY_CONCAT_AGG(x LIMIT 2)) AS array_concat_agg FROM (
  SELECT [1, 2, 3, 4] AS x
  UNION ALL SELECT [5, 6]
  UNION ALL SELECT [7, 8, 9]
);

+--------------------------+
| array_concat_agg         |
+--------------------------+
| [1, 2, 3, 4, 5, 6]       |
+--------------------------+
SELECT FORMAT("%T", ARRAY_CONCAT_AGG(x ORDER BY ARRAY_LENGTH(x) LIMIT 2)) AS array_concat_agg FROM (
  SELECT [1, 2, 3, 4] AS x
  UNION ALL SELECT [5, 6]
  UNION ALL SELECT [7, 8, 9]
);

+------------------+
| array_concat_agg |
+------------------+
| [5, 6, 7, 8, 9]  |
+------------------+

AVG

AVG(
  [DISTINCT]
  expression
)
[OVER (...)]

Description

Returns the average of non-NULL input values, or NaN if the input contains a NaN.

Supported Argument Types

Any numeric input type, such as INT64. Note that, for floating point input types, the return result is non-deterministic, which means you might receive a different result each time you use this function.

Optional Clauses

The clauses are applied in the following order:

  1. OVER: Specifies a window. See Analytic Functions. This clause is currently incompatible with all other clauses within AVG().
  2. DISTINCT: Each distinct value of expression is aggregated only once into the result.

Returned Data Types

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64

Examples

SELECT AVG(x) as avg
FROM UNNEST([0, 2, 4, 4, 5]) as x;

+-----+
| avg |
+-----+
| 3   |
+-----+
SELECT AVG(DISTINCT x) AS avg
FROM UNNEST([0, 2, 4, 4, 5]) AS x;

+------+
| avg  |
+------+
| 2.75 |
+------+
SELECT
  x,
  AVG(x) OVER (ORDER BY x ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) AS avg
FROM UNNEST([0, 2, NULL, 4, 4, 5]) AS x;

+------+------+
| x    | avg  |
+------+------+
| NULL | NULL |
| 0    | 0    |
| 2    | 1    |
| 4    | 3    |
| 4    | 4    |
| 5    | 4.5  |
+------+------+

BIT_AND

BIT_AND(
  expression
)

Description

Performs a bitwise AND operation on expression and returns the result.

Supported Argument Types

  • INT64

Returned Data Types

INT64

Examples

SELECT BIT_AND(x) as bit_and FROM UNNEST([0xF001, 0x00A1]) as x;

+---------+
| bit_and |
+---------+
| 1       |
+---------+

BIT_OR

BIT_OR(
  expression
)

Description

Performs a bitwise OR operation on expression and returns the result.

Supported Argument Types

  • INT64

Returned Data Types

INT64

Examples

SELECT BIT_OR(x) as bit_or FROM UNNEST([0xF001, 0x00A1]) as x;

+--------+
| bit_or |
+--------+
| 61601  |
+--------+

BIT_XOR

BIT_XOR(
  [DISTINCT]
  expression
)

Description

Performs a bitwise XOR operation on expression and returns the result.

Supported Argument Types

  • INT64

Optional Clause

DISTINCT: Each distinct value of expression is aggregated only once into the result.

Returned Data Types

INT64

Examples

SELECT BIT_XOR(x) AS bit_xor FROM UNNEST([5678, 1234]) AS x;

+---------+
| bit_xor |
+---------+
| 4860    |
+---------+
SELECT BIT_XOR(x) AS bit_xor FROM UNNEST([1234, 5678, 1234]) AS x;

+---------+
| bit_xor |
+---------+
| 5678    |
+---------+
SELECT BIT_XOR(DISTINCT x) AS bit_xor FROM UNNEST([1234, 5678, 1234]) AS x;

+---------+
| bit_xor |
+---------+
| 4860    |
+---------+

COUNT

1.

COUNT(*)  [OVER (...)]

2.

COUNT(
  [DISTINCT]
  expression
)
[OVER (...)]

Description

  1. Returns the number of rows in the input.
  2. Returns the number of rows with expression evaluated to any value other than NULL.

Supported Argument Types

expression can be any data type. If DISTINCT is present, expression can only be a data type that is groupable.

Optional Clauses

The clauses are applied in the following order:

  1. OVER: Specifies a window. See Analytic Functions.
  2. DISTINCT: Each distinct value of expression is aggregated only once into the result.

Return Data Types

INT64

Examples

You can use the COUNT function to return the number of rows in a table or the number of distinct values of an expression. For example:

SELECT
  COUNT(*) AS count_star,
  COUNT(DISTINCT x) AS count_dist_x
FROM UNNEST([1, 4, 4, 5]) AS x;

+------------+--------------+
| count_star | count_dist_x |
+------------+--------------+
| 4          | 3            |
+------------+--------------+
SELECT
  x,
  COUNT(*) OVER (PARTITION BY MOD(x, 3)) AS count_star,
  COUNT(DISTINCT x) OVER (PARTITION BY MOD(x, 3)) AS count_dist_x
FROM UNNEST([1, 4, 4, 5]) AS x;

+------+------------+--------------+
| x    | count_star | count_dist_x |
+------+------------+--------------+
| 1    | 3          | 2            |
| 4    | 3          | 2            |
| 4    | 3          | 2            |
| 5    | 1          | 1            |
+------+------------+--------------+
SELECT
  x,
  COUNT(*) OVER (PARTITION BY MOD(x, 3)) AS count_star,
  COUNT(x) OVER (PARTITION BY MOD(x, 3)) AS count_x
FROM UNNEST([1, 4, NULL, 4, 5]) AS x;

+------+------------+---------+
| x    | count_star | count_x |
+------+------------+---------+
| NULL | 1          | 0       |
| 1    | 3          | 3       |
| 4    | 3          | 3       |
| 4    | 3          | 3       |
| 5    | 1          | 1       |
+------+------------+---------+

If you want to count the number of distinct values of an expression for which a certain condition is satisfied, this is one recipe that you can use:

COUNT(DISTINCT IF(condition, expression, NULL))

Here, IF will return the value of expression if condition is TRUE, or NULL otherwise. The surrounding COUNT(DISTINCT ...) will ignore the NULL values, so it will count only the distinct values of expression for which condition is TRUE.

For example, to count the number of distinct positive values of x:

SELECT COUNT(DISTINCT IF(x > 0, x, NULL)) AS distinct_positive
FROM UNNEST([1, -2, 4, 1, -5, 4, 1, 3, -6, 1]) AS x;

+-------------------+
| distinct_positive |
+-------------------+
| 3                 |
+-------------------+

Or to count the number of distinct dates on which a certain kind of event occurred:

WITH Events AS (
  SELECT DATE '2021-01-01' AS event_date, 'SUCCESS' AS event_type
  UNION ALL
  SELECT DATE '2021-01-02' AS event_date, 'SUCCESS' AS event_type
  UNION ALL
  SELECT DATE '2021-01-02' AS event_date, 'FAILURE' AS event_type
  UNION ALL
  SELECT DATE '2021-01-03' AS event_date, 'SUCCESS' AS event_type
  UNION ALL
  SELECT DATE '2021-01-04' AS event_date, 'FAILURE' AS event_type
  UNION ALL
  SELECT DATE '2021-01-04' AS event_date, 'FAILURE' AS event_type
)
SELECT
  COUNT(DISTINCT IF(event_type = 'FAILURE', event_date, NULL))
    AS distinct_dates_with_failures
FROM Events;

+------------------------------+
| distinct_dates_with_failures |
+------------------------------+
| 2                            |
+------------------------------+

COUNTIF

COUNTIF(
  expression
)
[OVER (...)]

Description

Returns the count of TRUE values for expression. Returns 0 if there are zero input rows, or if expression evaluates to FALSE or NULL for all rows.

Since expression must be a BOOL, the form COUNTIF(DISTINCT ...) is not supported. This would not be useful: there is only one distinct value of TRUE. Usually when someone wants to combine COUNTIF and DISTINCT, they want to count the number of distinct values of an expression for which a certain condition is satisfied. One recipe to achieve this is the following:

COUNT(DISTINCT IF(condition, expression, NULL))

Note that this uses COUNT, not COUNTIF; the IF part has been moved inside. To learn more, see the examples for COUNT.

Supported Argument Types

BOOL

Optional Clause

OVER: Specifies a window. See Analytic Functions.

Return Data Types

INT64

Examples

SELECT COUNTIF(x<0) AS num_negative, COUNTIF(x>0) AS num_positive
FROM UNNEST([5, -2, 3, 6, -10, -7, 4, 0]) AS x;

+--------------+--------------+
| num_negative | num_positive |
+--------------+--------------+
| 3            | 4            |
+--------------+--------------+
SELECT
  x,
  COUNTIF(x<0) OVER (ORDER BY ABS(x) ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING) AS num_negative
FROM UNNEST([5, -2, 3, 6, -10, NULL, -7, 4, 0]) AS x;

+------+--------------+
| x    | num_negative |
+------+--------------+
| NULL | 0            |
| 0    | 1            |
| -2   | 1            |
| 3    | 1            |
| 4    | 0            |
| 5    | 0            |
| 6    | 1            |
| -7   | 2            |
| -10  | 2            |
+------+--------------+

LOGICAL_AND

LOGICAL_AND(
  expression
)

Description

Returns the logical AND of all non-NULL expressions. Returns NULL if there are zero input rows or expression evaluates to NULL for all rows.

Supported Argument Types

BOOL

Return Data Types

BOOL

Examples

SELECT LOGICAL_AND(x) AS logical_and FROM UNNEST([true, false, true]) AS x;

+-------------+
| logical_and |
+-------------+
| false       |
+-------------+

LOGICAL_OR

LOGICAL_OR(
  expression
)

Description

Returns the logical OR of all non-NULL expressions. Returns NULL if there are zero input rows or expression evaluates to NULL for all rows.

Supported Argument Types

BOOL

Return Data Types

BOOL

Examples

SELECT LOGICAL_OR(x) AS logical_or FROM UNNEST([true, false, true]) AS x;

+------------+
| logical_or |
+------------+
| true       |
+------------+

MAX

MAX(
  expression
)
[OVER (...)]

Description

Returns the maximum value of non-NULL expressions. Returns NULL if there are zero input rows or expression evaluates to NULL for all rows. Returns NaN if the input contains a NaN.

Supported Argument Types

Any orderable data type.

Optional Clause

OVER: Specifies a window. See Analytic Functions.

Return Data Types

Same as the data type used as the input values.

Examples

SELECT MAX(x) AS max
FROM UNNEST([8, 37, 4, 55]) AS x;

+-----+
| max |
+-----+
| 55  |
+-----+
SELECT x, MAX(x) OVER (PARTITION BY MOD(x, 2)) AS max
FROM UNNEST([8, NULL, 37, 4, NULL, 55]) AS x;

+------+------+
| x    | max  |
+------+------+
| NULL | NULL |
| NULL | NULL |
| 8    | 8    |
| 4    | 8    |
| 37   | 55   |
| 55   | 55   |
+------+------+

MIN

MIN(
  expression
)
[OVER (...)]

Description

Returns the minimum value of non-NULL expressions. Returns NULL if there are zero input rows or expression evaluates to NULL for all rows. Returns NaN if the input contains a NaN.

Supported Argument Types

Any orderable data type.

Optional Clause

OVER: Specifies a window. See Analytic Functions.

Return Data Types

Same as the data type used as the input values.

Examples

SELECT MIN(x) AS min
FROM UNNEST([8, 37, 4, 55]) AS x;

+-----+
| min |
+-----+
| 4   |
+-----+
SELECT x, MIN(x) OVER (PARTITION BY MOD(x, 2)) AS min
FROM UNNEST([8, NULL, 37, 4, NULL, 55]) AS x;

+------+------+
| x    | min  |
+------+------+
| NULL | NULL |
| NULL | NULL |
| 8    | 4    |
| 4    | 4    |
| 37   | 37   |
| 55   | 37   |
+------+------+

STRING_AGG

STRING_AGG(
  [DISTINCT]
  expression [, delimiter]
  [ORDER BY key [{ASC|DESC}] [, ... ]]
  [LIMIT n]
)
[OVER (...)]

Description

Returns a value (either STRING or BYTES) obtained by concatenating non-null values. Returns NULL if there are zero input rows or expression evaluates to NULL for all rows.

If a delimiter is specified, concatenated values are separated by that delimiter; otherwise, a comma is used as a delimiter.

Supported Argument Types

STRING BYTES

Optional Clauses

The clauses are applied in the following order:

  1. OVER: Specifies a window. See Analytic Functions. This clause is currently incompatible with all other clauses within STRING_AGG().
  2. DISTINCT: Each distinct value of expression is aggregated only once into the result.
  3. ORDER BY: Specifies the order of the values.
    • For each sort key, the default sort direction is ASC.
    • NULLs: In the context of the ORDER BY clause, NULLs are the minimum possible value; that is, NULLs appear first in ASC sorts and last in DESC sorts.
    • Floating point data types: see Floating Point Semantics on ordering and grouping.
    • If DISTINCT is also specified, then the sort key must be the same as expression.
    • If ORDER BY is not specified, the order of the elements in the output array is non-deterministic, which means you might receive a different result each time you use this function.
  4. LIMIT: Specifies the maximum number of expression inputs in the result. The limit applies to the number of input strings, not the number of characters or bytes in the inputs. An empty string counts as 1. A NULL string is not counted. The limit n must be a constant INT64.

Return Data Types

STRING BYTES

Examples

SELECT STRING_AGG(fruit) AS string_agg
FROM UNNEST(["apple", NULL, "pear", "banana", "pear"]) AS fruit;

+------------------------+
| string_agg             |
+------------------------+
| apple,pear,banana,pear |
+------------------------+
SELECT STRING_AGG(fruit, " & ") AS string_agg
FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit;

+------------------------------+
| string_agg                   |
+------------------------------+
| apple & pear & banana & pear |
+------------------------------+
SELECT STRING_AGG(DISTINCT fruit, " & ") AS string_agg
FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit;

+-----------------------+
| string_agg            |
+-----------------------+
| apple & pear & banana |
+-----------------------+
SELECT STRING_AGG(fruit, " & " ORDER BY LENGTH(fruit)) AS string_agg
FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit;

+------------------------------+
| string_agg                   |
+------------------------------+
| pear & pear & apple & banana |
+------------------------------+
SELECT STRING_AGG(fruit, " & " LIMIT 2) AS string_agg
FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit;

+--------------+
| string_agg   |
+--------------+
| apple & pear |
+--------------+
SELECT STRING_AGG(DISTINCT fruit, " & " ORDER BY fruit DESC LIMIT 2) AS string_agg
FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit;

+---------------+
| string_agg    |
+---------------+
| pear & banana |
+---------------+
SELECT
  fruit,
  STRING_AGG(fruit, " & ") OVER (ORDER BY LENGTH(fruit)) AS string_agg
FROM UNNEST(["apple", NULL, "pear", "banana", "pear"]) AS fruit;

+--------+------------------------------+
| fruit  | string_agg                   |
+--------+------------------------------+
| NULL   | NULL                         |
| pear   | pear & pear                  |
| pear   | pear & pear                  |
| apple  | pear & pear & apple          |
| banana | pear & pear & apple & banana |
+--------+------------------------------+

SUM

SUM(
  [DISTINCT]
  expression
)
[OVER (...)]

Description

Returns the sum of non-null values.

If the expression is a floating point value, the sum is non-deterministic, which means you might receive a different result each time you use this function.

Supported Argument Types

Any supported numeric data types and INTERVAL.

Optional Clauses

The clauses are applied in the following order:

  1. OVER: Specifies a window. See Analytic Functions.
  2. DISTINCT: Each distinct value of expression is aggregated only once into the result.

Return Data Types

INPUTINT64NUMERICBIGNUMERICFLOAT64INTERVAL
OUTPUTINT64NUMERICBIGNUMERICFLOAT64INTERVAL

Special cases:

Returns NULL if the input contains only NULLs.

Returns NULL if the input contains no rows.

Returns Inf if the input contains Inf.

Returns -Inf if the input contains -Inf.

Returns NaN if the input contains a NaN.

Returns NaN if the input contains a combination of Inf and -Inf.

Examples

SELECT SUM(x) AS sum
FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x;

+-----+
| sum |
+-----+
| 25  |
+-----+
SELECT SUM(DISTINCT x) AS sum
FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x;

+-----+
| sum |
+-----+
| 15  |
+-----+
SELECT
  x,
  SUM(x) OVER (PARTITION BY MOD(x, 3)) AS sum
FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x;

+---+-----+
| x | sum |
+---+-----+
| 3 | 6   |
| 3 | 6   |
| 1 | 10  |
| 4 | 10  |
| 4 | 10  |
| 1 | 10  |
| 2 | 9   |
| 5 | 9   |
| 2 | 9   |
+---+-----+
SELECT
  x,
  SUM(DISTINCT x) OVER (PARTITION BY MOD(x, 3)) AS sum
FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x;

+---+-----+
| x | sum |
+---+-----+
| 3 | 3   |
| 3 | 3   |
| 1 | 5   |
| 4 | 5   |
| 4 | 5   |
| 1 | 5   |
| 2 | 7   |
| 5 | 7   |
| 2 | 7   |
+---+-----+
SELECT SUM(x) AS sum
FROM UNNEST([]) AS x;

+------+
| sum  |
+------+
| NULL |
+------+

Statistical aggregate functions

BigQuery supports the following statistical aggregate functions.

CORR

CORR(
  X1, X2
)
[OVER (...)]

Description

Returns the Pearson coefficient of correlation of a set of number pairs. For each number pair, the first number is the dependent variable and the second number is the independent variable. The return result is between -1 and 1. A result of 0 indicates no correlation.

All numeric types are supported. If the input is NUMERIC or BIGNUMERIC then the internal aggregation is stable with the final output converted to a FLOAT64. Otherwise the input is converted to a FLOAT64 before aggregation, resulting in a potentially unstable result.

This function ignores any input pairs that contain one or more NULL values. If there are fewer than two input pairs without NULL values, this function returns NULL.

Optional Clause

OVER: Specifies a window. See Analytic Functions.

Return Data Type

FLOAT64

COVAR_POP

COVAR_POP(
  X1, X2
)
[OVER (...)]

Description

Returns the population covariance of a set of number pairs. The first number is the dependent variable; the second number is the independent variable. The return result is between -Inf and +Inf.

All numeric types are supported. If the input is NUMERIC or BIGNUMERIC then the internal aggregation is stable with the final output converted to a FLOAT64. Otherwise the input is converted to a FLOAT64 before aggregation, resulting in a potentially unstable result.

This function ignores any input pairs that contain one or more NULL values. If there is no input pair without NULL values, this function returns NULL. If there is exactly one input pair without NULL values, this function returns 0.

Optional Clause

OVER: Specifies a window. See Analytic Functions.

Return Data Type

FLOAT64

COVAR_SAMP

COVAR_SAMP(
  X1, X2
)
[OVER (...)]

Description

Returns the sample covariance of a set of number pairs. The first number is the dependent variable; the second number is the independent variable. The return result is between -Inf and +Inf.

All numeric types are supported. If the input is NUMERIC or BIGNUMERIC then the internal aggregation is stable with the final output converted to a FLOAT64. Otherwise the input is converted to a FLOAT64 before aggregation, resulting in a potentially unstable result.

This function ignores any input pairs that contain one or more NULL values. If there are fewer than two input pairs without NULL values, this function returns NULL.

Optional Clause

OVER: Specifies a window. See Analytic Functions.

Return Data Type

FLOAT64

STDDEV_POP

STDDEV_POP(
  [DISTINCT]
  expression
)
[OVER (...)]

Description

Returns the population (biased) standard deviation of the values. The return result is between 0 and +Inf.

All numeric types are supported. If the input is NUMERIC or BIGNUMERIC then the internal aggregation is stable with the final output converted to a FLOAT64. Otherwise the input is converted to a FLOAT64 before aggregation, resulting in a potentially unstable result.

This function ignores any NULL inputs. If all inputs are ignored, this function returns NULL.

If this function receives a single non-NULL input, it returns 0.

Optional Clauses

The clauses are applied in the following order:

  1. OVER: Specifies a window. See Analytic Functions. This clause is currently incompatible with all other clauses within STDDEV_POP().
  2. DISTINCT: Each distinct value of expression is aggregated only once into the result.

Return Data Type

FLOAT64

STDDEV_SAMP

STDDEV_SAMP(
  [DISTINCT]
  expression
)
[OVER (...)]

Description

Returns the sample (unbiased) standard deviation of the values. The return result is between 0 and +Inf.

All numeric types are supported. If the input is NUMERIC or BIGNUMERIC then the internal aggregation is stable with the final output converted to a FLOAT64. Otherwise the input is converted to a FLOAT64 before aggregation, resulting in a potentially unstable result.

This function ignores any NULL inputs. If there are fewer than two non-NULL inputs, this function returns NULL.

Optional Clauses

The clauses are applied in the following order:

  1. OVER: Specifies a window. See Analytic Functions. This clause is currently incompatible with all other clauses within STDDEV_SAMP().
  2. DISTINCT: Each distinct value of expression is aggregated only once into the result.

Return Data Type

FLOAT64

STDDEV

STDDEV(
  [DISTINCT]
  expression
)
[OVER (...)]

Description

An alias of STDDEV_SAMP.

VAR_POP

VAR_POP(
  [DISTINCT]
  expression
)
[OVER (...)]

Description

Returns the population (biased) variance of the values. The return result is between 0 and +Inf.

All numeric types are supported. If the input is NUMERIC or BIGNUMERIC then the internal aggregation is stable with the final output converted to a FLOAT64. Otherwise the input is converted to a FLOAT64 before aggregation, resulting in a potentially unstable result.

This function ignores any NULL inputs. If all inputs are ignored, this function returns NULL.

If this function receives a single non-NULL input, it returns 0.

Optional Clauses

The clauses are applied in the following order:

  1. OVER: Specifies a window. See Analytic Functions. This clause is currently incompatible with all other clauses within VAR_POP().
  2. DISTINCT: Each distinct value of expression is aggregated only once into the result.

Return Data Type

FLOAT64

VAR_SAMP

VAR_SAMP(
  [DISTINCT]
  expression
)
[OVER (...)]

Description

Returns the sample (unbiased) variance of the values. The return result is between 0 and +Inf.

All numeric types are supported. If the input is NUMERIC or BIGNUMERIC then the internal aggregation is stable with the final output converted to a FLOAT64. Otherwise the input is converted to a FLOAT64 before aggregation, resulting in a potentially unstable result.

This function ignores any NULL inputs. If there are fewer than two non-NULL inputs, this function returns NULL.

Optional Clauses

The clauses are applied in the following order:

  1. OVER: Specifies a window. See Analytic Functions. This clause is currently incompatible with all other clauses within VAR_SAMP().
  2. DISTINCT: Each distinct value of expression is aggregated only once into the result.

Return Data Type

FLOAT64

VARIANCE

VARIANCE(
  [DISTINCT]
  expression
)
[OVER (...)]

Description

An alias of VAR_SAMP.

Approximate aggregate functions

Approximate aggregate functions are scalable in terms of memory usage and time, but produce approximate results instead of exact results. These functions typically require less memory than exact aggregation functions like COUNT(DISTINCT ...), but also introduce statistical uncertainty. This makes approximate aggregation appropriate for large data streams for which linear memory usage is impractical, as well as for data that is already approximate.

The approximate aggregate functions in this section work directly on the input data, rather than an intermediate estimation of the data. These functions do not allow users to specify the precision for the estimation with sketches. If you would like specify precision with sketches, see:

APPROX_COUNT_DISTINCT

APPROX_COUNT_DISTINCT(
  expression
)

Description

Returns the approximate result for COUNT(DISTINCT expression). The value returned is a statistical estimate—not necessarily the actual value.

This function is less accurate than COUNT(DISTINCT expression), but performs better on huge input.

Supported Argument Types

Any data type except: ARRAY STRUCT

Returned Data Types

INT64

Examples

SELECT APPROX_COUNT_DISTINCT(x) as approx_distinct
FROM UNNEST([0, 1, 1, 2, 3, 5]) as x;

+-----------------+
| approx_distinct |
+-----------------+
| 5               |
+-----------------+

APPROX_QUANTILES

APPROX_QUANTILES(
  [DISTINCT]
  expression, number
  [{IGNORE|RESPECT} NULLS]
)

Description

Returns the approximate boundaries for a group of expression values, where number represents the number of quantiles to create. This function returns an array of number + 1 elements, where the first element is the approximate minimum and the last element is the approximate maximum.

Supported Argument Types

expression can be any supported data type except: ARRAY STRUCT

number must be INT64.

Optional Clauses

The clauses are applied in the following order:

  1. DISTINCT: Each distinct value of expression is aggregated only once into the result.
  2. IGNORE NULLS or RESPECT NULLS: If IGNORE NULLS is specified, the NULL values are excluded from the result. If RESPECT NULLS is specified, the NULL values are included in the result. If neither is specified, the NULL values are excluded from the result. An error is raised if an array in the final query result contains a NULL element.

Returned Data Types

An ARRAY of the type specified by the expression parameter.

Returns NULL if there are zero input rows or expression evaluates to NULL for all rows.

Examples

SELECT APPROX_QUANTILES(x, 2) AS approx_quantiles
FROM UNNEST([1, 1, 1, 4, 5, 6, 7, 8, 9, 10]) AS x;

+------------------+
| approx_quantiles |
+------------------+
| [1, 5, 10]       |
+------------------+
SELECT APPROX_QUANTILES(x, 100)[OFFSET(90)] AS percentile_90
FROM UNNEST([1, 2, 3, 4, 5, 6, 7, 8, 9, 10]) AS x;

+---------------+
| percentile_90 |
+---------------+
| 9             |
+---------------+
SELECT APPROX_QUANTILES(DISTINCT x, 2) AS approx_quantiles
FROM UNNEST([1, 1, 1, 4, 5, 6, 7, 8, 9, 10]) AS x;

+------------------+
| approx_quantiles |
+------------------+
| [1, 6, 10]       |
+------------------+
SELECT FORMAT("%T", APPROX_QUANTILES(x, 2 RESPECT NULLS)) AS approx_quantiles
FROM UNNEST([NULL, NULL, 1, 1, 1, 4, 5, 6, 7, 8, 9, 10]) AS x;

+------------------+
| approx_quantiles |
+------------------+
| [NULL, 4, 10]    |
+------------------+
SELECT FORMAT("%T", APPROX_QUANTILES(DISTINCT x, 2 RESPECT NULLS)) AS approx_quantiles
FROM UNNEST([NULL, NULL, 1, 1, 1, 4, 5, 6, 7, 8, 9, 10]) AS x;

+------------------+
| approx_quantiles |
+------------------+
| [NULL, 6, 10]    |
+------------------+

APPROX_TOP_COUNT

APPROX_TOP_COUNT(
  expression, number
)

Description

Returns the approximate top elements of expression. The number parameter specifies the number of elements returned.

Supported Argument Types

expression can be of any data type that the GROUP BY clause supports.

number must be INT64.

Returned Data Types

An ARRAY of type STRUCT. The STRUCT contains two fields. The first field (named value) contains an input value. The second field (named count) contains an INT64 specifying the number of times the value was returned.

Returns NULL if there are zero input rows.

Examples

SELECT APPROX_TOP_COUNT(x, 2) as approx_top_count
FROM UNNEST(["apple", "apple", "pear", "pear", "pear", "banana"]) as x;

+-------------------------+
| approx_top_count        |
+-------------------------+
| [{pear, 3}, {apple, 2}] |
+-------------------------+

NULL handling

APPROX_TOP_COUNT does not ignore NULLs in the input. For example:

SELECT APPROX_TOP_COUNT(x, 2) as approx_top_count
FROM UNNEST([NULL, "pear", "pear", "pear", "apple", NULL]) as x;

+------------------------+
| approx_top_count       |
+------------------------+
| [{pear, 3}, {NULL, 2}] |
+------------------------+

APPROX_TOP_SUM

APPROX_TOP_SUM(
  expression, weight, number
)

Description

Returns the approximate top elements of expression, based on the sum of an assigned weight. The number parameter specifies the number of elements returned.

If the weight input is negative or NaN, this function returns an error.

Supported Argument Types

expression can be of any data type that the GROUP BY clause supports.

weight must be one of the following:

  • INT64
  • NUMERIC
  • BIGNUMERIC
  • FLOAT64

number must be INT64.

Returned Data Types

An ARRAY of type STRUCT. The STRUCT contains two fields: value and sum. The value field contains the value of the input expression. The sum field is the same type as weight, and is the approximate sum of the input weight associated with the value field.

Returns NULL if there are zero input rows.

Examples

SELECT APPROX_TOP_SUM(x, weight, 2) AS approx_top_sum FROM
UNNEST([
  STRUCT("apple" AS x, 3 AS weight),
  ("pear", 2),
  ("apple", 0),
  ("banana", 5),
  ("pear", 4)
]);

+--------------------------+
| approx_top_sum           |
+--------------------------+
| [{pear, 6}, {banana, 5}] |
+--------------------------+

NULL handling

APPROX_TOP_SUM does not ignore NULL values for the expression and weight parameters.

SELECT APPROX_TOP_SUM(x, weight, 2) AS approx_top_sum FROM
UNNEST([STRUCT("apple" AS x, NULL AS weight), ("pear", 0), ("pear", NULL)]);

+----------------------------+
| approx_top_sum             |
+----------------------------+
| [{pear, 0}, {apple, NULL}] |
+----------------------------+
SELECT APPROX_TOP_SUM(x, weight, 2) AS approx_top_sum FROM
UNNEST([STRUCT("apple" AS x, 0 AS weight), (NULL, 2)]);

+-------------------------+
| approx_top_sum          |
+-------------------------+
| [{NULL, 2}, {apple, 0}] |
+-------------------------+
SELECT APPROX_TOP_SUM(x, weight, 2) AS approx_top_sum FROM
UNNEST([STRUCT("apple" AS x, 0 AS weight), (NULL, NULL)]);

+----------------------------+
| approx_top_sum             |
+----------------------------+
| [{apple, 0}, {NULL, NULL}] |
+----------------------------+

HyperLogLog++ functions

The HyperLogLog++ algorithm (HLL++) estimates cardinality from sketches. If you do not want to work with sketches and do not need customized precision, consider using approximate aggregate functions with system-defined precision.

HLL++ functions are approximate aggregate functions. Approximate aggregation typically requires less memory than exact aggregation functions, like COUNT(DISTINCT), but also introduces statistical uncertainty. This makes HLL++ functions appropriate for large data streams for which linear memory usage is impractical, as well as for data that is already approximate.

BigQuery supports the following HLL++ functions:

HLL_COUNT.INIT

HLL_COUNT.INIT(input [, precision])

Description

An aggregate function that takes one or more input values and aggregates them into a HLL++ sketch. Each sketch is represented using the BYTES data type. You can then merge sketches using HLL_COUNT.MERGE or HLL_COUNT.MERGE_PARTIAL. If no merging is needed, you can extract the final count of distinct values from the sketch using HLL_COUNT.EXTRACT.

This function supports an optional parameter, precision. This parameter defines the accuracy of the estimate at the cost of additional memory required to process the sketches or store them on disk. The following table shows the allowed precision values, the maximum sketch size per group, and confidence interval (CI) of typical precisions:

Precision Max. Sketch Size (KiB) 65% CI 95% CI 99% CI
10 1 ±3.25% ±6.50% ±9.75%
11 2 ±2.30% ±4.60% ±6.89%
12 4 ±1.63% ±3.25% ±4.88%
13 8 ±1.15% ±2.30% ±3.45%
14 16 ±0.81% ±1.63% ±2.44%
15 (default) 32 ±0.57% ±1.15% ±1.72%
16 64 ±0.41% ±0.81% ±1.22%
17 128 ±0.29% ±0.57% ±0.86%
18 256 ±0.20% ±0.41% ±0.61%
19 512 ±0.14% ±0.29% ±0.43%
20 1024 ±0.10% ±0.20% ±0.30%
21 2048 ±0.07% ±0.14% ±0.22%
22 4096 ±0.05% ±0.10% ±0.15%
23 8192 ±0.04% ±0.07% ±0.11%
24 16384 ±0.03% ±0.05% ±0.08%

If the input is NULL, this function returns NULL.

For more information, see HyperLogLog in Practice: Algorithmic Engineering of a State of The Art Cardinality Estimation Algorithm.

Supported input types

  • INT64
  • NUMERIC
  • BIGNUMERIC
  • STRING
  • BYTES

Return type

BYTES

Example

SELECT
  HLL_COUNT.INIT(respondent) AS respondents_hll,
  flavor,
  country
FROM UNNEST([
  STRUCT(1 AS respondent, "Vanilla" AS flavor, "CH" AS country),
  (1, "Chocolate", "CH"),
  (2, "Chocolate", "US"),
  (2, "Strawberry", "US")])
GROUP BY flavor, country;

HLL_COUNT.MERGE

HLL_COUNT.MERGE(sketch)

Description

An aggregate function that returns the cardinality of several HLL++ set sketches by computing their union.

Each sketch must be initialized on the same type. Attempts to merge sketches for different types results in an error. For example, you cannot merge a sketch initialized from INT64 data with one initialized from STRING data.

If the merged sketches were initialized with different precisions, the precision will be downgraded to the lowest precision involved in the merge.

This function ignores NULL values when merging sketches. If the merge happens over zero rows or only over NULL values, the function returns 0.

Supported input types

BYTES

Return type

INT64

Example

SELECT HLL_COUNT.MERGE(respondents_hll) AS num_respondents, flavor
FROM (
  SELECT
    HLL_COUNT.INIT(respondent) AS respondents_hll,
    flavor,
    country
  FROM UNNEST([
    STRUCT(1 AS respondent, "Vanilla" AS flavor, "CH" AS country),
    (1, "Chocolate", "CH"),
    (2, "Chocolate", "US"),
    (2, "Strawberry", "US")])
  GROUP BY flavor, country)
GROUP BY flavor;

HLL_COUNT.MERGE_PARTIAL

HLL_COUNT.MERGE_PARTIAL(sketch)

Description

An aggregate function that takes one or more HLL++ sketch inputs and merges them into a new sketch.

Each sketch must be initialized on the same type. Attempts to merge sketches for different types results in an error. For example, you cannot merge a sketch initialized from INT64 data with one initialized from STRING data.

If the merged sketches were initialized with different precisions, the precision will be downgraded to the lowest precision involved in the merge. For example, if MERGE_PARTIAL encounters sketches of precision 14 and 15, the returned new sketch will have precision 14.

This function returns NULL if there is no input or all inputs are NULL.

Supported input types

BYTES

Return type

BYTES

Example

SELECT HLL_COUNT.MERGE_PARTIAL(respondents_hll) AS num_respondents, flavor
FROM (
  SELECT
    HLL_COUNT.INIT(respondent) AS respondents_hll,
    flavor,
    country
  FROM UNNEST([
    STRUCT(1 AS respondent, "Vanilla" AS flavor, "CH" AS country),
    (1, "Chocolate", "CH"),
    (2, "Chocolate", "US"),
    (2, "Strawberry", "US")])
  GROUP BY flavor, country)
GROUP BY flavor;

HLL_COUNT.EXTRACT

HLL_COUNT.EXTRACT(sketch)

Description

A scalar function that extracts a cardinality estimate of a single HLL++ sketch.

If sketch is NULL, this function returns a cardinality estimate of 0.

Supported input types

BYTES

Return type

INT64

Example

SELECT
  flavor,
  country,
  HLL_COUNT.EXTRACT(respondents_hll) AS num_respondents
FROM (
  SELECT
    HLL_COUNT.INIT(respondent) AS respondents_hll,
    flavor,
    country
  FROM UNNEST([
    STRUCT(1 AS respondent, "Vanilla" AS flavor, "CH" AS country),
    (1, "Chocolate", "CH"),
    (2, "Chocolate", "US"),
    (2, "Strawberry", "US")])
  GROUP BY flavor, country);

+------------+---------+-----------------+
| flavor     | country | num_respondents |
+------------+---------+-----------------+
| Vanilla    | CH      | 1               |
| Chocolate  | CH      | 1               |
| Chocolate  | US      | 1               |
| Strawberry | US      | 1               |
+------------+---------+-----------------+

About the HLL++ algorithm

The HLL++ algorithm improves on the HLL algorithm by more accurately estimating very small and large cardinalities. The HLL++ algorithm includes a 64-bit hash function, sparse representation to reduce memory requirements for small cardinality estimates, and empirical bias correction for small cardinality estimates.

About sketches

A sketch is a summary of a large data stream. You can extract statistics from a sketch to estimate particular statistics of the original data, or merge sketches to summarize multiple data streams. A sketch has these features:

  • It compresses raw data into a fixed-memory representation.
  • It's asymptotically smaller than the input.
  • It's the serialized form of an in-memory, sublinear data structure.
  • It typically requires less memory than the input used to create it.

Sketches allow integration with other systems. For example, it is possible to build sketches in external applications, like Cloud Dataflow, or Apache Spark and consume them in BigQuery or vice versa. Sketches also allow building intermediate aggregations for non-additive functions like COUNT(DISTINCT).

Numbering functions

The following sections describe the numbering functions that BigQuery supports. Numbering functions are a subset of analytic functions. For an explanation of how analytic functions work, see Analytic Function Concepts. For a description of how numbering functions work, see the Numbering Function Concepts.

OVER clause requirements:

  • PARTITION BY: Optional.
  • ORDER BY: Required, except for ROW_NUMBER().
  • window_frame_clause: Disallowed.

RANK

Description

Returns the ordinal (1-based) rank of each row within the ordered partition. All peer rows receive the same rank value. The next row or set of peer rows receives a rank value which increments by the number of peers with the previous rank value, instead of DENSE_RANK, which always increments by 1.

Supported Argument Types

INT64

DENSE_RANK

Description

Returns the ordinal (1-based) rank of each row within the window partition. All peer rows receive the same rank value, and the subsequent rank value is incremented by one.

Supported Argument Types

INT64

PERCENT_RANK

Description

Return the percentile rank of a row defined as (RK-1)/(NR-1), where RK is the RANK of the row and NR is the number of rows in the partition. Returns 0 if NR=1.

Supported Argument Types

FLOAT64

CUME_DIST

Description

Return the relative rank of a row defined as NP/NR. NP is defined to be the number of rows that either precede or are peers with the current row. NR is the number of rows in the partition.

Supported Argument Types

FLOAT64

NTILE

NTILE(constant_integer_expression)

Description

This function divides the rows into constant_integer_expression buckets based on row ordering and returns the 1-based bucket number that is assigned to each row. The number of rows in the buckets can differ by at most 1. The remainder values (the remainder of number of rows divided by buckets) are distributed one for each bucket, starting with bucket 1. If constant_integer_expression evaluates to NULL, 0 or negative, an error is provided.

Supported Argument Types

INT64

ROW_NUMBER

Description

Does not require the ORDER BY clause. Returns the sequential row ordinal (1-based) of each row for each ordered partition. If the ORDER BY clause is unspecified then the result is non-deterministic.

Supported Argument Types

INT64

Bit functions

BigQuery supports the following bit functions.

BIT_COUNT

BIT_COUNT(expression)

Description

The input, expression, must be an integer or BYTES.

Returns the number of bits that are set in the input expression. For signed integers, this is the number of bits in two's complement form.

Return Data Type

INT64

Example

SELECT a, BIT_COUNT(a) AS a_bits, FORMAT("%T", b) as b, BIT_COUNT(b) AS b_bits
FROM UNNEST([
  STRUCT(0 AS a, b'' AS b), (0, b'\x00'), (5, b'\x05'), (8, b'\x00\x08'),
  (0xFFFF, b'\xFF\xFF'), (-2, b'\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFE'),
  (-1, b'\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFF'),
  (NULL, b'\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFF')
]) AS x;

+-------+--------+---------------------------------------------+--------+
| a     | a_bits | b                                           | b_bits |
+-------+--------+---------------------------------------------+--------+
| 0     | 0      | b""                                         | 0      |
| 0     | 0      | b"\x00"                                     | 0      |
| 5     | 2      | b"\x05"                                     | 2      |
| 8     | 1      | b"\x00\x08"                                 | 1      |
| 65535 | 16     | b"\xff\xff"                                 | 16     |
| -2    | 63     | b"\xff\xff\xff\xff\xff\xff\xff\xfe"         | 63     |
| -1    | 64     | b"\xff\xff\xff\xff\xff\xff\xff\xff"         | 64     |
| NULL  | NULL   | b"\xff\xff\xff\xff\xff\xff\xff\xff\xff\xff" | 80     |
+-------+--------+---------------------------------------------+--------+

Conversion functions

BigQuery supports the following conversion functions. These data type conversions are explicit, but some conversions can happen implicitly. You can learn more about implicit and explicit conversion here.

CAST overview

CAST(expression AS typename [format_clause])

Description

Cast syntax is used in a query to indicate that the result type of an expression should be converted to some other type.

When using CAST, a query can fail if BigQuery is unable to perform the cast. If you want to protect your queries from these types of errors, you can use SAFE_CAST.

Casts between supported types that do not successfully map from the original value to the target domain produce runtime errors. For example, casting BYTES to STRING where the byte sequence is not valid UTF-8 results in a runtime error.

Some casts can include a format clause, which provides instructions for how to conduct the cast. For example, you could instruct a cast to convert a sequence of bytes to a BASE64-encoded string instead of a UTF-8-encoded string.

The structure of the format clause is unique to each type of cast and more information is available in the section for that cast.

Examples

The following query results in "true" if x is 1, "false" for any other non-NULL value, and NULL if x is NULL.

CAST(x=1 AS STRING)

CAST AS ARRAY

CAST(expression AS ARRAY<element_type>)

Description

BigQuery supports casting to ARRAY. The expression parameter can represent an expression for these data types:

  • ARRAY

Conversion rules

From To Rule(s) when casting x
ARRAY ARRAY Must be the exact same ARRAY type.

CAST AS BIGNUMERIC

CAST(expression AS BIGNUMERIC)

Description

BigQuery supports casting to BIGNUMERIC. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • STRING

Conversion rules

From To Rule(s) when casting x
FLOAT64 BIGNUMERIC The floating point number will round half away from zero. Casting a NaN, +inf or -inf will return an error. Casting a value outside the range of BIGNUMERIC will return an overflow error.
STRING BIGNUMERIC The numeric literal contained in the STRING must not exceed the maximum precision or range of the BIGNUMERIC type, or an error will occur. If the number of digits after the decimal point exceeds 38, then the resulting BIGNUMERIC value will round half away from zero to have 38 digits after the decimal point.

CAST AS BOOL

CAST(expression AS BOOL)

Description

BigQuery supports casting to BOOL. The expression parameter can represent an expression for these data types:

  • INT64
  • BOOL
  • STRING

Conversion rules

From To Rule(s) when casting x
INT64 BOOL Returns FALSE if x is 0, TRUE otherwise.
STRING BOOL Returns TRUE if x is "true" and FALSE if x is "false"
All other values of x are invalid and throw an error instead of casting to BOOL.
STRINGs are case-insensitive when converting to BOOL.

CAST AS BYTES

CAST(expression AS BYTES [format_clause])

Description

BigQuery supports casting to BYTES. The expression parameter can represent an expression for these data types:

  • BYTES
  • STRING

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

Conversion rules

From To Rule(s) when casting x
STRING BYTES STRINGs are cast to BYTES using UTF-8 encoding. For example, the STRING "©", when cast to BYTES, would become a 2-byte sequence with the hex values C2 and A9.

CAST AS DATE

CAST(expression AS DATE [format_clause])

Description

BigQuery supports casting to DATE. The expression parameter can represent an expression for these data types:

  • STRING
  • TIME
  • DATETIME
  • TIMESTAMP

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

Conversion rules

From To Rule(s) when casting x
STRING DATE When casting from string to date, the string must conform to the supported date literal format, and is independent of time zone. If the string expression is invalid or represents a date that is outside of the supported min/max range, then an error is produced.
TIMESTAMP DATE Casting from a timestamp to date effectively truncates the timestamp as of the default time zone.

CAST AS DATETIME

CAST(expression AS DATETIME [format_clause])

Description

BigQuery supports casting to DATETIME. The expression parameter can represent an expression for these data types:

  • STRING
  • TIME
  • DATETIME
  • TIMESTAMP

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

Conversion rules

From To Rule(s) when casting x
STRING DATETIME When casting from string to datetime, the string must conform to the supported datetime literal format, and is independent of time zone. If the string expression is invalid or represents a datetime that is outside of the supported min/max range, then an error is produced.
TIMESTAMP DATETIME Casting from a timestamp to datetime effectively truncates the timestamp as of the default time zone.

CAST AS FLOAT64

CAST(expression AS FLOAT64)

Description

BigQuery supports casting to floating point types. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • STRING

Conversion rules

From To Rule(s) when casting x
INT64 FLOAT64 Returns a close but potentially not exact floating point value.
NUMERIC FLOAT64 NUMERIC will convert to the closest floating point number with a possible loss of precision.
BIGNUMERIC FLOAT64 BIGNUMERIC will convert to the closest floating point number with a possible loss of precision.
STRING FLOAT64 Returns x as a floating point value, interpreting it as having the same form as a valid floating point literal. Also supports casts from "[+,-]inf" to [,-]Infinity, "[+,-]infinity" to [,-]Infinity, and "[+,-]nan" to NaN. Conversions are case-insensitive.

CAST AS INT64

CAST(expression AS INT64)

Description

BigQuery supports casting to integer types. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • BOOL
  • STRING

Conversion rules

From To Rule(s) when casting x
FLOAT64 INT64 Returns the closest integer value.
Halfway cases such as 1.5 or -0.5 round away from zero.
BOOL INT64 Returns 1 if x is TRUE, 0 otherwise.
STRING INT64 A hex string can be cast to an integer. For example, 0x123 to 291 or -0x123 to -291.

Examples

If you are working with hex strings (0x123), you can cast those strings as integers:

SELECT '0x123' as hex_value, CAST('0x123' as INT64) as hex_to_int;

+-----------+------------+
| hex_value | hex_to_int |
+-----------+------------+
| 0x123     | 291        |
+-----------+------------+
SELECT '-0x123' as hex_value, CAST('-0x123' as INT64) as hex_to_int;

+-----------+------------+
| hex_value | hex_to_int |
+-----------+------------+
| -0x123    | -291       |
+-----------+------------+

CAST AS INTERVAL

CAST(expression AS INTERVAL)

Description

BigQuery supports casting to INTERVAL. The expression parameter can represent an expression for these data types:

  • STRING

Conversion rules

From To Rule(s) when casting x
STRING INTERVAL When casting from string to interval, the string must conform to either ISO 8601 Duration standard or to interval literal format 'Y-M D H:M:S.F'. Partial interval literal formats are also accepted when they are not ambiguous, for example 'H:M:S'. If the string expression is invalid or represents an interval that is outside of the supported min/max range, then an error is produced.

Examples

SELECT input, CAST(input AS INTERVAL) AS output
FROM UNNEST([
  '1-2 3 10:20:30.456',
  '1-2',
  '10:20:30',
  'P1Y2M3D',
  'PT10H20M30,456S'
]) input

+--------------------+--------------------+
| input              | output             |
+--------------------+--------------------+
| 1-2 3 10:20:30.456 | 1-2 3 10:20:30.456 |
| 1-2                | 1-2 0 0:0:0        |
| 10:20:30           | 0-0 0 10:20:30     |
| P1Y2M3D            | 1-2 3 0:0:0        |
| PT10H20M30,456S    | 0-0 0 10:20:30.456 |
+--------------------+--------------------+

CAST AS NUMERIC

CAST(expression AS NUMERIC)

Description

BigQuery supports casting to NUMERIC. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • STRING

Conversion rules

From To Rule(s) when casting x
FLOAT64 NUMERIC The floating point number will round half away from zero. Casting a NaN, +inf or -inf will return an error. Casting a value outside the range of NUMERIC will return an overflow error.
STRING NUMERIC The numeric literal contained in the STRING must not exceed the maximum precision or range of the NUMERIC type, or an error will occur. If the number of digits after the decimal point exceeds nine, then the resulting NUMERIC value will round half away from zero to have nine digits after the decimal point.

CAST AS STRING

CAST(expression AS STRING [format_clause [AT TIME ZONE timezone_expr]])

Description

BigQuery supports casting to STRING. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • BOOL
  • BYTES
  • TIME
  • DATE
  • DATETIME
  • TIMESTAMP
  • STRING

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is one of these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • BYTES
  • TIME
  • DATE
  • DATETIME
  • TIMESTAMP

The format clause for STRING has an additional optional clause called AT TIME ZONE timezone_expr, which you can use to specify a specific time zone to use during formatting of a TIMESTAMP. If this optional clause is not included when formatting a TIMESTAMP, your current time zone is used.

For more information, see the following topics:

Conversion rules

From To Rule(s) when casting x
FLOAT64 STRING Returns an approximate string representation.
BOOL STRING Returns "true" if x is TRUE, "false" otherwise.
BYTES STRING Returns x interpreted as a UTF-8 STRING.
For example, the BYTES literal b'\xc2\xa9', when cast to STRING, is interpreted as UTF-8 and becomes the unicode character "©".
An error occurs if x is not valid UTF-8.
TIME STRING Casting from a time type to a string is independent of time zone and is of the form HH:MM:SS.
DATE STRING Casting from a date type to a string is independent of time zone and is of the form YYYY-MM-DD.
DATETIME STRING Casting from a datetime type to a string is independent of time zone and is of the form YYYY-MM-DD HH:MM:SS.
TIMESTAMP STRING When casting from timestamp types to string, the timestamp is interpreted using the default time zone, UTC. The number of subsecond digits produced depends on the number of trailing zeroes in the subsecond part: the CAST function will truncate zero, three, or six digits.
INTERVAL STRING Casting from an interval to a string is of the form Y-M D H:M:S.

Examples

SELECT CAST(CURRENT_DATE() AS STRING) AS current_date

+---------------+
| current_date  |
+---------------+
| 2021-03-09    |
+---------------+
SELECT CAST(CURRENT_DATE() AS STRING FORMAT 'DAY') AS current_day

+-------------+
| current_day |
+-------------+
| MONDAY      |
+-------------+
SELECT CAST(
  TIMESTAMP '2008-12-25 00:00:00+00:00'
  AS STRING FORMAT 'YYYY-MM-DD HH24:MI:SS TZH:TZM') AS date_time_to_string

-- Results depend upon where this query was executed.
+------------------------------+
| date_time_to_string          |
+------------------------------+
| 2008-12-24 16:00:00 -08:00   |
+------------------------------+
SELECT CAST(
  TIMESTAMP '2008-12-25 00:00:00+00:00'
  AS STRING FORMAT 'YYYY-MM-DD HH24:MI:SS TZH:TZM'
  AT TIME ZONE 'Asia/Kolkata') AS date_time_to_string

-- Because the time zone is specified, the result is always the same.
+------------------------------+
| date_time_to_string          |
+------------------------------+
| 2008-12-25 05:30:00 +05:30   |
+------------------------------+

CAST AS STRUCT

CAST(expression AS STRUCT)

Description

BigQuery supports casting to STRUCT. The expression parameter can represent an expression for these data types:

  • STRUCT

Conversion rules

From To Rule(s) when casting x
STRUCT STRUCT Allowed if the following conditions are met:
  1. The two STRUCTs have the same number of fields.
  2. The original STRUCT field types can be explicitly cast to the corresponding target STRUCT field types (as defined by field order, not field name).

CAST AS TIME

CAST(expression AS TIME [format_clause])

Description

BigQuery supports casting to TIME. The expression parameter can represent an expression for these data types:

  • STRING
  • TIME
  • DATETIME
  • TIMESTAMP

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

Conversion rules

From To Rule(s) when casting x
STRING TIME When casting from string to time, the string must conform to the supported time literal format, and is independent of time zone. If the string expression is invalid or represents a time that is outside of the supported min/max range, then an error is produced.

CAST AS TIMESTAMP

CAST(expression AS TIMESTAMP [format_clause [AT TIME ZONE timezone_expr]])

Description

BigQuery supports casting to TIMESTAMP. The expression parameter can represent an expression for these data types:

  • STRING
  • TIME
  • DATETIME
  • TIMESTAMP

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

The format clause for TIMESTAMP has an additional optional clause called AT TIME ZONE timezone_expr, which you can use to specify a specific time zone to use during formatting. If this optional clause is not included, your current time zone is used.

Conversion rules

From To Rule(s) when casting x
STRING TIMESTAMP When casting from string to a timestamp, string_expression must conform to the supported timestamp literal formats, or else a runtime error occurs. The string_expression may itself contain a time zone.
If there is a time zone in the string_expression, that time zone is used for conversion, otherwise the default time zone, UTC, is used. If the string has fewer than six digits, then it is implicitly widened.
An error is produced if the string_expression is invalid, has more than six subsecond digits (i.e. precision greater than microseconds), or represents a time outside of the supported timestamp range.
DATE TIMESTAMP Casting from a date to a timestamp interprets date_expression as of midnight (start of the day) in the default time zone, UTC.
DATETIME TIMESTAMP Casting from a datetime to a timestamp interprets datetime_expression as of midnight (start of the day) in the default time zone, UTC.

Examples

The following example casts a string-formatted timestamp as a timestamp:

SELECT CAST("2020-06-02 17:00:53.110+00:00" AS TIMESTAMP) AS as_timestamp

-- Results depend upon where this query was executed.
+-----------------------------+
| as_timestamp                |
+-----------------------------+
| 2020-06-03 00:00:53.110 UTC |
+-----------------------------+

The following examples cast a string-formatted date and time as a timestamp. These examples return the same output as the previous example.

SELECT CAST("06/02/2020 17:00:53.110" AS TIMESTAMP FORMAT 'MM/DD/YYYY HH:MI:SS' AT TIME ZONE 'America/Los_Angeles') AS as_timestamp
SELECT CAST("06/02/2020 17:00:53.110" AS TIMESTAMP FORMAT 'MM/DD/YYYY HH:MI:SS' AT TIME ZONE '00') AS as_timestamp
SELECT CAST('06/02/2020 17:00:53.110 +00' AS TIMESTAMP FORMAT 'YYYY-MM-DD HH:MI:SS TZH') AS as_timestamp

PARSE_BIGNUMERIC

PARSE_BIGNUMERIC(string_expression)

Description

Converts a string to a BIGNUMERIC value.

The numeric literal contained in the string must not exceed the maximum precision or range of the BIGNUMERIC type, or an error occurs. If the number of digits after the decimal point exceeds 38, then the resulting BIGNUMERIC value rounds half away from zero to have 38 digits after the decimal point.


-- This example shows how a string with a decimal point is parsed.
SELECT PARSE_BIGNUMERIC("123.45") AS parsed

+--------+
| parsed |
+--------+
| 123.45 |
+--------+

-- This example shows how a string with an exponent is parsed.
SELECT PARSE_BIGNUMERIC("123.456E37") AS parsed

+-----------------------------------------+
| parsed                                  |
+-----------------------------------------+
| 123400000000000000000000000000000000000 |
+-----------------------------------------+

-- This example shows the rounding when digits after the decimal point exceeds 38.
SELECT PARSE_BIGNUMERIC("1.123456789012345678901234567890123456789") as parsed

+------------------------------------------+
| parsed                                   |
+------------------------------------------+
| 1.12345678901234567890123456789012345679 |
+------------------------------------------+

This funcion is similar to using the CAST AS BIGNUMERIC function except that the PARSE_BIGNUMERIC function only accepts string inputs and allows the following in the string:

  • Spaces between the sign (+/-) and the number
  • Signs (+/-) after the number

Rules for valid input strings:

Rule Example Input Output
The string can only contain digits, commas, decimal points and signs. "- 12,34567,89.0" -123456789
Whitepaces are allowed anywhere except between digits. " - 12.345 " -12.345
Only digits and commas are allowed before the decimal point. " 12,345,678" 12345678
Only digits are allowed after the decimal point. "1.234 " 1.234
Use E or e for exponents. After the e, digits and a leading sign indicator are allowed. " 123.45e-1" 12.345
If the integer part is not empty, then it must contain at least one digit. " 0,.12 -" -0.12
If the string contains a decimal point, then it must contain at least one digit. " .1" 0.1
The string cannot contain more than one sign. " 0.5 +" 0.5

Return Data Type

BIGNUMERIC

Examples

This example shows an input with spaces before, after, and between the sign and the number:

SELECT PARSE_BIGNUMERIC("  -  12.34 ") as parsed;

+--------+
| parsed |
+--------+
| -12.34 |
+--------+

This example shows an input with an exponent as well as the sign after the number:

SELECT PARSE_BIGNUMERIC("12.34e-1-") as parsed;

+--------+
| parsed |
+--------+
| -1.234 |
+--------+

This example shows an input with multiple commas in the integer part of the number:

SELECT PARSE_BIGNUMERIC("  1,2,,3,.45 + ") as parsed;

+--------+
| parsed |
+--------+
| 123.45 |
+--------+

This example shows an input with a decimal point and no digits in the whole number part:

SELECT PARSE_BIGNUMERIC(".1234  ") as parsed;

+--------+
| parsed |
+--------+
| 0.1234 |
+--------+

Examples of invalid inputs

This example is invalid because the whole number part contains no digits:

SELECT PARSE_BIGNUMERIC(",,,.1234  ") as parsed;

This example is invalid because there are whitespaces between digits:

SELECT PARSE_BIGNUMERIC("1  23.4 5  ") as parsed;

This example is invalid because the number is empty except for an exponent:

SELECT PARSE_BIGNUMERIC("  e1 ") as parsed;

This example is invalid because the string contains multiple signs:

SELECT PARSE_BIGNUMERIC("  - 12.3 - ") as parsed;

This example is invalid because the value of the number falls outside the range of BIGNUMERIC:

SELECT PARSE_BIGNUMERIC("12.34E100 ") as parsed;

This example is invalid because the string contains invalid characters:

SELECT PARSE_BIGNUMERIC("$12.34") as parsed;

PARSE_NUMERIC

PARSE_NUMERIC(string_expression)

Description

Converts a string to a NUMERIC value.

The numeric literal contained in the string must not exceed the maximum precision or range of the NUMERIC type, or an error occurs. If the number of digits after the decimal point exceeds nine, then the resulting NUMERIC value rounds half away from zero to have nine digits after the decimal point.


-- This example shows how a string with a decimal point is parsed.
SELECT PARSE_NUMERIC("123.45") AS parsed

+--------+
| parsed |
+--------+
| 123.45 |
+--------+

-- This example shows how a string with an exponent is parsed.
SELECT PARSE_NUMERIC("12.34E27") as parsed

+-------------------------------+
| parsed                        |
+-------------------------------+
| 12340000000000000000000000000 |
+-------------------------------+

-- This example shows the rounding when digits after the decimal point exceeds 9.
SELECT PARSE_NUMERIC("1.0123456789") as parsed

+-------------+
| parsed      |
+-------------+
| 1.012345679 |
+-------------+

This function is similar to using the CAST AS NUMERIC function except that the PARSE_NUMERIC function only accepts string inputs and allows the following in the string:

  • Spaces between the sign (+/-) and the number
  • Signs (+/-) after the number

Rules for valid input strings:

Rule Example Input Output
The string can only contain digits, commas, decimal points and signs. "- 12,34567,89.0" -123456789
Whitepaces are allowed anywhere except between digits. " - 12.345 " -12.345
Only digits and commas are allowed before the decimal point. " 12,345,678" 12345678
Only digits are allowed after the decimal point. "1.234 " 1.234
Use E or e for exponents. After the e, digits and a leading sign indicator are allowed. " 123.45e-1" 12.345
If the integer part is not empty, then it must contain at least one digit. " 0,.12 -" -0.12
If the string contains a decimal point, then it must contain at least one digit. " .1" 0.1
The string cannot contain more than one sign. " 0.5 +" 0.5

Return Data Type

NUMERIC

Examples

This example shows an input with spaces before, after, and between the sign and the number:

SELECT PARSE_NUMERIC("  -  12.34 ") as parsed;

+--------+
| parsed |
+--------+
| -12.34 |
+--------+

This example shows an input with an exponent as well as the sign after the number:

SELECT PARSE_NUMERIC("12.34e-1-") as parsed;

+--------+
| parsed |
+--------+
| -1.234 |
+--------+

This example shows an input with multiple commas in the integer part of the number:

SELECT PARSE_NUMERIC("  1,2,,3,.45 + ") as parsed;

+--------+
| parsed |
+--------+
| 123.45 |
+--------+

This example shows an input with a decimal point and no digits in the whole number part:

SELECT PARSE_NUMERIC(".1234  ") as parsed;

+--------+
| parsed |
+--------+
| 0.1234 |
+--------+

Examples of invalid inputs

This example is invalid because the whole number part contains no digits:

SELECT PARSE_NUMERIC(",,,.1234  ") as parsed;

This example is invalid because there are whitespaces between digits:

SELECT PARSE_NUMERIC("1  23.4 5  ") as parsed;

This example is invalid because the number is empty except for an exponent:

SELECT PARSE_NUMERIC("  e1 ") as parsed;

This example is invalid because the string contains multiple signs:

SELECT PARSE_NUMERIC("  - 12.3 - ") as parsed;

This example is invalid because the value of the number falls outside the range of BIGNUMERIC:

SELECT PARSE_NUMERIC("12.34E100 ") as parsed;

This example is invalid because the string contains invalid characters:

SELECT PARSE_NUMERIC("$12.34") as parsed;

SAFE_CAST

SAFE_CAST(expression AS typename [format_clause])

Description

When using CAST, a query can fail if BigQuery is unable to perform the cast. For example, the following query generates an error:

SELECT CAST("apple" AS INT64) AS not_a_number;

If you want to protect your queries from these types of errors, you can use SAFE_CAST. SAFE_CAST is identical to CAST, except it returns NULL instead of raising an error.

SELECT SAFE_CAST("apple" AS INT64) AS not_a_number;

+--------------+
| not_a_number |
+--------------+
| NULL         |
+--------------+

If you are casting from bytes to strings, you can also use the function, SAFE_CONVERT_BYTES_TO_STRING. Any invalid UTF-8 characters are replaced with the unicode replacement character, U+FFFD. See SAFE_CONVERT_BYTES_TO_STRING for more information.

Other conversion functions

You can learn more about these conversion functions elsewhere in the documentation:

Conversion function From To
ARRAY_TO_STRING ARRAY STRING
DATE Various data types DATE
DATETIME Various data types DATETIME
FROM_BASE32 STRING BYTEs
FROM_BASE64 STRING BYTES
FROM_HEX STRING BYTES
PARSE_DATE STRING DATE
PARSE_DATETIME STRING DATETIME
PARSE_TIME STRING TIME
PARSE_TIMESTAMP STRING TIMESTAMP
SAFE_CONVERT_BYTES_TO_STRING BYTES STRING
STRING TIMESTAMP STRING
TIME Various data types TIME
TIMESTAMP Various data types TIMESTAMP
TO_BASE32 BYTES STRING
TO_BASE64 BYTES STRING
TO_HEX BYTES STRING
TO_JSON_STRING All data types STRING

Format clause for CAST

format_clause:
  FORMAT format_model

format_model:
  format_string_expression

The format clause can be used in some CAST functions. You use a format clause to provide instructions for how to conduct a cast. For example, you could instruct a cast to convert a sequence of bytes to a BASE64-encoded string instead of a UTF-8-encoded string.

The format clause includes a format model. The format model can contain format elements combined together as a format string.

Format bytes as string

CAST(bytes_expression AS STRING FORMAT format_string_expression)

You can cast a sequence of bytes to a string with a format element in the format string. If the bytes cannot be formatted with a format element, an error is returned. If the sequence of bytes is NULL, the result is NULL. Format elements are case-insensitive.

Format element Returns Example
HEX Converts a sequence of bytes into a hexadecimal string. Input: b'\x00\x01\xEF\xFF'
Output: 0001efff
BASEX Converts a sequence of bytes into a BASEX encoded string. X represents one of these numbers: 2, 8, 16, 32, 64. Input as BASE8: b'\x02\x11\x3B'
Output: 00410473
BASE64M Converts a sequence of bytes into a BASE64-encoded string based on rfc 2045 for MIME. Generates a newline character ("\n") every 76 characters. Input: b'\xde\xad\xbe\xef'
Output: 3q2+7w==
ASCII Converts a sequence of bytes that are ASCII values to a string. If the input contains bytes that are not a valid ASCII encoding, an error is returned. Input: b'\x48\x65\x6c\x6c\x6f'
Output: Hello
UTF-8 Converts a sequence of bytes that are UTF-8 values to a string. If the input contains bytes that are not a valid UTF-8 encoding, an error is returned. Input: b'\x24'
Output: $
UTF8 Same behavior as UTF-8.

Return type

STRING

Example

SELECT CAST(b'\x48\x65\x6c\x6c\x6f' AS STRING FORMAT 'ASCII') AS bytes_to_string;

+-----------------+
| bytes_to_string |
+-----------------+
| Hello           |
+-----------------+

Format string as bytes

CAST(string_expression AS BYTES FORMAT format_string_expression)

You can cast a string to bytes with a format element in the format string. If the string cannot be formatted with the format element, an error is returned. Format elements are case-insensitive.

In the string expression, whitespace characters, such as \n, are ignored if the BASE64 or BASE64M format element is used.

Format element Returns Example
HEX Converts a hexadecimal-encoded string to bytes. If the input contains characters that are not part of the HEX encoding alphabet (0~9, case-insensitive a~f), an error is returned. Input: '0001efff'
Output: b'\x00\x01\xEF\xFF'
BASEX Converts a BASEX-encoded string to bytes. X represents one of these numbers: 2, 8, 16, 32, 64. An error is returned if the input contains characters that are not part of the BASEX encoding alphabet, except whitespace characters if the format element is BASE64. Input as BASE8: '00410473'
Output: b'\x02\x11\x3B'
BASE64M Converts a BASE64-encoded string to bytes. If the input contains characters that are not whitespace and not part of the BASE64 encoding alphabet defined at rfc 2045, an error is returned. BASE64M and BASE64 decoding have the same behavior. Input: '3q2+7w=='
Output: b'\xde\xad\xbe\xef'
ASCII Converts a string with only ASCII characters to bytes. If the input contains characters that are not ASCII characters, an error is returned. Input: 'Hello'
Output: b'\x48\x65\x6c\x6c\x6f'
UTF-8 Converts a string to a sequence of UTF-8 bytes. Input: '$'
Output: b'\x24'
UTF8 Same behavior as UTF-8.

Return type

BYTES

Example

SELECT CAST('Hello' AS BYTES FORMAT 'ASCII') AS string_to_bytes

+-------------------------+
| string_to_bytes         |
+-------------------------+
| b'\x48\x65\x6c\x6c\x6f' |
+-------------------------+

Format date and time as string

You can format these date and time parts as a string:

Case matching is supported when you format some date or time parts as a string and the output contains letters. To learn more, see Case matching.

Case matching

When the output of some format element contains letters, the letter cases of the output is matched with the letter cases of the format element, meaning the words in the output are capitalized according to how the format element is capitalized. This is called case matching. The rules are:

  • If the first two letters of the element are both upper case, the words in the output are capitalized. For example DAY = THURSDAY.
  • If the first letter of the element is upper case, and the second letter is lowercase, the first letter of each word in the output is capitalized and other letters are lowercase. For example Day = Thursday.
  • If the first letter of the element is lowercase, then all letters in the output are lowercase. For example, day = thursday.

Format year part as string

CAST(expression AS STRING FORMAT format_string_expression)

Casts a data type that contains the year part to a string. Includes format elements, which provide instructions for how to conduct the cast.

  • expression: This expression contains the data type with the year that you need to format.
  • format_string_expression: A string which contains format elements, including the year format element.

These data types include a year part:

  • DATE
  • DATETIME
  • TIMESTAMP

If expression or format_string_expression is NULL the return value is NULL. If format_string_expression is an empty string, the output is an empty string. An error is generated if a value that is not a supported format element appears in format_string_expression or expression does not contain a value specified by a format element.

Format element Returns Example
YYYY Year, 4 or more digits. Input: DATE '2018-01-30'
Output: 2018
Input: DATE '76-01-30'
Output: 0076
Input: DATE '10000-01-30'
Output: 10000
YYY Year, last 3 digits only. Input: DATE '2018-01-30'
Output: 018
Input: DATE '98-01-30'
Output: 098
YY Year, last 2 digits only. Input: DATE '2018-01-30'
Output: 18
Input: DATE '8-01-30'
Output: 08
Y Year, last digit only. Input: DATE '2018-01-30'
Output: 8
RRRR Same behavior as YYYY.
RR Same behavior as YY.

Return type

STRING

Example

SELECT CAST(DATE '2018-01-30' AS STRING FORMAT 'YYYY') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| 2018                |
+---------------------+

Format month part as string

CAST(expression AS STRING FORMAT format_string_expression)

Casts a data type that contains the month part to a string. Includes format elements, which provide instructions for how to conduct the cast.

  • expression: This expression contains the data type with the month that you need to format.
  • format_string_expression: A string which contains format elements, including the month format element.

These data types include a month part:

  • DATE
  • DATETIME
  • TIMESTAMP

If expression or format_string_expression is NULL the return value is NULL. If format_string_expression is an empty string, the output is an empty string. An error is generated if a value that is not a supported format element appears in format_string_expression or expression does not contain a value specified by a format element.

Format element Returns Example
MM Month, 2 digits. Input: DATE '2018-01-30'
Output: 01
MON Abbreviated, 3-character name of the month. The abbreviated month names for locale en-US are: JAN, FEB, MAR, APR, MAY, JUN, JUL, AUG, SEP, OCT, NOV, DEC. Case matching is supported. Input: DATE '2018-01-30'
Output: JAN
MONTH Name of the month. Case matching is supported. Input: DATE '2018-01-30'
Output: JANUARY

Return type

STRING

Example

SELECT CAST(DATE '2018-01-30' AS STRING FORMAT 'MONTH') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| JANUARY             |
+---------------------+

Format day part as string

CAST(expression AS STRING FORMAT format_string_expression)

Casts a data type that contains the day part to a string. Includes format elements, which provide instructions for how to conduct the cast.

  • expression: This expression contains the data type with the day that you need to format.
  • format_string_expression: A string which contains format elements, including the day format element.

These data types include a day part:

  • DATE
  • DATETIME
  • TIMESTAMP

If expression or format_string_expression is NULL the return value is NULL. If format_string_expression is an empty string, the output is an empty string. An error is generated if a value that is not a supported format element appears in format_string_expression or expression does not contain a value specified by a format element.

Format element Returns Example
DAY Name of the day of the week, localized. Spaces are padded on the right side to make the output size exactly 9. Case matching is supported. Input: DATE '2020-12-31'
Output: THURSDAY
DY Abbreviated, 3-character name of the weekday, localized. The abbreviated weekday names for locale en-US are: MON, TUE, WED, THU, FRI, SAT, SUN. Case matching is supported. Input: DATE '2020-12-31'
Output: THU
D Day of the week (1 to 7), starting with Sunday as 1. Input: DATE '2020-12-31'
Output: 4
DD 2-digit day of the month. Input: DATE '2018-12-02'
Output: 02
DDD 3-digit day of the year. Input: DATE '2018-02-03'
Output: 034

Return type

STRING

Example

SELECT CAST(DATE '2018-02-15' AS STRING FORMAT 'DD') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| 15                  |
+---------------------+

Format hour part as string

CAST(expression AS STRING FORMAT format_string_expression)

Casts a data type that contains the hour part to a string. Includes format elements, which provide instructions for how to conduct the cast.

  • expression: This expression contains the data type with the hour that you need to format.
  • format_string_expression: A string which contains format elements, including the hour format element.

These data types include a hour part:

  • TIME
  • DATETIME
  • TIMESTAMP

If expression or format_string_expression is NULL the return value is NULL. If format_string_expression is an empty string, the output is an empty string. An error is generated if a value that is not a supported format element appears in format_string_expression or expression does not contain a value specified by a format element.

Format element Returns Example
HH Hour of the day, 12-hour clock, 2 digits. Input: TIME '21:30:00'
Output: 09
HH12 Hour of the day, 12-hour clock. Input: TIME '21:30:00'
Output: 09
HH24 Hour of the day, 24-hour clock, 2 digits. Input: TIME '21:30:00'
Output: 21

Return type

STRING

Examples

SELECT CAST(TIME '21:30:00' AS STRING FORMAT 'HH24') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| 21                  |
+---------------------+
SELECT CAST(TIME '21:30:00' AS STRING FORMAT 'HH12') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| 09                  |
+---------------------+

Format minute part as string

CAST(expression AS STRING FORMAT format_string_expression)

Casts a data type that contains the minute part to a string. Includes format elements, which provide instructions for how to conduct the cast.

  • expression: This expression contains the data type with the minute that you need to format.
  • format_string_expression: A string which contains format elements, including the minute format element.

These data types include a minute part:

  • TIME
  • DATETIME
  • TIMESTAMP

If expression or format_string_expression is NULL the return value is NULL. If format_string_expression is an empty string, the output is an empty string. An error is generated if a value that is not a supported format element appears in format_string_expression or expression does not contain a value specified by a format element.

Format element Returns Example
MI Minute, 2 digits. Input: TIME '01:02:03'
Output: 02

Return type

STRING

Example

SELECT CAST(TIME '21:30:00' AS STRING FORMAT 'MI') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| 30                  |
+---------------------+

Format second part as string

CAST(expression AS STRING FORMAT format_string_expression)

Casts a data type that contains the second part to a string. Includes format elements, which provide instructions for how to conduct the cast.

  • expression: This expression contains the data type with the second that you need to format.
  • format_string_expression: A string which contains format elements, including the second format element.

These data types include a second part:

  • TIME
  • DATETIME
  • TIMESTAMP

If expression or format_string_expression is NULL the return value is NULL. If format_string_expression is an empty string, the output is an empty string. An error is generated if a value that is not a supported format element appears in format_string_expression or expression does not contain a value specified by a format element.

Format element Returns Example
SS Seconds of the minute, 2 digits. Input: TIME '01:02:03'
Output: 03
SSSSS Seconds of the day, 5 digits. Input: TIME '01:02:03'
Output: 03723
FFn Fractional part of the second, n digits long. Replace n with a value from 1 to 9. For example, FF5. The fractional part of the second is rounded to fit the size of the output. Input for FF1: TIME '01:05:07.16'
Output: 1
Input for FF2: TIME '01:05:07.16'
Output: 16
Input for FF3: TIME '01:05:07.16'
Output: 016

Return type

STRING

Examples

SELECT CAST(TIME '21:30:25.16' AS STRING FORMAT 'SS') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| 25                  |
+---------------------+
SELECT CAST(TIME '21:30:25.16' AS STRING FORMAT 'FF2') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| 16                  |
+---------------------+

Format meridian indicator part as string

CAST(expression AS STRING FORMAT format_string_expression)

Casts a data type that contains the meridian indicator part to a string. Includes format elements, which provide instructions for how to conduct the cast.

  • expression: This expression contains the data type with the meridian indicator that you need to format.
  • format_string_expression: A string which contains format elements, including the meridian indicator format element.

These data types include a meridian indicator part:

  • TIME
  • DATETIME
  • TIMESTAMP

If expression or format_string_expression is NULL the return value is NULL. If format_string_expression is an empty string, the output is an empty string. An error is generated if a value that is not a supported format element appears in format_string_expression or expression does not contain a value specified by a format element.

Format element Returns Example
A.M. A.M. if the time is less than 12, otherwise P.M. The letter case of the output is determined by the first letter case of the format element. Input for A.M.: TIME '01:02:03'
Output: A.M.
Input for A.M.: TIME '16:02:03'
Output: P.M.
Input for a.m.: TIME '01:02:03'
Output: a.m.
Input for a.M.: TIME '01:02:03'
Output: a.m.
AM AM if the time is less than 12, otherwise PM. The letter case of the output is determined by the first letter case of the format element. Input for AM: TIME '01:02:03'
Output: AM
Input for AM: TIME '16:02:03'
Output: PM
Input for am: TIME '01:02:03'
Output: am
Input for aM: TIME '01:02:03'
Output: am
P.M. Output is the same as A.M. format element.
PM Output is the same as AM format element.

Return type

STRING

Examples

SELECT CAST(TIME '21:30:00' AS STRING FORMAT 'AM') AS date_time_to_string;
SELECT CAST(TIME '21:30:00' AS STRING FORMAT 'PM') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| PM                  |
+---------------------+
SELECT CAST(TIME '01:30:00' AS STRING FORMAT 'AM') AS date_time_to_string;
SELECT CAST(TIME '01:30:00' AS STRING FORMAT 'PM') AS date_time_to_string;

+---------------------+
| date_time_to_string |
+---------------------+
| AM                  |
+---------------------+

Format time zone part as string

CAST(expression AS STRING FORMAT format_string_expression)

Casts a data type that contains the time zone part to a string. Includes format elements, which provide instructions for how to conduct the cast.

  • expression: This expression contains the data type with the time zone that you need to format.
  • format_string_expression: A string which contains format elements, including the time zone format element.

These data types include a time zone part:

  • DATE
  • TIME
  • DATETIME
  • TIMESTAMP

If expression or format_string_expression is NULL the return value is NULL. If format_string_expression is an empty string, the output is an empty string. An error is generated if a value that is not a supported format element appears in format_string_expression or expression does not contain a value specified by a format element.

Format element Returns Example
TZH Hour offset for a time zone. This includes the +/- sign and 2-digit hour. Inputstamp: TIMESTAMP '2008-12-25 05:30:00+00' Output: −08
TZM Minute offset for a time zone. This includes only the 2-digit minute. Inputstamp: TIMESTAMP '2008-12-25 05:30:00+00' Output: 00

Return type

STRING

Examples

SELECT CAST(TIMESTAMP '2008-12-25 00:00:00+00:00' AS STRING FORMAT 'TZH') AS date_time_to_string;

-- Results depend upon where this query was executed.
+---------------------+
| date_time_to_string |
+---------------------+
| -08                 |
+---------------------+
SELECT CAST(TIMESTAMP '2008-12-25 00:00:00+00:00' AS STRING FORMAT 'TZH' AT TIME ZONE 'Asia/Kolkata')
AS date_time_to_string;

-- Because the time zone is specified, the result is always the same.
+---------------------+
| date_time_to_string |
+---------------------+
| +05                 |
+---------------------+
SELECT CAST(TIMESTAMP '2008-12-25 00:00:00+00:00' AS STRING FORMAT 'TZM') AS date_time_to_string;

-- Results depend upon where this query was executed.
+---------------------+
| date_time_to_string |
+---------------------+
| 00                  |
+---------------------+
SELECT CAST(TIMESTAMP '2008-12-25 00:00:00+00:00' AS STRING FORMAT 'TZM' AT TIME ZONE 'Asia/Kolkata')
AS date_time_to_string;

-- Because the time zone is specified, the result is always the same.
+---------------------+
| date_time_to_string |
+---------------------+
| 30                  |
+---------------------+

Format literal as string

CAST(expression AS STRING FORMAT format_string_expression)
Format element Returns Example
- Output is the same as the input. -
. Output is the same as the input. .
/ Output is the same as the input. /
, Output is the same as the input. ,
' Output is the same as the input. '
; Output is the same as the input. ;
: Output is the same as the input. :
Whitespace Output is the same as the input. Whitespace means the space character, ASCII 32. It does not mean other types of space like tab or new line. Any whitespace character that is not the ASCII 32 character in the format model generates an error.
"text" Output is the value within the double quotes. To preserve a double quote or backslash character, use the \" or \\ escape sequence. Other escape sequences are not supported. Input: "abc"
Output: abc
Input: "a\"b\\c"
Output: a"b\c

Format string as date and time

You can format a string with these date and time parts:

When formatting a string with date and time parts, you must follow the format model rules.

Format model rules

When casting a string to date and time parts, you must ensure the format model is valid. The format model represents the elements passed into CAST(string_expression AS type FORMAT format_string_expression) as the format_string_expression and is validated according to the following rules:

  • It contains at most one of each of the following parts: meridian indicator, year, month, day, hour.
  • A non-literal, non-whitespace format element cannot appear more than once.
  • If it contains the day of year format element, DDD, then it cannot contain the month.
  • If it contains the 24-hour format element, HH24, then it cannot contain the 12-hour format element or a meridian indicator.
  • If it contains the 12-hour format element, HH12 or HH, then it must also contain a meridian indicator.
  • If it contains a meridian indicator, then it must also contain a 12-hour format element.
  • If it contains the second of the day format element, SSSSS, then it cannot contain any of the following: hour, minute, second, or meridian indicator.
  • It cannot contain a format element such that the value it sets does not exist in the target type. For example, an hour format element such as HH24 cannot appear in a string you are casting as a DATE.

Format string as year part

CAST(string_expression AS type FORMAT format_string_expression)

Casts a string-formatted year to a data type that contains the year part. Includes format elements, which provide instructions for how to conduct the cast.

  • string_expression: This expression contains the string with the year that you need to format.
  • type: The data type to which you are casting. Must include the year part.
  • format_string_expression: A string which contains format elements, including the year format element. The formats elements in this string are defined collectively as the format model, which must follow these rules.

These data types include a year part:

  • DATE
  • DATETIME
  • TIMESTAMP

If the YEAR part is missing from string_expression and the return type includes this part, YEAR is set to the current year.

An error is generated if a value that is not a supported format element appears in format_string_expression or string_expression does not contain a value specified by a format element.

Format element Returns Example
YYYY If it is delimited, matches 1 to 5 digits. If it is not delimited, matches 4 digits. Sets the year part to the matched number. Input for MM-DD-YYYY: '03-12-2018'
Output as DATE: 2018-12-03
Input for YYYY-MMDD: '10000-1203'
Output as DATE: 10000-12-03
Input for YYYY: '18'
Output as DATE: 2018-03-01 (Assume current date is March 23, 2021)
YYY Matches 3 digits. Sets the last 3 digits of the year part to the matched number. Input for YYY-MM-DD: '018-12-03'
Output as DATE: 2018-12-03
Input for YYY-MM-DD: '038-12-03'
Output as DATE: 2038-12-03
YY Matches 2 digits. Sets the last 2 digits of the year part to the matched number. Input for YY-MM-DD: '18-12-03'
Output as DATE: 2018-12-03
Input for YY-MM-DD: '38-12-03'
Output as DATE: 2038-12-03
Y Matches 1 digit. Sets the last digit of the year part to the matched number. Input for Y-MM-DD: '8-12-03'
Output as DATE: 2008-12-03
Y,YYY Matches the pattern of 1 to 2 digits, comma, then exactly 3 digits. Sets the year part to the matched number. Input for Y,YYY-MM-DD: '2,018-12-03'
Output as DATE: 2008-12-03
RRRR Same behavior as YYYY.
RR

Matches 2 digits.

If the 2 digits entered are between 00 and 49 and the last 2 digits of the current year are between 00 and 49, the returned year has the same first 2 digits as the current year. If the last 2 digits of the current year are between 50 and 99, the first 2 digits of the returned year is 1 greater than the first 2 digits of the current year.

If the 2 digits entered are between 50 and 99 and the last 2 digits of the current year are between 00 and 49, the first 2 digits of the returned year are 1 less than the first 2 digits of the current year. If the last 2 digits of the current year are between 50 and 99, the returned year has the same first 2 digits as the current year.

Input for RR-MM-DD: '18-12-03'
Output as DATE: 2018-12-03 (executed in the year 2021) Output as DATE: 2118-12-03 (executed in the year 2050)
Input for RR-MM-DD: '50-12-03'
Output as DATE: 2050-12-03 (executed in the year 2021) Output as DATE: 2050-12-03 (executed in the year 2050)

Return type

The data type to which the string was cast. This can be:

  • DATE
  • DATETIME
  • TIMESTAMP

Examples

SELECT CAST('18-12-03' AS DATE FORMAT 'YY-MM-DD') AS string_to_date_time

+---------------------+
| string_to_date_time |
+---------------------+
| 2018-02-03          |
+---------------------+

Format string as month part

CAST(string_expression AS type FORMAT format_string_expression)

Casts a string-formatted month to a data type that contains the month part. Includes format elements, which provide instructions for how to conduct the cast.

  • string_expression: This expression contains the string with the month that you need to format.
  • type: The data type to which you are casting. Must include the month part.
  • format_string_expression: A string which contains format elements, including the month format element. The formats elements in this string are defined collectively as the format model, which must follow these rules.

These data types include a month part:

  • DATE
  • DATETIME
  • TIMESTAMP

If the MONTH part is missing from string_expression and the return type includes this part, MONTH is set to the current month.

An error is generated if a value that is not a supported format element appears in format_string_expression or string_expression does not contain a value specified by a format element.

Format element Returns Example
MM Matches 2 digits. Sets the month part to the matched number. Input for MM-DD-YYYY: '03-12-2018'
Output as DATE: 2018-12-03
MON Matches 3 letters. Sets the month part to the matched string interpreted as the abbreviated name of the month. Input for MON DD, YYYY: 'DEC 03, 2018'
Output as DATE: 2018-12-03
MONTH Matches 9 letters. Sets the month part to the matched string interpreted as the name of the month. Input for MONTH DD, YYYY: 'DECEMBER 03, 2018'
Output as DATE: 2018-12-03

Return type

The data type to which the string was cast. This can be:

  • DATE
  • DATETIME
  • TIMESTAMP

Examples

SELECT CAST('DEC 03, 2018' AS DATE FORMAT 'MON DD, YYYY') AS string_to_date_time

+---------------------+
| string_to_date_time |
+---------------------+
| 2018-12-03          |
+---------------------+

Format string as day part

CAST(string_expression AS type FORMAT format_string_expression)

Casts a string-formatted day to a data type that contains the day part. Includes format elements, which provide instructions for how to conduct the cast.

  • string_expression: This expression contains the string with the day that you need to format.
  • type: The data type to which you are casting. Must include the day part.
  • format_string_expression: A string which contains format elements, including the day format element. The formats elements in this string are defined collectively as the format model, which must follow these rules.

These data types include a day part:

  • DATE
  • DATETIME
  • TIMESTAMP

If the DAY part is missing from string_expression and the return type includes this part, DAY is set to 1.

An error is generated if a value that is not a supported format element appears in format_string_expression or string_expression does not contain a value specified by a format element.

Format element Returns Example
DD Matches 2 digits. Sets the day part to the matched number. Input for MONTH DD, YYYY: 'DECEMBER 03, 2018'
Output as DATE: 2018-12-03

Return type

The data type to which the string was cast. This can be:

  • DATE
  • DATETIME
  • TIMESTAMP

Examples

SELECT CAST('DECEMBER 03, 2018' AS DATE FORMAT 'MONTH DD, YYYY') AS string_to_date_time

+---------------------+
| string_to_date_time |
+---------------------+
| 2018-12-03          |
+---------------------+

Format string as hour part

CAST(string_expression AS type FORMAT format_string_expression)

Casts a string-formatted hour to a data type that contains the hour part. Includes format elements, which provide instructions for how to conduct the cast.

  • string_expression: This expression contains the string with the hour that you need to format.
  • type: The data type to which you are casting. Must include the hour part.
  • format_string_expression: A string which contains format elements, including the hour format element. The formats elements in this string are defined collectively as the format model, which must follow these rules.

These data types include a hour part:

  • TIME
  • DATETIME
  • TIMESTAMP

If the HOUR part is missing from string_expression and the return type includes this part, HOUR is set to 0.

An error is generated if a value that is not a supported format element appears in format_string_expression or string_expression does not contain a value specified by a format element.

Format element Returns Example
HH Matches 2 digits. If the matched number n is 12, sets temp = 0; otherwise, sets temp = n. If the matched value of the A.M./P.M. format element is P.M., sets temp = n + 12. Sets the hour part to temp. A meridian indicator must be present in the format model, when HH is present. Input for HH:MI P.M.: '03:30 P.M.'
Output as TIME: 15:30:00
HH12 Same behavior as HH.
HH24 Matches 2 digits. Sets the hour part to the matched number. Input for HH24:MI: '15:30'
Output as TIME: 15:30:00

Return type

The data type to which the string was cast. This can be:

  • TIME
  • DATETIME
  • TIMESTAMP

Examples

SELECT CAST('15:30' AS TIME FORMAT 'HH24:MI') AS string_to_date_time

+---------------------+
| string_to_date_time |
+---------------------+
| 15:30:00            |
+---------------------+

Format string as minute part

CAST(string_expression AS type FORMAT format_string_expression)

Casts a string-formatted minute to a data type that contains the minute part. Includes format elements, which provide instructions for how to conduct the cast.

  • string_expression: This expression contains the string with the minute that you need to format.
  • type: The data type to which you are casting. Must include the minute part.
  • format_string_expression: A string which contains format elements, including the minute format element. The formats elements in this string are defined collectively as the format model, which must follow these rules.

These data types include a minute part:

  • TIME
  • DATETIME
  • TIMESTAMP

If the MINUTE part is missing from string_expression and the return type includes this part, MINUTE is set to 0.

An error is generated if a value that is not a supported format element appears in format_string_expression or string_expression does not contain a value specified by a format element.

Format element Returns Example
MI Matches 2 digits. Sets the minute part to the matched number. Input for HH:MI P.M.: '03:30 P.M.'
Output as TIME: 15:30:00

Return type

The data type to which the string was cast. This can be:

  • TIME
  • DATETIME
  • TIMESTAMP

Examples

SELECT CAST('03:30 P.M.' AS TIME FORMAT 'HH:MI P.M.') AS string_to_date_time

+---------------------+
| string_to_date_time |
+---------------------+
| 15:30:00            |
+---------------------+

Format string as second part

CAST(string_expression AS type FORMAT format_string_expression)

Casts a string-formatted second to a data type that contains the second part. Includes format elements, which provide instructions for how to conduct the cast.

  • string_expression: This expression contains the string with the second that you need to format.
  • type: The data type to which you are casting. Must include the second part.
  • format_string_expression: A string which contains format elements, including the second format element. The formats elements in this string are defined collectively as the format model, which must follow these rules.

These data types include a second part:

  • TIME
  • DATETIME
  • TIMESTAMP

If the SECOND part is missing from string_expression and the return type includes this part, SECOND is set to 0.

An error is generated if a value that is not a supported format element appears in format_string_expression or string_expression does not contain a value specified by a format element.

Format element Returns Example
SS Matches 2 digits. Sets the second part to the matched number. Input for HH:MI:SS P.M.: '03:30:02 P.M.'
Output as TIME: 15:30:02
SSSSS Matches 5 digits. Sets the hour, minute and second parts by interpreting the matched number as the number of seconds past midnight. Input for SSSSS: '03723'
Output as TIME: 01:02:03
FFn Matches n digits, where n is the number following FF in the format element. Sets the fractional part of the second part to the matched number. Input for HH24:MI:SS.FF1: '01:05:07.16'
Output as TIME: 01:05:07.2
Input for HH24:MI:SS.FF2: '01:05:07.16'
Output as TIME: 01:05:07.16
Input for HH24:MI:SS.FF3: 'FF3: 01:05:07.16'
Output as TIME: 01:05:07.160

Return type

The data type to which the string was cast. This can be:

  • TIME
  • DATETIME
  • TIMESTAMP

Examples

SELECT CAST('01:05:07.16' AS TIME FORMAT 'HH24:MI:SS.FF1') AS string_to_date_time

+---------------------+
| string_to_date_time |
+---------------------+
| 01:05:07.2          |
+---------------------+

Format string as meridian indicator part

CAST(string_expression AS type FORMAT format_string_expression)

Casts a string-formatted meridian indicator to a data type that contains the meridian indicator part. Includes format elements, which provide instructions for how to conduct the cast.

  • string_expression: This expression contains the string with the meridian indicator that you need to format.
  • type: The data type to which you are casting. Must include the meridian indicator part.
  • format_string_expression: A string which contains format elements, including the meridian indicator format element. The formats elements in this string are defined collectively as the format model, which must follow these rules.

These data types include a meridian indicator part:

  • TIME
  • DATETIME
  • TIMESTAMP

An error is generated if a value that is not a supported format element appears in format_string_expression or string_expression does not contain a value specified by a format element.

Format element Returns Example
A.M. or P.M. Matches using the regular expression '(A|P)\.M\.'. Input for HH:MI A.M.: '03:30 A.M.'
Output as TIME: 03:30:00
Input for HH:MI P.M.: '03:30 P.M.'
Output as TIME: 15:30:00
Input for HH:MI P.M.: '03:30 A.M.'
Output as TIME: 03:30:00
Input for HH:MI A.M.: '03:30 P.M.'
Output as TIME: 15:30:00
Input for HH:MI a.m.: '03:30 a.m.'
Output as TIME: 03:30:00

Return type

The data type to which the string was cast. This can be:

  • TIME
  • DATETIME
  • TIMESTAMP

Examples

SELECT CAST('03:30 P.M.' AS TIME FORMAT 'HH:MI A.M.') AS string_to_date_time

+---------------------+
| string_to_date_time |
+---------------------+
| 15:30:00            |
+---------------------+

Format string as time zone part

CAST(string_expression AS type FORMAT format_string_expression)

Casts a string-formatted time zone to a data type that contains the time zone part. Includes format elements, which provide instructions for how to conduct the cast.

  • string_expression: This expression contains the string with the time zone that you need to format.
  • type: The data type to which you are casting. Must include the time zone part.
  • format_string_expression: A string which contains format elements, including the time zone format element. The formats elements in this string are defined collectively as the format model, which must follow these rules.

These data types include a time zone part:

  • DATE
  • TIME
  • DATETIME
  • TIMESTAMP

An error is generated if a value that is not a supported format element appears in format_string_expression or string_expression does not contain a value specified by a format element.

Format element Returns Example
TZH Matches using the regular expression '(\+|\-| )[0-9]{2}'. Sets the time zone and hour parts to the matched sign and number. Sets the time zone sign to be the first letter of the matched string. The number 2 means matching up to 2 digits for non-exact matching, and exactly 2 digits for exact matching. Input for YYYY-MM-DD HH:MI:SSTZH: '2008-12-25 05:30:00-08'
Output as TIMESTAMP: 2008-12-25 05:30:00-08
TZM Matches 2 digits. Let n be the matched number. If the time zone sign is the minus sign, sets the time zone minute part to -n. Otherwise, sets the time zone minute part to n. Input for YYYY-MM-DD HH:MI:SSTZH: '2008-12-25 05:30:00+05.30'
Output as TIMESTAMP: 2008-12-25 05:30:00+05.30

Return type

The data type to which the string was cast. This can be:

  • DATE
  • TIME
  • DATETIME
  • TIMESTAMP

Examples

SELECT CAST('2020.06.03 00:00:53+00' AS TIMESTAMP FORMAT 'YYYY.MM.DD HH:MI:SSTZH') AS string_to_date_time

+-----------------------------+
| as_timestamp                |
+-----------------------------+
| 2020-06-03 00:00:53.110 UTC |
+-----------------------------+

Format string as literal

CAST(string_expression AS data_type FORMAT format_string_expression)
Format element Returns Example
- Output is the same as the input.
. Output is the same as the input. .
/ Output is the same as the input. /
, Output is the same as the input. ,
' Output is the same as the input. '
; Output is the same as the input. ;
: Output is the same as the input. :
Whitespace A consecutive sequence of one or more spaces in the format model is matched with one or more consecutive Unicode whitespace characters in the input. Space means the ASCII 32 space character. It does not mean the general whitespace such as a tab or new line. Any whitespace character that is not the ASCII 32 character in the format model generates an error.
"text" Output generated by the format element in formatting, using this regular expression, with s representing the string input: regex.escape(s). Input: "abc"
Output: abc
Input: "a\"b\\c"
Output: a"b\c

Format numeric type as string

CAST(numeric_expression AS STRING FORMAT format_string_expression)

You can cast a numeric type to a string by combining the following format elements:

Except for the exponent format element (EEEE), all of the format elements generate a fixed number of characters in the output, and the output is aligned by the decimal point. To suppress blank characters and trailing zeroes, use the FM flag.

Return type

STRING

Example

SELECT input, CAST(input AS STRING FORMAT '$999,999.999') AS output
FROM UNNEST([1.2, 12.3, 123.456, 1234.56, -12345.678, 1234567.89]) AS input

+------------+---------------+
|   input    |    output     |
+------------+---------------+
|        1.2 |        $1.200 |
|       12.3 |       $12.300 |
|    123.456 |      $123.456 |
|    1234.56 |    $1,234.560 |
| -12345.678 |  -$12,345.678 |
| 1234567.89 |  $###,###.### |
+------------+---------------+

Format digits as string

The following format elements output digits. If there aren't enough digit format elements to represent the input, all digit format elements are replaced with # in the output.

Format element Returns Example
0 A decimal digit. Leading and trailing zeros are included. Input: 12
Format: '000'
Output: ' 012'
Input: 12
Format: '000.000'
Output: ' 012.000'
Input: -12
Format: '000.000'
Output: '-012.000'
9 A decimal digit. Leading zeros are replaced with spaces. Trailing zeros are included. Input: 12
Format: '999'
Output: '  12'
Input: 12
Format: '999.999'
Output: '  12.000'
X or x

A hexadecimal digit. Cannot appear with other format elements except 0, FM, and the sign format elements. The maximum number of hexadecimal digits in the format string is 16.

X generates uppercase letters and x generates lowercase letters.

When 0 is combined with the hexadecimal format element, the letter generated by 0 matches the case of the next X or x element. If there is no subsequent X or x, then 0 generates an uppercase letter.

Input: 43981
Format: 'XXXX'
Output: ' ABCD'
Input: 43981
Format: 'xxxx'
Output: ' abcd'
Input: 43981
Format: '0X0x'
Output: ' ABcd'
Input: 43981
Format: '0000000X'
Output: ' 0000ABCD'

Return type

STRING

Example

SELECT
  CAST(12 AS STRING FORMAT '999') as a,
  CAST(-12 AS STRING FORMAT '999') as b;

+------+------+
|  a   |  b   |
+------+------+
|   12 |  -12 |
+------+------+

Format decimal point as string

The following format elements output a decimal point. These format elements are mutually exclusive. At most one can appear in the format string.

Format element Returns Example
. (period) Decimal point. Input: 123.58
Format: '999.999'
Output: ' 123.580'
D The decimal point of the current locale. Input: 123.58
Format: '999D999'
Output: ' 123.580'

Return type

STRING

Example

SELECT CAST(12.5 AS STRING FORMAT '99.99') as a;

+--------+
|   a    |
+--------+
|  12.50 |
+--------+

Format sign as string

The following format elements output the sign (+/-). These format elements are mutually exclusive. At most one can appear in the format string.

If there are no sign format elements, one extra space is reserved for the sign. For example, if the input is 12 and the format string is '99', then the output is ' 12', with a length of three characters.

The sign appears before the number. If the format model includes a currency symbol element, then the sign appears before the currency symbol.

Format element Returns Example
S Explicit sign. Outputs + for positive numbers and - for negative numbers. The position in the output is anchored to the number. Input: -12
Format: 'S9999'
Output: '  -12'
Input: -12
Format: '9999S'
Output: '  12-'
MI Explicit sign. Outputs a space for positive numbers and - for negative numbers. This element can only appear in the last position. Input: 12
Format: '9999MI'
Output: '  12 '
Input: -12
Format: '9999MI'
Output: '  12-'
PR For negative numbers, the value is enclosed in angle brackets. For positive numbers, the value is returned with a leading and trailing space. This element can only appear in the last position. Input: 12
Format: '9999PR'
Output: '   12 '
Input: -12
Format: '9999PR'
Output: '  <12>'

Return type

STRING

Example

SELECT
  CAST(12 AS STRING FORMAT 'S99') as a,
  CAST(-12 AS STRING FORMAT 'S99') as b;

+-----+-----+
|  a  |  b  |
+-----+-----+
| +12 | -12 |
+-----+-----+

Format currency symbol as string

The following format elements output a currency symbol. These format elements are mutually exclusive. At most one can appear in the format string. In the output, the currency symbol appears before the first digit or decimal point.

Format element Returns Example
$ Dollar sign ($). Input: -12
Format: '$999'
Output: ' -$12'
C or c The ISO-4217 currency code of the current locale. Input: -12
Format: 'C999'
Output: ' -USD12'
Input: -12
Format: 'c999'
Output: ' -usd12'
L The currency symbol of the current locale. Input: -12
Format: 'L999'
Output: ' -$12'

Return type

STRING

Example

SELECT
  CAST(12 AS STRING FORMAT '$99') as a,
  CAST(-12 AS STRING FORMAT '$99') as b;

+------+------+
|  a   |  b   |
+------+------+
|  $12 | -$12 |
+------+------+

Format group separator as string

The following format elements output a group separator.

Format element Returns Example
, (comma) Group separator. Input: 12345
Format: '999,999'
Output: '  12,345'
G The group separator point of the current locale. Input: 12345
Format: '999G999'
Output: '  12,345'

Return type

STRING

Example

SELECT CAST(1234 AS STRING FORMAT '999,999') as a;

+----------+
|    a     |
+----------+
|    1,234 |
+----------+

Other numeric format elements

Format element Returns Example
B Outputs spaces when the integer part is zero. If the integer part of the number is 0, then the following format elements generate spaces in the output: digits (9, X, 0), decimal point, group separator, currency, sign, and exponent. Input: 0.23
Format: 'B99.999S'
Output: '       '
Input: 1.23
Format: 'B99.999S'
Output: ' 1.230+'
EEEE Outputs the exponent part of the value in scientific notation. If the exponent value is between -99 and 99, the output is four characters. Otherwise, the minimum number of digits is used in the output. Input: 20
Format: '9.99EEEE'
Output: ' 2.0E+01'
Input: 299792458
Format: 'S9.999EEEE'
Output: '+2.998E+08'
FM Removes all spaces and trailing zeroes from the output. You can use this element to suppress spaces and trailing zeroes that are generated by other format elements. Input: 12.5
Format: '999999.000FM'
Output: '12.5'
RN Returns the value as Roman numerals, rounded to the nearest integer. The input must be between 1 and 3999. The output is padded with spaces to the left to a length of 15. This element cannot be used with other format elements except FM. Input: 2021
Format: 'RN'
Output: '          MMXXI'
V The input value is multiplied by 10^n, where n is the number of 9s after the V. This element cannot be used with a decimal point or exponent format element. Input: 23.5
Format: 'S000V00'
Output: '+02350'

Return type

STRING

Example

SELECT CAST(-123456 AS STRING FORMAT '9.999EEEE') as a;"

+------------+
|     a      |
+------------+
| -1.235E+05 |
+------------+

About BASE encoding

BASE encoding translates binary data in string format into a radix-X representation.

If X is 2, 8, or 16, Arabic numerals 0–9 and the Latin letters a–z are used in the encoded string. So for example, BASE16/Hexadecimal encoding results contain 0~9 and a~f).

If X is 32 or 64, the default character tables are defined in rfc 4648. When you decode a BASE string where X is 2, 8, or 16, the Latin letters in the input string are case-insensitive. For example, both "3a" and "3A" are valid input strings for BASE16/Hexadecimal decoding, and will output the same result.

Mathematical functions

All mathematical functions have the following behaviors:

  • They return NULL if any of the input parameters is NULL.
  • They return NaN if any of the arguments is NaN.

ABS

ABS(X)

Description

Computes absolute value. Returns an error if the argument is an integer and the output value cannot be represented as the same type; this happens only for the largest negative input value, which has no positive representation.

X ABS(X)
25 25
-25 25
+inf +inf
-inf +inf

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTINT64NUMERICBIGNUMERICFLOAT64

SIGN

SIGN(X)

Description

Returns -1, 0, or +1 for negative, zero and positive arguments respectively. For floating point arguments, this function does not distinguish between positive and negative zero.

X SIGN(X)
25 +1
0 0
-25 -1
NaN NaN

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTINT64NUMERICBIGNUMERICFLOAT64

IS_INF

IS_INF(X)

Description

Returns TRUE if the value is positive or negative infinity.

X IS_INF(X)
+inf TRUE
-inf TRUE
25 FALSE

IS_NAN

IS_NAN(X)

Description

Returns TRUE if the value is a NaN value.

X IS_NAN(X)
NaN TRUE
25 FALSE

IEEE_DIVIDE

IEEE_DIVIDE(X, Y)

Description

Divides X by Y; this function never fails. Returns FLOAT64. Unlike the division operator (/), this function does not generate errors for division by zero or overflow.

X Y IEEE_DIVIDE(X, Y)
20.0 4.0 5.0
0.0 25.0 0.0
25.0 0.0 +inf
-25.0 0.0 -inf
0.0 0.0 NaN
0.0 NaN NaN
NaN 0.0 NaN
+inf +inf NaN
-inf -inf NaN

RAND

RAND()

Description

Generates a pseudo-random value of type FLOAT64 in the range of [0, 1), inclusive of 0 and exclusive of 1.

SQRT

SQRT(X)

Description

Computes the square root of X. Generates an error if X is less than 0.

X SQRT(X)
25.0 5.0
+inf +inf
X < 0 Error

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64

POW

POW(X, Y)

Description

Returns the value of X raised to the power of Y. If the result underflows and is not representable, then the function returns a value of zero.

X Y POW(X, Y)
2.0 3.0 8.0
1.0 Any value including NaN 1.0
Any value including NaN 0 1.0
-1.0 +inf 1.0
-1.0 -inf 1.0
ABS(X) < 1 -inf +inf
ABS(X) > 1 -inf 0.0
ABS(X) < 1 +inf 0.0
ABS(X) > 1 +inf +inf
-inf Y < 0 0.0
-inf Y > 0 -inf if Y is an odd integer, +inf otherwise
+inf Y < 0 0
+inf Y > 0 +inf
Finite value < 0 Non-integer Error
0 Finite value < 0 Error

Return Data Type

The return data type is determined by the argument types with the following table.

INPUTINT64NUMERICBIGNUMERICFLOAT64
INT64FLOAT64NUMERICBIGNUMERICFLOAT64
NUMERICNUMERICNUMERICBIGNUMERICFLOAT64
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERICFLOAT64
FLOAT64FLOAT64FLOAT64FLOAT64FLOAT64

POWER

POWER(X, Y)

Description

Synonym of POW(X, Y).

EXP

EXP(X)

Description

Computes e to the power of X, also called the natural exponential function. If the result underflows, this function returns a zero. Generates an error if the result overflows.

X EXP(X)
0.0 1.0
+inf +inf
-inf 0.0

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64

LN

LN(X)

Description

Computes the natural logarithm of X. Generates an error if X is less than or equal to zero.

X LN(X)
1.0 0.0
+inf +inf
X < 0 Error

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64

LOG

LOG(X [, Y])

Description

If only X is present, LOG is a synonym of LN. If Y is also present, LOG computes the logarithm of X to base Y.

X Y LOG(X, Y)
100.0 10.0 2.0
-inf Any value NaN
Any value +inf NaN
+inf 0.0 < Y < 1.0 -inf
+inf Y > 1.0 +inf
X <= 0 Any value Error
Any value Y <= 0 Error
Any value 1.0 Error

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
INT64FLOAT64NUMERICBIGNUMERICFLOAT64
NUMERICNUMERICNUMERICBIGNUMERICFLOAT64
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERICFLOAT64
FLOAT64FLOAT64FLOAT64FLOAT64FLOAT64

LOG10

LOG10(X)

Description

Similar to LOG, but computes logarithm to base 10.

X LOG10(X)
100.0 2.0
-inf NaN
+inf NaN
X <= 0 Error

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64

GREATEST

GREATEST(X1,...,XN)

Description

Returns the largest value among X1,...,XN according to the < comparison. If any parts of X1,...,XN are NULL, the return value is NULL.

X1,...,XN GREATEST(X1,...,XN)
3,5,1 5

Return Data Types

Data type of the input values.

LEAST

LEAST(X1,...,XN)

Description

Returns the smallest value among X1,...,XN according to the > comparison. If any parts of X1,...,XN are NULL, the return value is NULL.

X1,...,XN LEAST(X1,...,XN)
3,5,1 1

Return Data Types

Data type of the input values.

DIV

DIV(X, Y)

Description

Returns the result of integer division of X by Y. Division by zero returns an error. Division by -1 may overflow.

X Y DIV(X, Y)
20 4 5
0 20 0
20 0 Error

Return Data Type

The return data type is determined by the argument types with the following table.

INPUTINT64NUMERICBIGNUMERIC
INT64INT64NUMERICBIGNUMERIC
NUMERICNUMERICNUMERICBIGNUMERIC
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERIC

SAFE_DIVIDE

SAFE_DIVIDE(X, Y)

Description

Equivalent to the division operator (X / Y), but returns NULL if an error occurs, such as a division by zero error.

XYSAFE_DIVIDE(X, Y)
2045
0200
200NULL

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
INT64FLOAT64NUMERICBIGNUMERICFLOAT64
NUMERICNUMERICNUMERICBIGNUMERICFLOAT64
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERICFLOAT64
FLOAT64FLOAT64FLOAT64FLOAT64FLOAT64

SAFE_MULTIPLY

SAFE_MULTIPLY(X, Y)

Description

Equivalent to the multiplication operator (*), but returns NULL if overflow occurs.

XYSAFE_MULTIPLY(X, Y)
20480

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
INT64INT64NUMERICBIGNUMERICFLOAT64
NUMERICNUMERICNUMERICBIGNUMERICFLOAT64
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERICFLOAT64
FLOAT64FLOAT64FLOAT64FLOAT64FLOAT64

SAFE_NEGATE

SAFE_NEGATE(X)

Description

Equivalent to the unary minus operator (-), but returns NULL if overflow occurs.

XSAFE_NEGATE(X)
+1-1
-1+1
00

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTINT64NUMERICBIGNUMERICFLOAT64

SAFE_ADD

SAFE_ADD(X, Y)

Description

Equivalent to the addition operator (+), but returns NULL if overflow occurs.

XYSAFE_ADD(X, Y)
549

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
INT64INT64NUMERICBIGNUMERICFLOAT64
NUMERICNUMERICNUMERICBIGNUMERICFLOAT64
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERICFLOAT64
FLOAT64FLOAT64FLOAT64FLOAT64FLOAT64

SAFE_SUBTRACT

SAFE_SUBTRACT(X, Y)

Description

Returns the result of Y subtracted from X. Equivalent to the subtraction operator (-), but returns NULL if overflow occurs.

XYSAFE_SUBTRACT(X, Y)
541

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
INT64INT64NUMERICBIGNUMERICFLOAT64
NUMERICNUMERICNUMERICBIGNUMERICFLOAT64
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERICFLOAT64
FLOAT64FLOAT64FLOAT64FLOAT64FLOAT64

MOD

MOD(X, Y)

Description

Modulo function: returns the remainder of the division of X by Y. Returned value has the same sign as X. An error is generated if Y is 0.

X Y MOD(X, Y)
25 12 1
25 0 Error

Return Data Type

The return data type is determined by the argument types with the following table.

INPUTINT64NUMERICBIGNUMERIC
INT64INT64NUMERICBIGNUMERIC
NUMERICNUMERICNUMERICBIGNUMERIC
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERIC

ROUND

ROUND(X [, N])

Description

If only X is present, ROUND rounds X to the nearest integer. If N is present, ROUND rounds X to N decimal places after the decimal point. If N is negative, ROUND will round off digits to the left of the decimal point. Rounds halfway cases away from zero. Generates an error if overflow occurs.

X ROUND(X)
2.0 2.0
2.3 2.0
2.8 3.0
2.5 3.0
-2.3 -2.0
-2.8 -3.0
-2.5 -3.0
0 0
+inf +inf
-inf -inf
NaN NaN

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64

TRUNC

TRUNC(X [, N])

Description

If only X is present, TRUNC rounds X to the nearest integer whose absolute value is not greater than the absolute value of X. If N is also present, TRUNC behaves like ROUND(X, N), but always rounds towards zero and never overflows.

X TRUNC(X)
2.0 2.0
2.3 2.0
2.8 2.0
2.5 2.0
-2.3 -2.0
-2.8 -2.0
-2.5 -2.0
0 0
+inf +inf
-inf -inf
NaN NaN

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64

CEIL

CEIL(X)

Description

Returns the smallest integral value that is not less than X.

X CEIL(X)
2.0 2.0
2.3 3.0
2.8 3.0
2.5 3.0
-2.3 -2.0
-2.8 -2.0
-2.5 -2.0
0 0
+inf +inf
-inf -inf
NaN NaN

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64

CEILING

CEILING(X)

Description

Synonym of CEIL(X)

FLOOR

FLOOR(X)

Description

Returns the largest integral value that is not greater than X.

X FLOOR(X)
2.0 2.0
2.3 2.0
2.8 2.0
2.5 2.0
-2.3 -3.0
-2.8 -3.0
-2.5 -3.0
0 0
+inf +inf
-inf -inf
NaN NaN

Return Data Type

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64

COS

COS(X)

Description

Computes the cosine of X where X is specified in radians. Never fails.

X COS(X)
+inf NaN
-inf NaN
NaN NaN

COSH

COSH(X)

Description

Computes the hyperbolic cosine of X where X is specified in radians. Generates an error if overflow occurs.

X COSH(X)
+inf +inf
-inf +inf
NaN NaN

ACOS

ACOS(X)

Description

Computes the principal value of the inverse cosine of X. The return value is in the range [0,π]. Generates an error if X is a value outside of the range [-1, 1].

X ACOS(X)
+inf NaN
-inf NaN
NaN NaN
X < -1 Error
X > 1 Error

ACOSH

ACOSH(X)

Description

Computes the inverse hyperbolic cosine of X. Generates an error if X is a value less than 1.

X ACOSH(X)
+inf +inf
-inf NaN
NaN NaN
X < 1 Error

SIN

SIN(X)

Description

Computes the sine of X where X is specified in radians. Never fails.

X SIN(X)
+inf NaN
-inf NaN
NaN NaN

SINH

SINH(X)

Description

Computes the hyperbolic sine of X where X is specified in radians. Generates an error if overflow occurs.

X SINH(X)
+inf +inf
-inf -inf
NaN NaN

ASIN

ASIN(X)

Description

Computes the principal value of the inverse sine of X. The return value is in the range [-π/2,π/2]. Generates an error if X is outside of the range [-1, 1].

X ASIN(X)
+inf NaN
-inf NaN
NaN NaN
X < -1 Error
X > 1 Error

ASINH

ASINH(X)

Description

Computes the inverse hyperbolic sine of X. Does not fail.

X ASINH(X)
+inf +inf
-inf -inf
NaN NaN

TAN

TAN(X)

Description

Computes the tangent of X where X is specified in radians. Generates an error if overflow occurs.

X TAN(X)
+inf NaN
-inf NaN
NaN NaN

TANH

TANH(X)

Description

Computes the hyperbolic tangent of X where X is specified in radians. Does not fail.

X TANH(X)
+inf 1.0
-inf -1.0
NaN NaN

ATAN

ATAN(X)

Description

Computes the principal value of the inverse tangent of X. The return value is in the range [-π/2,π/2]. Does not fail.

X ATAN(X)
+inf π/2
-inf -π/2
NaN NaN

ATANH

ATANH(X)

Description

Computes the inverse hyperbolic tangent of X. Generates an error if X is outside of the range [-1, 1].

X ATANH(X)
+inf NaN
-inf NaN
NaN NaN
X < -1 Error
X > 1 Error

ATAN2

ATAN2(X, Y)

Description

Calculates the principal value of the inverse tangent of X/Y using the signs of the two arguments to determine the quadrant. The return value is in the range [-π,π].

X Y ATAN2(X, Y)
NaN Any value NaN
Any value NaN NaN
0.0 0.0 0.0
Positive Finite value -inf π
Negative Finite value -inf
Finite value +inf 0.0
+inf Finite value π/2
-inf Finite value -π/2
+inf -inf ¾π
-inf -inf -¾π
+inf +inf π/4
-inf +inf -π/4

RANGE_BUCKET

RANGE_BUCKET(point, boundaries_array)

Description

RANGE_BUCKET scans through a sorted array and returns the 0-based position of the point's upper bound. This can be useful if you need to group your data to build partitions, histograms, business-defined rules, and more.

RANGE_BUCKET follows these rules:

  • If the point exists in the array, returns the index of the next larger value.

    RANGE_BUCKET(20, [0, 10, 20, 30, 40]) -- 3 is return value
    RANGE_BUCKET(20, [0, 10, 20, 20, 40, 40]) -- 4 is return value
    
  • If the point does not exist in the array, but it falls between two values, returns the index of the larger value.

    RANGE_BUCKET(25, [0, 10, 20, 30, 40]) -- 3 is return value
    
  • If the point is smaller than the first value in the array, returns 0.

    RANGE_BUCKET(-10, [5, 10, 20, 30, 40]) -- 0 is return value
    
  • If the point is greater than or equal to the last value in the array, returns the length of the array.

    RANGE_BUCKET(80, [0, 10, 20, 30, 40]) -- 5 is return value
    
  • If the array is empty, returns 0.

    RANGE_BUCKET(80, []) -- 0 is return value
    
  • If the point is NULL or NaN, returns NULL.

    RANGE_BUCKET(NULL, [0, 10, 20, 30, 40]) -- NULL is return value
    
  • The data type for the point and array must be compatible.

    RANGE_BUCKET('a', ['a', 'b', 'c', 'd']) -- 1 is return value
    RANGE_BUCKET(1.2, [1, 1.2, 1.4, 1.6]) -- 2 is return value
    RANGE_BUCKET(1.2, [1, 2, 4, 6]) -- execution failure
    

Execution failure occurs when:

  • The array has a NaN or NULL value in it.

    RANGE_BUCKET(80, [NULL, 10, 20, 30, 40]) -- execution failure
    
  • The array is not sorted in ascending order.

    RANGE_BUCKET(30, [10, 30, 20, 40, 50]) -- execution failure
    

Parameters

  • point: A generic value.
  • boundaries_array: A generic array of values.

Return Value

INT64

Examples

In a table called students, check to see how many records would exist in each age_group bucket, based on a student's age:

  • age_group 0 (age < 10)
  • age_group 1 (age >= 10, age < 20)
  • age_group 2 (age >= 20, age < 30)
  • age_group 3 (age >= 30)
WITH students AS
(
  SELECT 9 AS age UNION ALL
  SELECT 20 AS age UNION ALL
  SELECT 25 AS age UNION ALL
  SELECT 31 AS age UNION ALL
  SELECT 32 AS age UNION ALL
  SELECT 33 AS age
)
SELECT RANGE_BUCKET(age, [10, 20, 30]) AS age_group, COUNT(*) AS count
FROM students
GROUP BY 1

+--------------+-------+
| age_group    | count |
+--------------+-------+
| 0            | 1     |
| 2            | 2     |
| 3            | 3     |
+--------------+-------+

The following sections describe the navigation functions that BigQuery supports. Navigation functions are a subset of analytic functions. For an explanation of how analytic functions work, see Analytic Function Concepts. For an explanation of how navigation functions work, see Navigation Function Concepts.

FIRST_VALUE

FIRST_VALUE (value_expression [{RESPECT | IGNORE} NULLS])

Description

Returns the value of the value_expression for the first row in the current window frame.

This function includes NULL values in the calculation unless IGNORE NULLS is present. If IGNORE NULLS is present, the function excludes NULL values from the calculation.

Supported Argument Types

value_expression can be any data type that an expression can return.

Return Data Type

Same type as value_expression.

Examples

The following example computes the fastest time for each division.

WITH finishers AS
 (SELECT 'Sophia Liu' as name,
  TIMESTAMP '2016-10-18 2:51:45' as finish_time,
  'F30-34' as division
  UNION ALL SELECT 'Lisa Stelzner', TIMESTAMP '2016-10-18 2:54:11', 'F35-39'
  UNION ALL SELECT 'Nikki Leith', TIMESTAMP '2016-10-18 2:59:01', 'F30-34'
  UNION ALL SELECT 'Lauren Matthews', TIMESTAMP '2016-10-18 3:01:17', 'F35-39'
  UNION ALL SELECT 'Desiree Berry', TIMESTAMP '2016-10-18 3:05:42', 'F35-39'
  UNION ALL SELECT 'Suzy Slane', TIMESTAMP '2016-10-18 3:06:24', 'F35-39'
  UNION ALL SELECT 'Jen Edwards', TIMESTAMP '2016-10-18 3:06:36', 'F30-34'
  UNION ALL SELECT 'Meghan Lederer', TIMESTAMP '2016-10-18 3:07:41', 'F30-34'
  UNION ALL SELECT 'Carly Forte', TIMESTAMP '2016-10-18 3:08:58', 'F25-29'
  UNION ALL SELECT 'Lauren Reasoner', TIMESTAMP '2016-10-18 3:10:14', 'F30-34')
SELECT name,
  FORMAT_TIMESTAMP('%X', finish_time) AS finish_time,
  division,
  FORMAT_TIMESTAMP('%X', fastest_time) AS fastest_time,
  TIMESTAMP_DIFF(finish_time, fastest_time, SECOND) AS delta_in_seconds
FROM (
  SELECT name,
  finish_time,
  division,
  FIRST_VALUE(finish_time)
    OVER (PARTITION BY division ORDER BY finish_time ASC
    ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS fastest_time
  FROM finishers);

+-----------------+-------------+----------+--------------+------------------+
| name            | finish_time | division | fastest_time | delta_in_seconds |
+-----------------+-------------+----------+--------------+------------------+
| Carly Forte     | 03:08:58    | F25-29   | 03:08:58     | 0                |
| Sophia Liu      | 02:51:45    | F30-34   | 02:51:45     | 0                |
| Nikki Leith     | 02:59:01    | F30-34   | 02:51:45     | 436              |
| Jen Edwards     | 03:06:36    | F30-34   | 02:51:45     | 891              |
| Meghan Lederer  | 03:07:41    | F30-34   | 02:51:45     | 956              |
| Lauren Reasoner | 03:10:14    | F30-34   | 02:51:45     | 1109             |
| Lisa Stelzner   | 02:54:11    | F35-39   | 02:54:11     | 0                |
| Lauren Matthews | 03:01:17    | F35-39   | 02:54:11     | 426              |
| Desiree Berry   | 03:05:42    | F35-39   | 02:54:11     | 691              |
| Suzy Slane      | 03:06:24    | F35-39   | 02:54:11     | 733              |
+-----------------+-------------+----------+--------------+------------------+

LAST_VALUE

LAST_VALUE (value_expression [{RESPECT | IGNORE} NULLS])

Description

Returns the value of the value_expression for the last row in the current window frame.

This function includes NULL values in the calculation unless IGNORE NULLS is present. If IGNORE NULLS is present, the function excludes NULL values from the calculation.

Supported Argument Types

value_expression can be any data type that an expression can return.

Return Data Type

Same type as value_expression.

Examples

The following example computes the slowest time for each division.

WITH finishers AS
 (SELECT 'Sophia Liu' as name,
  TIMESTAMP '2016-10-18 2:51:45' as finish_time,
  'F30-34' as division
  UNION ALL SELECT 'Lisa Stelzner', TIMESTAMP '2016-10-18 2:54:11', 'F35-39'
  UNION ALL SELECT 'Nikki Leith', TIMESTAMP '2016-10-18 2:59:01', 'F30-34'
  UNION ALL SELECT 'Lauren Matthews', TIMESTAMP '2016-10-18 3:01:17', 'F35-39'
  UNION ALL SELECT 'Desiree Berry', TIMESTAMP '2016-10-18 3:05:42', 'F35-39'
  UNION ALL SELECT 'Suzy Slane', TIMESTAMP '2016-10-18 3:06:24', 'F35-39'
  UNION ALL SELECT 'Jen Edwards', TIMESTAMP '2016-10-18 3:06:36', 'F30-34'
  UNION ALL SELECT 'Meghan Lederer', TIMESTAMP '2016-10-18 3:07:41', 'F30-34'
  UNION ALL SELECT 'Carly Forte', TIMESTAMP '2016-10-18 3:08:58', 'F25-29'
  UNION ALL SELECT 'Lauren Reasoner', TIMESTAMP '2016-10-18 3:10:14', 'F30-34')
SELECT name,
  FORMAT_TIMESTAMP('%X', finish_time) AS finish_time,
  division,
  FORMAT_TIMESTAMP('%X', slowest_time) AS slowest_time,
  TIMESTAMP_DIFF(slowest_time, finish_time, SECOND) AS delta_in_seconds
FROM (
  SELECT name,
  finish_time,
  division,
  LAST_VALUE(finish_time)
    OVER (PARTITION BY division ORDER BY finish_time ASC
    ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS slowest_time
  FROM finishers);

+-----------------+-------------+----------+--------------+------------------+
| name            | finish_time | division | slowest_time | delta_in_seconds |
+-----------------+-------------+----------+--------------+------------------+
| Carly Forte     | 03:08:58    | F25-29   | 03:08:58     | 0                |
| Sophia Liu      | 02:51:45    | F30-34   | 03:10:14     | 1109             |
| Nikki Leith     | 02:59:01    | F30-34   | 03:10:14     | 673              |
| Jen Edwards     | 03:06:36    | F30-34   | 03:10:14     | 218              |
| Meghan Lederer  | 03:07:41    | F30-34   | 03:10:14     | 153              |
| Lauren Reasoner | 03:10:14    | F30-34   | 03:10:14     | 0                |
| Lisa Stelzner   | 02:54:11    | F35-39   | 03:06:24     | 733              |
| Lauren Matthews | 03:01:17    | F35-39   | 03:06:24     | 307              |
| Desiree Berry   | 03:05:42    | F35-39   | 03:06:24     | 42               |
| Suzy Slane      | 03:06:24    | F35-39   | 03:06:24     | 0                |
+-----------------+-------------+----------+--------------+------------------+

NTH_VALUE

NTH_VALUE (value_expression, constant_integer_expression [{RESPECT | IGNORE} NULLS])

Description

Returns the value of value_expression at the Nth row of the current window frame, where Nth is defined by constant_integer_expression. Returns NULL if there is no such row.

This function includes NULL values in the calculation unless IGNORE NULLS is present. If IGNORE NULLS is present, the function excludes NULL values from the calculation.

Supported Argument Types

  • value_expression can be any data type that can be returned from an expression.
  • constant_integer_expression can be any constant expression that returns an integer.

Return Data Type

Same type as value_expression.

Examples

WITH finishers AS
 (SELECT 'Sophia Liu' as name,
  TIMESTAMP '2016-10-18 2:51:45' as finish_time,
  'F30-34' as division
  UNION ALL SELECT 'Lisa Stelzner', TIMESTAMP '2016-10-18 2:54:11', 'F35-39'
  UNION ALL SELECT 'Nikki Leith', TIMESTAMP '2016-10-18 2:59:01', 'F30-34'
  UNION ALL SELECT 'Lauren Matthews', TIMESTAMP '2016-10-18 3:01:17', 'F35-39'
  UNION ALL SELECT 'Desiree Berry', TIMESTAMP '2016-10-18 3:05:42', 'F35-39'
  UNION ALL SELECT 'Suzy Slane', TIMESTAMP '2016-10-18 3:06:24', 'F35-39'
  UNION ALL SELECT 'Jen Edwards', TIMESTAMP '2016-10-18 3:06:36', 'F30-34'
  UNION ALL SELECT 'Meghan Lederer', TIMESTAMP '2016-10-18 3:07:41', 'F30-34'
  UNION ALL SELECT 'Carly Forte', TIMESTAMP '2016-10-18 3:08:58', 'F25-29'
  UNION ALL SELECT 'Lauren Reasoner', TIMESTAMP '2016-10-18 3:10:14', 'F30-34')
SELECT name,
  FORMAT_TIMESTAMP('%X', finish_time) AS finish_time,
  division,
  FORMAT_TIMESTAMP('%X', fastest_time) AS fastest_time,
  FORMAT_TIMESTAMP('%X', second_fastest) AS second_fastest
FROM (
  SELECT name,
  finish_time,
  division,finishers,
  FIRST_VALUE(finish_time)
    OVER w1 AS fastest_time,
  NTH_VALUE(finish_time, 2)
    OVER w1 as second_fastest
  FROM finishers
  WINDOW w1 AS (
    PARTITION BY division ORDER BY finish_time ASC
    ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING));

+-----------------+-------------+----------+--------------+----------------+
| name            | finish_time | division | fastest_time | second_fastest |
+-----------------+-------------+----------+--------------+----------------+
| Carly Forte     | 03