Aggregate function calls

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

An aggregate function is a function that summarizes the rows of a group into a single value. When an aggregate function is used with the OVER clause, it becomes a window function, which computes values over a group of rows and then returns a single result for each row.

Aggregate function call syntax

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

Notation rules

  • Square brackets [ ] indicate optional clauses.
  • Parentheses ( ) indicate literal parentheses.
  • The vertical bar | indicates a logical OR.
  • Curly braces { } enclose a set of options.
  • A comma followed by an ellipsis within square brackets [, ... ] indicates that the preceding item can repeat in a comma-separated list.

Description

Each aggregate function supports all or a subset of the aggregate function call syntax. You can use the following syntax to build an aggregate function:

  • DISTINCT: Each distinct value of expression is aggregated only once into the result.
  • 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.
  • ORDER BY: Specifies the order of the values.

    • For each sort key, the default sort direction is ASC.

    • NULL is the minimum possible value, so NULLs appear first in ASC sorts and last in DESC sorts.

    • If you're using floating point data types, see Floating point semantics on ordering and grouping.

    • The ORDER BY clause is supported only for aggregate functions that depend on the order of their input. For those functions, if the ORDER BY clause is omitted, the output is nondeterministic.

    • If DISTINCT is also specified, then the sort key must be the same as expression.

  • LIMIT: Specifies the maximum number of expression inputs in the result.

    • If the input is an ARRAY value, 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.

    • If the input is a STRING value, 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.

  • OVER: If the aggregate function is also a window function, use this clause to define a window of rows around the row being evaluated. For each row, the aggregate function result is computed using the selected window of rows as input. To learn more, see Window function calls.

Details

The clauses in an aggregate function call are applied in the following order:

  • OVER
  • DISTINCT
  • IGNORE NULLS or RESPECT NULLS
  • ORDER BY
  • LIMIT

When used in conjunction with a GROUP BY clause, the groups summarized typically have at least one row. When the associated SELECT statement 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.

Aggregate function examples

A simple aggregate function call for COUNT, MIN, and MAX looks like this:

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

In the following example, the average of x over a specified window is returned for each row. To learn more about windows and how to use them, see Window function calls.

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

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