15.14. Aggregate Functions
Aggregate functions operate on a set of values to compute a single result.
Except for count()
, count_if()
, max_by()
, min_by()
and
approx_distinct()
, all of these aggregate functions ignore null values
and return null for no input rows or when all values are null. For example,
sum()
returns null rather than zero and avg()
does not include null
values in the count. The coalesce
function can be used to convert null into
zero.
General Aggregate Functions
-
arbitrary
(x) → [same as input] Returns an arbitrary non-null value of
x
, if one exists.
-
array_agg
(x) → array<[same as input]> Returns an array created from the input
x
elements.
-
avg
(x) → double Returns the average (arithmetic mean) of all input values.
-
bool_and
(boolean) → boolean Returns
TRUE
if every input value isTRUE
, otherwiseFALSE
.
-
bool_or
(boolean) → boolean Returns
TRUE
if any input value isTRUE
, otherwiseFALSE
.
-
checksum
(x) → varbinary Returns an order-insensitive checksum of the given values.
-
count
(*) → bigint Returns the number of input rows.
-
count
(x) → bigint Returns the number of non-null input values.
-
count_if
(x) → bigint Returns the number of
TRUE
input values. This function is equivalent tocount(CASE WHEN x THEN 1 END)
.
-
every
(boolean) → boolean This is an alias for
bool_and()
.
-
geometric_mean
(x) → double Returns the geometric mean of all input values.
-
grouping
(col1, ..., colN) → integer Returns a bit set converted to decimal, indicating which columns are present in a grouping. The function must be used in conjunction with
GROUPING SETS
,ROLLUP
,CUBE
orGROUP BY
and its arguments must match exactly the columns referenced in the correspondingGROUPING SETS
,ROLLUP
,CUBE
orGROUP BY
clause.To compute the resulting bit set for a particular row, bits are assigned to the argument columns with the rightmost column being the least significant bit. For a given grouping, a bit is set to 0 if the corresponding column is included in the grouping and to 1 otherwise. For example, consider the query below:
SELECT origin_state, origin_zip, destination_state, sum(package_weight), grouping(origin_state, origin_zip, destination_state) FROM shipping GROUP BY GROUPING SETS ( (origin_state), (origin_state, origin_zip), (destination_state));
origin_state | origin_zip | destination_state | _col3 | _col4 --------------+------------+-------------------+-------+------- California | NULL | NULL | 1397 | 3 New Jersey | NULL | NULL | 225 | 3 New York | NULL | NULL | 3 | 3 California | 94131 | NULL | 60 | 1 New Jersey | 7081 | NULL | 225 | 1 California | 90210 | NULL | 1337 | 1 New York | 10002 | NULL | 3 | 1 NULL | NULL | New Jersey | 58 | 6 NULL | NULL | Connecticut | 1562 | 6 NULL | NULL | Colorado | 5 | 6 (10 rows)
The first grouping in the above result only includes the
origin_state
column and excludes theorigin_zip
anddestination_state
columns. The bit set constructed for that grouping is011
where the most significant bit representsorigin_state
.See also: Complex Grouping Operations
-
max_by
(x, y) → [same as x] Returns the value of
x
associated with the maximum value ofy
over all input values.
-
max_by
(x, y, n) → array<[same as x]> Returns
n
values ofx
associated with then
largest of all input values ofy
in descending order ofy
.
-
min_by
(x, y) → [same as x] Returns the value of
x
associated with the minimum value ofy
over all input values.
-
min_by
(x, y, n) → array<[same as x]> Returns
n
values ofx
associated with then
smallest of all input values ofy
in ascending order ofy
.
-
max
(x) → [same as input] Returns the maximum value of all input values.
-
max
(x, n) → array<[same as x]> Returns
n
largest values of all input values ofx
.
-
min
(x) → [same as input] Returns the minimum value of all input values.
-
min
(x, n) → array<[same as x]> Returns
n
smallest values of all input values ofx
.
-
sum
(x) → [same as input] Returns the sum of all input values.
Bitwise Aggregate Functions
-
bitwise_and_agg
(x) → bigint Returns the bitwise AND of all input values in 2’s complement representation.
-
bitwise_or_agg
(x) → bigint Returns the bitwise OR of all input values in 2’s complement representation.
Map Aggregate Functions
-
histogram
(x) → map<K,bigint> Returns a map containing the count of the number of times each input value occurs.
-
map_agg
(key, value) → map<K,V> Returns a map created from the input
key
/value
pairs.
-
map_union
(x<K, V>) → map<K,V> Returns the union of all the input maps. If a key is found in multiple input maps, that key’s value in the resulting map comes from an arbitrary input map.
-
multimap_agg
(key, value) → map<K,array<V>> Returns a multimap created from the input
key
/value
pairs. Each key can be associated with multiple values.
Approximate Aggregate Functions
-
approx_distinct
(x) → bigint Returns the approximate number of distinct input values. This function provides an approximation of
count(DISTINCT x)
. Zero is returned if all input values are null.This function should produce a standard error of 2.3%, which is the standard deviation of the (approximately normal) error distribution over all possible sets. It does not guarantee an upper bound on the error for any specific input set.
-
approx_distinct
(x, e) → bigint Returns the approximate number of distinct input values. This function provides an approximation of
count(DISTINCT x)
. Zero is returned if all input values are null.This function should produce a standard error of no more than
e
, which is the standard deviation of the (approximately normal) error distribution over all possible sets. It does not guarantee an upper bound on the error for any specific input set. The current implementation of this function requires thate
be in the range: [0.01150, 0.26000].
-
approx_percentile
(x, percentage) → [same as x] Returns the approximate percentile for all input values of
x
at the givenpercentage
. The value ofpercentage
must be between zero and one and must be constant for all input rows.
-
approx_percentile
(x, percentages) → array<[same as x]> Returns the approximate percentile for all input values of
x
at each of the specified percentages. Each element of thepercentages
array must be between zero and one, and the array must be constant for all input rows.
-
approx_percentile
(x, w, percentage) → [same as x] Returns the approximate weighed percentile for all input values of
x
using the per-item weightw
at the percentagep
. The weight must be an integer value of at least one. It is effectively a replication count for the valuex
in the percentile set. The value ofp
must be between zero and one and must be constant for all input rows.
-
approx_percentile
(x, w, percentage, accuracy) → [same as x] Returns the approximate weighed percentile for all input values of
x
using the per-item weightw
at the percentagep
, with a maximum rank error ofaccuracy
. The weight must be an integer value of at least one. It is effectively a replication count for the valuex
in the percentile set. The value ofp
must be between zero and one and must be constant for all input rows.accuracy
must be a value greater than zero and less than one, and it must be constant for all input rows.
-
approx_percentile
(x, w, percentages) → array<[same as x]> Returns the approximate weighed percentile for all input values of
x
using the per-item weightw
at each of the given percentages specified in the array. The weight must be an integer value of at least one. It is effectively a replication count for the valuex
in the percentile set. Each element of the array must be between zero and one, and the array must be constant for all input rows.
-
numeric_histogram
(buckets, value, weight) → map<double, double> Computes an approximate histogram with up to
buckets
number of buckets for allvalue
s with a per-item weight ofweight
. The algorithm is based loosely on:Yael Ben-Haim and Elad Tom-Tov, "A streaming parallel decision tree algorithm", J. Machine Learning Research 11 (2010), pp. 849--872.
buckets
must be abigint
.value
andweight
must be numeric.
-
numeric_histogram
(buckets, value) → map<double, double> Computes an approximate histogram with up to
buckets
number of buckets for allvalue
s. This function is equivalent to the variant ofnumeric_histogram()
that takes aweight
, with a per-item weight of1
.
Statistical Aggregate Functions
-
corr
(y, x) → double Returns correlation coefficient of input values.
-
covar_pop
(y, x) → double Returns the population covariance of input values.
-
covar_samp
(y, x) → double Returns the sample covariance of input values.
-
regr_intercept
(y, x) → double Returns linear regression intercept of input values.
y
is the dependent value.x
is the independent value.
-
regr_slope
(y, x) → double Returns linear regression slope of input values.
y
is the dependent value.x
is the independent value.
-
stddev
(x) → double This is an alias for
stddev_samp()
.
-
stddev_pop
(x) → double Returns the population standard deviation of all input values.
-
stddev_samp
(x) → double Returns the sample standard deviation of all input values.
-
variance
(x) → double This is an alias for
var_samp()
.
-
var_pop
(x) → double Returns the population variance of all input values.
-
var_samp
(x) → double Returns the sample variance of all input values.