Functions, operators, and conditionals

Stay organized with collections Save and categorize content based on your preferences.

This topic is a compilation of functions, operators, and conditional expressions.

To learn more about how to call functions, function call rules, the SAFE prefix, and special types of arguments, see Function calls.


OPERATORS AND CONDITIONALS

Operators

Google Standard SQL for BigQuery supports operators. Operators are represented by special characters or keywords; they do not use function call syntax. An operator manipulates any number of data inputs, also called operands, and returns a result.

Common conventions:

  • Unless otherwise specified, all operators return NULL when one of the operands is NULL.
  • All operators will throw an error if the computation result overflows.
  • For all floating point operations, +/-inf and NaN may only be returned if one of the operands is +/-inf or NaN. In other cases, an error is returned.

Operator precedence

The following table lists all Google Standard SQL operators from highest to lowest precedence, i.e. the order in which they will be evaluated within a statement.

Order of Precedence Operator Input Data Types Name Operator Arity
1 Field access operator JSON
STRUCT
Field access operator Binary
  Array subscript operator ARRAY Array position. Must be used with OFFSET or ORDINAL—see Array Functions . Binary
  JSON subscript operator JSON Field name or array position in JSON. Binary
2 + All numeric types Unary plus Unary
  - All numeric types Unary minus Unary
  ~ Integer or BYTES Bitwise not Unary
3 * All numeric types Multiplication Binary
  / All numeric types Division Binary
  || STRING, BYTES, or ARRAY<T> Concatenation operator Binary
4 + All numeric types, DATE with INT64 , INTERVAL Addition Binary
  - All numeric types, DATE with INT64 , INTERVAL Subtraction Binary
5 << Integer or BYTES Bitwise left-shift Binary
  >> Integer or BYTES Bitwise right-shift Binary
6 & Integer or BYTES Bitwise and Binary
7 ^ Integer or BYTES Bitwise xor Binary
8 | Integer or BYTES Bitwise or Binary
9 (Comparison Operators) = Any comparable type. See Data Types for a complete list. Equal Binary
  < Any comparable type. See Data Types for a complete list. Less than Binary
  > Any comparable type. See Data Types for a complete list. Greater than Binary
  <= Any comparable type. See Data Types for a complete list. Less than or equal to Binary
  >= Any comparable type. See Data Types for a complete list. Greater than or equal to Binary
  !=, <> Any comparable type. See Data Types for a complete list. Not equal Binary
  [NOT] LIKE STRING and byte Value does [not] match the pattern specified Binary
  [NOT] BETWEEN Any comparable types. See Data Types for a complete list. Value is [not] within the range specified Binary
  [NOT] IN Any comparable types. See Data Types for a complete list. Value is [not] in the set of values specified Binary
  IS [NOT] NULL All Value is [not] NULL Unary
  IS [NOT] TRUE BOOL Value is [not] TRUE. Unary
  IS [NOT] FALSE BOOL Value is [not] FALSE. Unary
10 NOT BOOL Logical NOT Unary
11 AND BOOL Logical AND Binary
12 OR BOOL Logical OR Binary

Operators with the same precedence are left associative. This means that those operators are grouped together starting from the left and moving right. For example, the expression:

x AND y AND z

is interpreted as

( ( x AND y ) AND z )

The expression:

x * y / z

is interpreted as:

( ( x * y ) / z )

All comparison operators have the same priority, but comparison operators are not associative. Therefore, parentheses are required in order to resolve ambiguity. For example:

(x < y) IS FALSE

Field access operator

expression.fieldname[. ...]

Description

Gets the value of a field. Alternatively known as the dot operator. Can be used to access nested fields. For example, expression.fieldname1.fieldname2.

Input types

  • STRUCT
  • JSON

Return type

  • For STRUCT: SQL data type of fieldname. If a field is not found in the struct, an error is thrown.
  • For JSON: JSON. If a field is not found in a JSON value, a SQL NULL is returned.

Example

In the following example, the expression is t.customer and the field access operations are .address and .country. An operation is an application of an operator (.) to specific operands (in this case, address and country, or more specifically, t.customer and address, for the first operation, and t.customer.address and country for the second operation).

WITH orders AS (
  SELECT STRUCT(STRUCT('Yonge Street' AS street, 'Canada' AS country) AS address) AS customer
)
SELECT t.customer.address.country FROM orders AS t;

+---------+
| country |
+---------+
| Canada  |
+---------+

Array subscript operator

array_expression[array_subscript_specifier]

array_subscript_specifier:
  position_keyword(index)

position_keyword:
  { OFFSET | SAFE_OFFSET | ORDINAL | SAFE_ORDINAL }

Description

Gets a value from an array at a specific location.

Input types

  • array_expression: The input array.
  • position_keyword: Where the index for the array should start and how out-of-range indexes are handled. Your choices are:
    • OFFSET: The index starts at zero. Produces an error if the index is out of range.
    • SAFE_OFFSET: The index starts at zero. Returns NULL if the index is out of range.
    • ORDINAL: The index starts at one. Produces an error if the index is out of range.
    • SAFE_ORDINAL: The index starts at one. Returns NULL if the index is out of range.
  • index: An integer that represents a specific position in the array.

Return type

T where array_expression is ARRAY<T>.

Examples

In this example, the array subscript operator is used to return values at specific locations in item_array. This example also shows what happens when you reference an index (6) in an array that is out of range. If the SAFE prefix is included, NULL is returned, otherwise an error is produced.

WITH Items AS (SELECT ["coffee", "tea", "milk"] AS item_array)
SELECT
  item_array,
  item_array[OFFSET(1)] AS item_offset,
  item_array[ORDINAL(1)] AS item_ordinal,
  item_array[SAFE_OFFSET(6)] AS item_safe_offset,
FROM Items

+----------------------------------+--------------+--------------+------------------+
| item_array                       | item_offset  | item_ordinal | item_safe_offset |
+----------------------------------+--------------+--------------+------------------+
| [coffee, tea, milk]              | tea          | coffee       | NULL             |
+----------------------------------+--------------+--------------+------------------+

In the following example, when you reference an index in an array that is out of range and the SAFE prefix is not included, an error is produced.

WITH Items AS (SELECT ["coffee", "tea", "milk"] AS item_array)
SELECT
  item_array[OFFSET(6)] AS item_offset
FROM Items

-- Error. OFFSET(6) is out of range.

JSON subscript operator

json_expression[array_element_id]
json_expression[field_name]

Description

Gets a value of an array element or field in a JSON expression. Can be used to access nested data.

Input types

  • JSON expression: The JSON expression that contains an array element or field to return.
  • [array_element_id]: An INT64 expression that represents a zero-based index in the array. If a negative value is entered, or the value is greater than or equal to the size of the array, or the JSON expression doesn't represent a JSON array, a SQL NULL is returned.
  • [field_name]: A STRING expression that represents the name of a field in JSON. If the field name is not found, or the JSON expression is not a JSON object, a SQL NULL is returned.

Return type

JSON

Example

In the following example:

  • json_value is a JSON expression.
  • .class is a JSON field access.
  • .students is a JSON field access.
  • [0] is a JSON subscript expression with an element offset that accesses the zeroth element of an array in the JSON value.
  • ['name'] is a JSON subscript expression with a field name that accesses a field.
SELECT json_value.class.students[0]['name'] AS first_student
FROM
  UNNEST(
    [
      JSON '{"class" : {"students" : [{"name" : "Jane"}]}}',
      JSON '{"class" : {"students" : []}}',
      JSON '{"class" : {"students" : [{"name" : "John"}, {"name": "Jamie"}]}}'])
    AS json_value;

+-----------------+
| first_student   |
+-----------------+
| "Jane"          |
| NULL            |
| "John"          |
+-----------------+

Arithmetic operators

All arithmetic operators accept input of numeric type T, and the result type has type T unless otherwise indicated in the description below:

Name Syntax
Addition X + Y
Subtraction X - Y
Multiplication X * Y
Division X / Y
Unary Plus + X
Unary Minus - X

NOTE: Divide by zero operations return an error. To return a different result, consider the IEEE_DIVIDE or SAFE_DIVIDE functions.

Result types for Addition, Subtraction and Multiplication:

INPUTINT64NUMERICBIGNUMERICFLOAT64
INT64INT64NUMERICBIGNUMERICFLOAT64
NUMERICNUMERICNUMERICBIGNUMERICFLOAT64
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERICFLOAT64
FLOAT64FLOAT64FLOAT64FLOAT64FLOAT64

Result types for Division:

INPUTINT64NUMERICBIGNUMERICFLOAT64
INT64FLOAT64NUMERICBIGNUMERICFLOAT64
NUMERICNUMERICNUMERICBIGNUMERICFLOAT64
BIGNUMERICBIGNUMERICBIGNUMERICBIGNUMERICFLOAT64
FLOAT64FLOAT64FLOAT64FLOAT64FLOAT64

Result types for Unary Plus:

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTINT64NUMERICBIGNUMERICFLOAT64

Result types for Unary Minus:

INPUTINT64NUMERICBIGNUMERICFLOAT64
OUTPUTINT64NUMERICBIGNUMERICFLOAT64

Date arithmetics operators

Operators '+' and '-' can be used for arithmetic operations on dates.

date_expression + int64_expression
int64_expression + date_expression
date_expression - int64_expression

Description

Adds or subtracts int64_expression days to or from date_expression. This is equivalent to DATE_ADD or DATE_SUB functions, when interval is expressed in days.

Return Data Type

DATE

Example

SELECT DATE "2020-09-22" + 1 AS day_later, DATE "2020-09-22" - 7 AS week_ago

+------------+------------+
| day_later  | week_ago   |
+------------+------------+
| 2020-09-23 | 2020-09-15 |
+------------+------------+

Datetime subtraction

date_expression - date_expression
timestamp_expression - timestamp_expression
datetime_expression - datetime_expression

Description

Computes the difference between two datetime values as an interval.

Return Data Type

INTERVAL

Example

SELECT
  DATE "2021-05-20" - DATE "2020-04-19" AS date_diff,
  TIMESTAMP "2021-06-01 12:34:56.789" - TIMESTAMP "2021-05-31 00:00:00" AS time_diff

+-------------------+------------------------+
| date_diff         | time_diff              |
+-------------------+------------------------+
| 0-0 396 0:0:0     | 0-0 0 36:34:56.789     |
+-------------------+------------------------+

Interval arithmetic operators

Addition and subtraction

date_expression + interval_expression = DATETIME
date_expression - interval_expression = DATETIME
timestamp_expression + interval_expression = TIMESTAMP
timestamp_expression - interval_expression = TIMESTAMP
datetime_expression + interval_expression = DATETIME
datetime_expression - interval_expression = DATETIME

Description

Adds an interval to a datetime value or subtracts an interval from a datetime value. Example

SELECT
  DATE "2021-04-20" + INTERVAL 25 HOUR AS date_plus,
  TIMESTAMP "2021-05-02 00:01:02.345" - INTERVAL 10 SECOND AS time_minus;

+-------------------------+--------------------------------+
| date_plus               | time_minus                     |
+-------------------------+--------------------------------+
| 2021-04-21 01:00:00     | 2021-05-02 00:00:52.345+00     |
+-------------------------+--------------------------------+

Multiplication and division

interval_expression * integer_expression = INTERVAL
interval_expression / integer_expression = INTERVAL

Description

Multiplies or divides an interval value by an integer.

Example

SELECT
  INTERVAL '1:2:3' HOUR TO SECOND * 10 AS mul1,
  INTERVAL 35 SECOND * 4 AS mul2,
  INTERVAL 10 YEAR / 3 AS div1,
  INTERVAL 1 MONTH / 12 AS div2

+----------------+--------------+-------------+--------------+
| mul1           | mul2         | div1        | div2         |
+----------------+--------------+-------------+--------------+
| 0-0 0 10:20:30 | 0-0 0 0:2:20 | 3-4 0 0:0:0 | 0-0 2 12:0:0 |
+----------------+--------------+-------------+--------------+

Bitwise operators

All bitwise operators return the same type and the same length as the first operand.

Name Syntax Input Data Type Description
Bitwise not ~ X Integer or BYTES Performs logical negation on each bit, forming the ones' complement of the given binary value.
Bitwise or X | Y X: Integer or BYTES
Y: Same type as X
Takes two bit patterns of equal length and performs the logical inclusive OR operation on each pair of the corresponding bits. This operator throws an error if X and Y are BYTES of different lengths.
Bitwise xor X ^ Y X: Integer or BYTES
Y: Same type as X
Takes two bit patterns of equal length and performs the logical exclusive OR operation on each pair of the corresponding bits. This operator throws an error if X and Y are BYTES of different lengths.
Bitwise and X & Y X: Integer or BYTES
Y: Same type as X
Takes two bit patterns of equal length and performs the logical AND operation on each pair of the corresponding bits. This operator throws an error if X and Y are BYTES of different lengths.
Left shift X << Y X: Integer or BYTES
Y: INT64
Shifts the first operand X to the left. This operator returns 0 or a byte sequence of b'\x00' if the second operand Y is greater than or equal to the bit length of the first operand X (for example, 64 if X has the type INT64). This operator throws an error if Y is negative.
Right shift X >> Y X: Integer or BYTES
Y: INT64
Shifts the first operand X to the right. This operator does not do sign bit extension with a signed type (i.e. it fills vacant bits on the left with 0). This operator returns 0 or a byte sequence of b'\x00' if the second operand Y is greater than or equal to the bit length of the first operand X (for example, 64 if X has the type INT64). This operator throws an error if Y is negative.

Logical operators

Google Standard SQL supports the AND, OR, and NOT logical operators. Logical operators allow only BOOL or NULL input and use three-valued logic to produce a result. The result can be TRUE, FALSE, or NULL:

x y x AND y x OR y
TRUE TRUE TRUE TRUE
TRUE FALSE FALSE TRUE
TRUE NULL NULL TRUE
FALSE TRUE FALSE TRUE
FALSE FALSE FALSE FALSE
FALSE NULL FALSE NULL
NULL TRUE NULL TRUE
NULL FALSE FALSE NULL
NULL NULL NULL NULL
x NOT x
TRUE FALSE
FALSE TRUE
NULL NULL

Examples

The examples in this section reference a table called entry_table:

+-------+
| entry |
+-------+
| a     |
| b     |
| c     |
| NULL  |
+-------+
SELECT 'a' FROM entry_table WHERE entry = 'a'

-- a => 'a' = 'a' => TRUE
-- b => 'b' = 'a' => FALSE
-- NULL => NULL = 'a' => NULL

+-------+
| entry |
+-------+
| a     |
+-------+
SELECT entry FROM entry_table WHERE NOT (entry = 'a')

-- a => NOT('a' = 'a') => NOT(TRUE) => FALSE
-- b => NOT('b' = 'a') => NOT(FALSE) => TRUE
-- NULL => NOT(NULL = 'a') => NOT(NULL) => NULL

+-------+
| entry |
+-------+
| b     |
| c     |
+-------+
SELECT entry FROM entry_table WHERE entry IS NULL

-- a => 'a' IS NULL => FALSE
-- b => 'b' IS NULL => FALSE
-- NULL => NULL IS NULL => TRUE

+-------+
| entry |
+-------+
| NULL  |
+-------+

Comparison operators

Comparisons always return BOOL. Comparisons generally require both operands to be of the same type. If operands are of different types, and if Google Standard SQL can convert the values of those types to a common type without loss of precision, Google Standard SQL will generally coerce them to that common type for the comparison; Google Standard SQL will generally coerce literals to the type of non-literals, where present. Comparable data types are defined in Data Types.

STRUCTs support only 4 comparison operators: equal (=), not equal (!= and <>), and IN.

The following rules apply when comparing these data types:

  • FLOAT64: All comparisons with NaN return FALSE, except for != and <>, which return TRUE.
  • BOOL: FALSE is less than TRUE.
  • STRING: Strings are compared codepoint-by-codepoint, which means that canonically equivalent strings are only guaranteed to compare as equal if they have been normalized first.
  • NULL: The convention holds here: any operation with a NULL input returns NULL.
Name Syntax Description
Less Than X < Y Returns TRUE if X is less than Y. This operator supports specifying collation.
Less Than or Equal To X <= Y Returns TRUE if X is less than or equal to Y. This operator supports specifying collation.
Greater Than X > Y Returns TRUE if X is greater than Y. This operator supports specifying collation.
Greater Than or Equal To X >= Y Returns TRUE if X is greater than or equal to Y. This operator supports specifying collation.
Equal X = Y Returns TRUE if X is equal to Y. This operator supports specifying collation.
Not Equal X != Y
X <> Y
Returns TRUE if X is not equal to Y. This operator supports specifying collation.
BETWEEN X [NOT] BETWEEN Y AND Z

Returns TRUE if X is [not] within the range specified. The result of "X BETWEEN Y AND Z" is equivalent to "Y <= X AND X <= Z" but X is evaluated only once in the former. This operator supports specifying collation.

LIKE X [NOT] LIKE Y Checks if the STRING in the first operand X matches a pattern specified by the second operand Y. Expressions can contain these characters:
  • A percent sign "%" matches any number of characters or bytes
  • An underscore "_" matches a single character or byte
  • You can escape "\", "_", or "%" using two backslashes. For example, "\\%". If you are using raw strings, only a single backslash is required. For example, r"\%".
IN Multiple - see below Returns FALSE if the right operand is empty. Returns NULL if the left operand is NULL. Returns TRUE or NULL, never FALSE, if the right operand contains NULL. Arguments on either side of IN are general expressions. Neither operand is required to be a literal, although using a literal on the right is most common. X is evaluated only once. This operator generally supports specifying collation.

When testing values that have a STRUCT data type for equality, it's possible that one or more fields are NULL. In such cases:

  • If all non-NULL field values are equal, the comparison returns NULL.
  • If any non-NULL field values are not equal, the comparison returns false.

The following table demonstrates how STRUCT data types are compared when they have fields that are NULL valued.

Struct1 Struct2 Struct1 = Struct2
STRUCT(1, NULL) STRUCT(1, NULL) NULL
STRUCT(1, NULL) STRUCT(2, NULL) FALSE
STRUCT(1,2) STRUCT(1, NULL) NULL

EXISTS operator

EXISTS ( subquery )

Description

Returns TRUE if the subquery produces one or more rows. Returns FALSE if the subquery produces zero rows. Never returns NULL. To learn more about how you can use a subquery with EXISTS, see EXISTS subqueries.

Examples

In this example, the EXISTS operator returns FALSE because there are no rows in Words where the direction is south:

WITH Words AS (
  SELECT 'Intend' as value, 'east' as direction UNION ALL
  SELECT 'Secure', 'north' UNION ALL
  SELECT 'Clarity', 'west'
 )
SELECT EXISTS ( SELECT value FROM Words WHERE direction = 'south' ) as result;

+--------+
| result |
+--------+
| FALSE  |
+--------+

IN operator

The IN operator supports the following syntax:

search_value [NOT] IN value_set

value_set:
  {
    (expression[, ...])
    | (subquery)
    | UNNEST(array_expression)
  }

Description

Checks for an equal value in a set of values. Semantic rules apply, but in general, IN returns TRUE if an equal value is found, FALSE if an equal value is excluded, otherwise NULL. NOT IN returns FALSE if an equal value is found, TRUE if an equal value is excluded, otherwise NULL.

  • search_value: The expression that is compared to a set of values.
  • value_set: One or more values to compare to a search value.

    • (expression[, ...]): A list of expressions.
    • (subquery): A subquery that returns a single column. The values in that column are the set of values. If no rows are produced, the set of values is empty.
    • UNNEST(array_expression): An UNNEST operator that returns a column of values from an array expression. This is equivalent to:

      IN (SELECT element FROM UNNEST(array_expression) AS element)
      

Semantic rules

When using the IN operator, the following semantics apply in this order:

  • Returns FALSE if value_set is empty.
  • Returns NULL if search_value is NULL.
  • Returns TRUE if value_set contains a value equal to search_value.
  • Returns NULL if value_set contains a NULL.
  • Returns FALSE.

When using the NOT IN operator, the following semantics apply in this order:

  • Returns TRUE if value_set is empty.
  • Returns NULL if search_value is NULL.
  • Returns FALSE if value_set contains a value equal to search_value.
  • Returns NULL if value_set contains a NULL.
  • Returns TRUE.

This operator generally supports collation, however, x [NOT] IN UNNEST is not supported.

The semantics of:

x IN (y, z, ...)

are defined as equivalent to:

(x = y) OR (x = z) OR ...

and the subquery and array forms are defined similarly.

x NOT IN ...

is equivalent to:

NOT(x IN ...)

The UNNEST form treats an array scan like UNNEST in the FROM clause:

x [NOT] IN UNNEST(<array expression>)

This form is often used with ARRAY parameters. For example:

x IN UNNEST(@array_parameter)

See the Arrays topic for more information on how to use this syntax.

IN can be used with multi-part keys by using the struct constructor syntax. For example:

(Key1, Key2) IN ( (12,34), (56,78) )
(Key1, Key2) IN ( SELECT (table.a, table.b) FROM table )

See the Struct Type for more information.

Return Data Type

BOOL

Examples

You can use these WITH clauses to emulate temporary tables for Words and Items in the following examples:

WITH Words AS (
  SELECT 'Intend' as value UNION ALL
  SELECT 'Secure' UNION ALL
  SELECT 'Clarity' UNION ALL
  SELECT 'Peace' UNION ALL
  SELECT 'Intend'
 )
SELECT * FROM Words;

+----------+
| value    |
+----------+
| Intend   |
| Secure   |
| Clarity  |
| Peace    |
| Intend   |
+----------+
WITH
  Items AS (
    SELECT STRUCT('blue' AS color, 'round' AS shape) AS info UNION ALL
    SELECT STRUCT('blue', 'square') UNION ALL
    SELECT STRUCT('red', 'round')
  )
SELECT * FROM Items;

+----------------------------+
| info                       |
+----------------------------+
| {blue color, round shape}  |
| {blue color, square shape} |
| {red color, round shape}   |
+----------------------------+

Example with IN and an expression:

SELECT * FROM Words WHERE value IN ('Intend', 'Secure');

+----------+
| value    |
+----------+
| Intend   |
| Secure   |
| Intend   |
+----------+

Example with NOT IN and an expression:

SELECT * FROM Words WHERE value NOT IN ('Intend');

+----------+
| value    |
+----------+
| Secure   |
| Clarity  |
| Peace    |
+----------+

Example with IN, a scalar subquery, and an expression:

SELECT * FROM Words WHERE value IN ((SELECT 'Intend'), 'Clarity');

+----------+
| value    |
+----------+
| Intend   |
| Clarity  |
| Intend   |
+----------+

Example with IN and an UNNEST operation:

SELECT * FROM Words WHERE value IN UNNEST(['Secure', 'Clarity']);

+----------+
| value    |
+----------+
| Secure   |
| Clarity  |
+----------+

Example with IN and a STRUCT:

SELECT
  (SELECT AS STRUCT Items.info) as item
FROM
  Items
WHERE (info.shape, info.color) IN (('round', 'blue'));

+------------------------------------+
| item                               |
+------------------------------------+
| { {blue color, round shape} info } |
+------------------------------------+

IS operators

IS operators return TRUE or FALSE for the condition they are testing. They never return NULL, even for NULL inputs, unlike the IS_INF and IS_NAN functions defined in Mathematical Functions. If NOT is present, the output BOOL value is inverted.

Function Syntax Input Data Type Result Data Type Description
X IS TRUE
BOOL BOOL Evaluates to TRUE if X evaluates to TRUE. Otherwise, evaluates to FALSE.
X IS NOT TRUE
BOOL BOOL Evaluates to FALSE if X evaluates to TRUE. Otherwise, evaluates to TRUE.
X IS FALSE
BOOL BOOL Evaluates to TRUE if X evaluates to FALSE. Otherwise, evaluates to FALSE.
X IS NOT FALSE
BOOL BOOL Evaluates to FALSE if X evaluates to FALSE. Otherwise, evaluates to TRUE.
X IS NULL
Any value type BOOL Evaluates to TRUE if X evaluates to NULL. Otherwise evaluates to FALSE.
X IS NOT NULL
Any value type BOOL Evaluates to FALSE if X evaluates to NULL. Otherwise evaluates to TRUE.
X IS UNKNOWN
BOOL BOOL Evaluates to TRUE if X evaluates to NULL. Otherwise evaluates to FALSE.
X IS NOT UNKNOWN
BOOL BOOL Evaluates to FALSE if X evaluates to NULL. Otherwise, evaluates to TRUE.

IS DISTINCT FROM operator

expression_1 IS [NOT] DISTINCT FROM expression_2

Description

IS DISTINCT FROM returns TRUE if the input values are considered to be distinct from each other by the DISTINCT and GROUP BY clauses. Otherwise, returns FALSE.

a IS DISTINCT FROM b being TRUE is equivalent to:

  • SELECT COUNT(DISTINCT x) FROM UNNEST([a,b]) x returning 2.
  • SELECT * FROM UNNEST([a,b]) x GROUP BY x returning 2 rows.

a IS DISTINCT FROM b is equivalent to NOT (a = b), except for the following cases:

  • This operator never returns NULL so NULL values are considered to be distinct from non-NULL values, not other NULL values.
  • NaN values are considered to be distinct from non-NaN values, but not other NaN values.

You can use this operation with fields in a complex data type, but not on the complex data types themselves. These complex data types cannot be compared directly:

  • STRUCT
  • ARRAY

Input types

  • expression_1: The first value to compare. This can be a groupable data type, NULL or NaN.
  • expression_2: The second value to compare. This can be a groupable data type, NULL or NaN.
  • NOT: If present, the output BOOL value is inverted.

Return type

BOOL

Examples

These return TRUE:

SELECT 1 IS DISTINCT FROM 2
SELECT 1 IS DISTINCT FROM NULL
SELECT 1 IS NOT DISTINCT FROM 1
SELECT NULL IS NOT DISTINCT FROM NULL

These return FALSE:

SELECT NULL IS DISTINCT FROM NULL
SELECT 1 IS DISTINCT FROM 1
SELECT 1 IS NOT DISTINCT FROM 2
SELECT 1 IS NOT DISTINCT FROM NULL

Concatenation operator

The concatenation operator combines multiple values into one.

Function Syntax Input Data Type Result Data Type
STRING || STRING [ || ... ]
STRING STRING
BYTES || BYTES [ || ... ]
BYTES STRING
ARRAY<T> || ARRAY<T> [ || ... ]
ARRAY<T> ARRAY<T>

Conditional expressions

Google Standard SQL for BigQuery supports conditional expressions. Conditional expressions impose constraints on the evaluation order of their inputs. In essence, they are evaluated left to right, with short-circuiting, and only evaluate the output value that was chosen. In contrast, all inputs to regular functions are evaluated before calling the function. Short-circuiting in conditional expressions can be exploited for error handling or performance tuning.

CASE expr

CASE expr
  WHEN expr_to_match THEN result
  [ ... ]
  [ ELSE else_result ]
  END

Description

Compares expr to expr_to_match of each successive WHEN clause and returns the first result where this comparison evaluates to TRUE. The remaining WHEN clauses and else_result aren't evaluated.

If the expr = expr_to_match comparison evaluates to FALSE or NULL for all WHEN clauses, returns the evaluation of else_result if present; if else_result isn't present, then returns NULL.

Consistent with equality comparisons elsewhere, if both expr and expr_to_match are NULL, then expr = expr_to_match evaluates to NULL, which returns else_result. If a CASE statement needs to distinguish a NULL value, then the alternate CASE syntax should be used.

expr and expr_to_match can be any type. They must be implicitly coercible to a common supertype; equality comparisons are done on coerced values. There may be multiple result types. result and else_result expressions must be coercible to a common supertype.

This expression supports specifying collation.

Return Data Type

Supertype of result[, ...] and else_result.

Example

WITH Numbers AS (
  SELECT 90 as A, 2 as B UNION ALL
  SELECT 50, 8 UNION ALL
  SELECT 60, 6 UNION ALL
  SELECT 50, 10
)
SELECT
  A,
  B,
  CASE A
    WHEN 90 THEN 'red'
    WHEN 50 THEN 'blue'
    ELSE 'green'
    END
    AS result
FROM Numbers

+------------------+
| A  | B  | result |
+------------------+
| 90 | 2  | red    |
| 50 | 8  | blue   |
| 60 | 6  | green  |
| 50 | 10 | blue   |
+------------------+

CASE

CASE
  WHEN condition THEN result
  [ ... ]
  [ ELSE else_result ]
  END

Description

Evaluates the condition of each successive WHEN clause and returns the first result where the condition evaluates to TRUE; any remaining WHEN clauses and else_result aren't evaluated.

If all conditions evaluate to FALSE or NULL, returns evaluation of else_result if present; if else_result isn't present, then returns NULL.

For additional rules on how values are evaluated, see the three-valued logic table in Logical operators.

condition must be a boolean expression. There may be multiple result types. result and else_result expressions must be implicitly coercible to a common supertype.

This expression supports specifying collation.

Return Data Type

Supertype of result[, ...] and else_result.

Example

WITH Numbers AS (
  SELECT 90 as A, 2 as B UNION ALL
  SELECT 50, 6 UNION ALL
  SELECT 20, 10
)
SELECT
  A,
  B,
  CASE
    WHEN A > 60 THEN 'red'
    WHEN B = 6 THEN 'blue'
    ELSE 'green'
    END
    AS result
FROM Numbers

+------------------+
| A  | B  | result |
+------------------+
| 90 | 2  | red    |
| 50 | 6  | blue   |
| 20 | 10 | green  |
+------------------+

COALESCE

COALESCE(expr[, ...])

Description

Returns the value of the first non-NULL expression. The remaining expressions aren't evaluated. An input expression can be any type. There may be multiple input expression types. All input expressions must be implicitly coercible to a common supertype.

Return Data Type

Supertype of expr[, ...].

Examples

SELECT COALESCE('A', 'B', 'C') as result

+--------+
| result |
+--------+
| A      |
+--------+
SELECT COALESCE(NULL, 'B', 'C') as result

+--------+
| result |
+--------+
| B      |
+--------+

IF

IF(expr, true_result, else_result)

Description

If expr evaluates to TRUE, returns true_result, else returns the evaluation for else_result. else_result isn't evaluated if expr evaluates to TRUE. true_result isn't evaluated if expr evaluates to FALSE or NULL.

expr must be a boolean expression. true_result and else_result must be coercible to a common supertype.

Return Data Type

Supertype of true_result and else_result.

Example

WITH Numbers AS (
  SELECT 10 as A, 20 as B UNION ALL
  SELECT 50, 30 UNION ALL
  SELECT 60, 60
)
SELECT
  A,
  B,
  IF(A < B, 'true', 'false') AS result
FROM Numbers

+------------------+
| A  | B  | result |
+------------------+
| 10 | 20 | true   |
| 50 | 30 | false  |
| 60 | 60 | false  |
+------------------+

IFNULL

IFNULL(expr, null_result)

Description

If expr evaluates to NULL, returns null_result. Otherwise, returns expr. If expr doesn't evaluate to NULL, null_result isn't evaluated.

expr and null_result can be any type and must be implicitly coercible to a common supertype. Synonym for COALESCE(expr, null_result).

Return Data Type

Supertype of expr or null_result.

Examples

SELECT IFNULL(NULL, 0) as result

+--------+
| result |
+--------+
| 0      |
+--------+
SELECT IFNULL(10, 0) as result

+--------+
| result |
+--------+
| 10     |
+--------+

NULLIF

NULLIF(expr, expr_to_match)

Description

Returns NULL if expr = expr_to_match evaluates to TRUE, otherwise returns expr.

expr and expr_to_match must be implicitly coercible to a common supertype, and must be comparable.

This expression supports specifying collation.

Return Data Type

Supertype of expr and expr_to_match.

Example

SELECT NULLIF(0, 0) as result

+--------+
| result |
+--------+
| NULL   |
+--------+
SELECT NULLIF(10, 0) as result

+--------+
| result |
+--------+
| 10     |
+--------+

FUNCTIONS

Aggregate functions

Google Standard SQL for BigQuery supports the following general aggregate functions. To learn about the syntax for aggregate function calls, see Aggregate function calls.

ANY_VALUE

ANY_VALUE(
  expression
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Supported Argument Types

Any

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 over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

Description

Returns an ARRAY of expression values.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

An error is raised if an array in the final query result contains a NULL element.

Supported Argument Types

All data types except ARRAY.

Returned Data Types

ARRAY

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

Examples

SELECT 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 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 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 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 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] |
+-------------------+
WITH vals AS
  (
    SELECT 1 x UNION ALL
    SELECT -2 x UNION ALL
    SELECT 3 x UNION ALL
    SELECT -2 x UNION ALL
    SELECT 1 x
  )
SELECT ARRAY_AGG(DISTINCT x ORDER BY x) as array_agg
FROM vals;

+------------+
| array_agg  |
+------------+
| [-2, 1, 3] |
+------------+
WITH vals AS
  (
    SELECT 1 x, 'a' y UNION ALL
    SELECT 1 x, 'b' y UNION ALL
    SELECT 2 x, 'a' y UNION ALL
    SELECT 2 x, 'c' y
  )
SELECT x, ARRAY_AGG(y) as array_agg
FROM vals
GROUP BY x;

+---------------+
| x | array_agg |
+---------------+
| 1 | [a, b]    |
| 2 | [a, c]    |
+---------------+
SELECT
  x,
  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. Returns NULL if there are zero input rows or expression evaluates to NULL for all rows.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

Supported Argument Types

ARRAY

Returned Data Types

ARRAY

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 over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

Description

Returns the average of non-NULL input values.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Caveats:

  • If a floating-point type is returned, the result is non-deterministic, which means you might receive a different result each time you use this function.
  • If the input is empty, does not come from the FROM clause, or contains only NULLs, returns NULL.
  • If the input contains NaN, returns NaN.
  • If the input contains [+|-]Infinity and the input is a singleton, returns [+|-]Infinity. If the input is not a singleton, returns NaN.
  • If there is numeric overflow, produces an error.

Supported Argument Types

Any numeric input type and INTERVAL.

Returned Data Types

INPUTINT64NUMERICBIGNUMERICFLOAT64INTERVAL
OUTPUTFLOAT64NUMERICBIGNUMERICFLOAT64INTERVAL

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

Supported Argument Types

  • INT64

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 over_clause]

2.

COUNT(
  [ DISTINCT ]
  expression
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

This function with DISTINCT supports specifying collation.

Supported Argument Types

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

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 over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Supported Argument Types

BOOL

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

Supported Argument Types

BOOL

Return Data Types

BOOL

Examples

LOGICAL_AND returns FALSE because not all of the values in the array are less than 3.

SELECT LOGICAL_AND(x < 3) AS logical_and FROM UNNEST([1, 2, 4]) 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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

Supported Argument Types

BOOL

Return Data Types

BOOL

Examples

LOGICAL_OR returns TRUE because at least one of the values in the array is less than 3.

SELECT LOGICAL_OR(x < 3) AS logical_or FROM UNNEST([1, 2, 4]) AS x;

+------------+
| logical_or |
+------------+
| TRUE       |
+------------+

MAX

MAX(
  expression
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

This function supports specifying collation.

Supported Argument Types

Any orderable data type except for ARRAY.

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 over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

This function supports specifying collation.

Supported Argument Types

Any orderable data type except for ARRAY.

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 over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Supported Argument Types

Either STRING or BYTES.

Return Data Types

Either STRING or 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 over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Supported Argument Types

Any supported numeric data types and INTERVAL.

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

Google Standard SQL for BigQuery supports statistical aggregate functions. To learn about the syntax for aggregate function calls, see Aggregate function calls.

CORR

CORR(
  X1, X2
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Return Data Type

FLOAT64

COVAR_POP

COVAR_POP(
  X1, X2
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Return Data Type

FLOAT64

COVAR_SAMP

COVAR_SAMP(
  X1, X2
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Return Data Type

FLOAT64

STDDEV_POP

STDDEV_POP(
  [ DISTINCT ]
  expression
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Return Data Type

FLOAT64

STDDEV_SAMP

STDDEV_SAMP(
  [ DISTINCT ]
  expression
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Return Data Type

FLOAT64

STDDEV

STDDEV(
  [ DISTINCT ]
  expression
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

Description

An alias of STDDEV_SAMP.

VAR_POP

VAR_POP(
  [ DISTINCT ]
  expression
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the OVER clause and how to use it, see Window function calls.

Return Data Type

FLOAT64

VAR_SAMP

VAR_SAMP(
  [ DISTINCT ]
  expression
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

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.

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

To learn more about the OVER clause and how to use it, see Window function calls.

Return Data Type

FLOAT64

VARIANCE

VARIANCE(
  [ DISTINCT ]
  expression
)
[ OVER over_clause ]

over_clause:
  { named_window | ( [ window_specification ] ) }

window_specification:
  [ named_window ]
  [ PARTITION BY partition_expression [, ...] ]
  [ ORDER BY expression [ { ASC | DESC }  ] [, ...] ]
  [ window_frame_clause ]

Description

An alias of VAR_SAMP.

Approximate aggregate functions

Google Standard SQL for BigQuery supports approximate aggregate functions. To learn about the syntax for aggregate function calls, see Aggregate function calls.

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
  • INTERVAL

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.

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

To learn more about the optional arguments in this function and how to use them, see Aggregate function calls.

Supported Argument Types

  • expression: Any supported data type except:

    • ARRAY
    • STRUCT
    • INTERVAL
  • number: INT64 literal or query parameter.

Returned Data Types

ARRAY<T> where T is the type specified by expression.

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))