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.
Some aggregate functions such as array_agg()
produce different results
depending on the order of input values.
General Aggregate Functions¶
- arbitrary(x) [same as x] ¶
Returns an arbitrary non-null value of
x
, if one exists.
- any_value(x) [same as x] ¶
This is an alias for
arbitrary()
.
- array_agg(x) array<[same as x]> ¶
Returns an array created from the input
x
elements. Ignores null inputs if presto.array_agg.ignore_nulls is set to false.
- avg(x) double | real ¶
Returns the average (arithmetic mean) of all non-null input values. When x is of type REAL, the result type is REAL. For all other input types, the result type is DOUBLE.
- 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)
.
- entropy(c) double ¶
Returns the log-2 entropy of count input-values.
\[\mathrm{entropy}(c) = \sum_i \left[ {c_i \over \sum_j [c_j]} \log_2\left({\sum_j [c_j] \over c_i}\right) \right].\]c
must be ainteger
column of non-negative values.The function ignores any
NULL
count. If the sum of non-NULL
counts is 0, it returns 0.
- every(boolean) boolean ¶
This is an alias for
bool_and()
.
- histogram(x)¶
Returns a map containing the count of the number of times each input value occurs. Supports integral, floating-point, boolean, timestamp, and date input types.
- geometric_mean(bigint) double ¶
- geometric_mean(double) double
- geometric_mean(real) real
Returns the geometric mean of all input values.
- max_by(x, y) [same as x] ¶
Returns the value of
x
associated with the maximum value ofy
over all input values.y
must be an orderable type.
- max_by(x, y, n) -> array([same as x])
Returns n values of
x
associated with the n largest 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.y
must be an orderable type.
- min_by(x, y, n) -> array([same as x])
Returns n values of
x
associated with the n smallest values ofy
in ascending order ofy
.
- max(x) [same as x] ¶
Returns the maximum value of all input values.
x
must not contain nulls when it is complex type.x
must be an orderable type. Nulls are ignored if there are any non-null inputs. For REAL and DOUBLE types, NaN is considered greater than Infinity.
- max(x, n) array<[same as x]>
Returns
n
largest values of all input values ofx
.n
must be a positive integer and not exceed 10’000. Currently not supported for ARRAY, MAP, and ROW input types. Nulls are not included in the output array. For REAL and DOUBLE types, NaN is considered greater than Infinity.
- min(x) [same as x] ¶
Returns the minimum value of all input values.
x
must not contain nulls when it is complex type.x
must be an orderable type. Nulls are ignored if there are any non-null inputs. For REAL and DOUBLE types, NaN is considered greater than Infinity.
- min(x, n) array<[same as x]>
Returns
n
smallest values of all input values ofx
.n
must be a positive integer and not exceed 10’000. Currently not supported for ARRAY, MAP, and ROW input types. Nulls are not included in output array. For REAL and DOUBLE types, NaN is considered greater than Infinity.
- multimap_agg(K key, V value) -> map(K, array(V))¶
Returns a multimap created from the input
key
/value
pairs. Each key can be associated with multiple values.
- reduce_agg(inputValue T, initialState S, inputFunction(S, T, S), combineFunction(S, S, S)) S ¶
Reduces all non-NULL input values into a single value.
inputFunction
will be invoked for each non-NULL input value. If all inputs are NULL, the result is NULL. In addition to taking the input value,inputFunction
takes the current state, initiallyinitialState
, and returns the new state.combineFunction
will be invoked to combine two states into a new state. The final state is returned. Throws an error ifinitialState
is NULL orinputFunction
orcombineFunction
returns a NULL.Take care when designing
initialState
,inputFunction
andcombineFunction
. These need to support evaluating aggregation in a distributed manner using partial aggregation on many nodes, followed by shuffle over group-by keys, followed by final aggregation. Given a set of all possible values of state, make sure that combineFunction is commutative and associative operation with initialState as the identity value.combineFunction(s, initialState) = s for any s
combineFunction(s1, s2) = combineFunction(s2, s1) for any s1 and s2
combineFunction(s1, combineFunction(s2, s3)) = combineFunction(combineFunction(s1, s2), s3) for any s1, s2, s3
In addition, make sure that the following holds for the inputFunction:
inputFunction(inputFunction(initialState, x), y) = combineFunction(inputFunction(initialState, x), inputFunction(initialState, y)) for any x and y
Check out blog post about reduce_agg for more context.
Note that reduce_agg doesn’t support evaluation over sorted inputs.:
-- Compute sum (for illustration purposes only; use SUM aggregate function in production queries). SELECT id, reduce_agg(value, 0, (a, b) -> a + b, (a, b) -> a + b) FROM ( VALUES (1, 2), (1, 3), (1, 4), (2, 20), (2, 30), (2, 40) ) AS t(id, value) GROUP BY id; -- (1, 9) -- (2, 90) -- Compute product. SELECT id, reduce_agg(value, 1, (a, b) -> a * b, (a, b) -> a * b) FROM ( VALUES (1, 2), (1, 3), (1, 4), (2, 20), (2, 30), (2, 40) ) AS t(id, value) GROUP BY id; -- (1, 24) -- (2, 24000) -- Compute avg (for illustration purposes only; use AVG aggregate function in production queries). SELECT id, sum_and_count.sum / sum_and_count.count FROM ( SELECT id, reduce_agg(value, CAST(row(0, 0) AS row(sum double, count bigint)), (s, x) -> CAST(row(s.sum + x, s.count + 1) AS row(sum double, count bigint)), (s, s2) -> CAST(row(s.sum + s2.sum, s.count + s2.count) AS row(sum double, count bigint))) AS sum_and_count FROM ( VALUES (1, 2), (1, 3), (1, 4), (2, 20), (2, 30), (2, 40) ) AS t(id, value) GROUP BY id ); -- (1, 3.0) -- (2, 30.0)
- set_agg(x) array<[same as x]> ¶
Returns an array created from the distinct input
x
elements.x
must not contain nulls when it is complex type.
- set_union(array(T)) -> array(T)¶
Returns an array of all the distinct values contained in each array of the input.
Returns an empty array if all input arrays are NULL.
Example:
SELECT set_union(elements) FROM ( VALUES ARRAY[1, 2, 3], ARRAY[2, 3, 4] ) AS t(elements);
Returns ARRAY[1, 2, 3, 4]
- sum(x) [same as x] ¶
Returns the sum of all input values.
Bitwise Aggregate Functions¶
- bitwise_and_agg(x) [same as x] ¶
Returns the bitwise AND of all input values in 2’s complement representation.
Supported types are TINYINT, SMALLINT, INTEGER and BIGINT.
- bitwise_or_agg(x) [same as x] ¶
Returns the bitwise OR of all input values in 2’s complement representation.
Supported types are TINYINT, SMALLINT, INTEGER and BIGINT.
- bitwise_xor_agg(x) [same as x] ¶
Returns the bitwise XOR of all input values in 2’s complement representation.
Supported types are TINYINT, SMALLINT, INTEGER and BIGINT.
Map Aggregate Functions¶
- map_agg(K key, V value) -> map(K, V)¶
Returns a map created from the input
key
/value
pairs. Inputs with NULL or duplicate keys are ignored.
- map_union(map(K, V)) -> map(K, V)¶
Returns the union of all the input
maps
. If akey
is found in multiple inputmaps
, thatkey’s
value
in the resultingmap
comes from an arbitrary inputmap
.
- map_union_sum(map(K, V)) -> map(K, V)¶
Returns the union of all the input maps summing the values of matching keys in all the maps. All null values in the original maps are coalesced to 0.
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 of[0.0040625, 0.26000]
.
- approx_most_frequent(buckets, value, capacity) map<[same as value], bigint> ¶
Computes the top frequent values up to
buckets
elements approximately. Approximate estimation of the function enables us to pick up the frequent values with less memory. Largercapacity
improves the accuracy of underlying algorithm with sacrificing the memory capacity. The returned value is a map containing the top elements with corresponding estimated frequency.For BOOLEAN ‘value’, this function always returns ‘perfect’ result. ‘bucket’ and ‘capacity’ arguments are ignored in this case.
The error of the function depends on the permutation of the values and its cardinality. We can set the capacity same as the cardinality of the underlying data to achieve the least error.
buckets
andcapacity
must bebigint
.value
can be numeric or string type.The function uses the stream summary data structure proposed in the paper Efficient computation of frequent and top-k elements in data streams by A. Metwally, D. Agrawal and A. Abbadi.
- 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, percentage, accuracy) [same as x]
As
approx_percentile(x, percentage)
, but with a maximum rank error ofaccuracy
. The value ofaccuracy
must be between zero and one (exclusive) and must be constant for all input rows. Note that a lower “accuracy” is really a lower error threshold, and thus more accurate. The default accuracy is 0.0133. The underlying implementation is KLL sketch thus has a stronger guarantee for accuracy than T-Digest.
- 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, percentages, accuracy) array<[same as x]>
As
approx_percentile(x, percentages)
, but with a maximum rank error ofaccuracy
.
- 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]
As
approx_percentile(x, w, percentage)
, but with a maximum rank error ofaccuracy
.
- 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.
- approx_percentile(x, w, percentages, accuracy) array<[same as x]>
As
approx_percentile(x, w, percentages)
, but with a maximum rank error ofaccuracy
.
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.
- kurtosis(x) double ¶
Returns the excess kurtosis of all input values. Unbiased estimate using the following expression:
\[\mathrm{kurtosis}(x) = {n(n+1) \over (n-1)(n-2)(n-3)} { \sum[(x_i-\mu)^4] \over \sigma^4} -3{ (n-1)^2 \over (n-2)(n-3) },\]where \(\mu\) is the mean, and \(\sigma\) is the standard deviation.
- regr_avgx(y, x) double ¶
Returns the average of the independent value in a group.
y
is the dependent value.x
is the independent value.
- regr_avgy(y, x) double ¶
Returns the average of the dependent value in a group.
y
is the dependent value.x
is the independent value.
- regr_count(y, x) double ¶
Returns the number of non-null pairs of input values.
y
is the dependent value.x
is the independent value.
- regr_intercept(y, x) double ¶
Returns linear regression intercept of input values.
y
is the dependent value.x
is the independent value.
- regr_r2(y, x) double ¶
Returns the coefficient of determination of the linear regression.
y
is the dependent value.x
is the independent value. If regr_sxx(y, x) is 0, result is null. If regr_syy(y, x) is 0 and regr_sxx(y, x) isn’t 0, result is 1.
- regr_slope(y, x) double ¶
Returns linear regression slope of input values.
y
is the dependent value.x
is the independent value.
- regr_sxx(y, x) double ¶
Returns the sum of the squares of the independent values in a group.
y
is the dependent value.x
is the independent value.
- regr_sxy(y, x) double ¶
Returns the sum of the product of the dependent and independent values in a group.
y
is the dependent value.x
is the independent value.
- regr_syy(y, x) double ¶
Returns the sum of the squares of the dependent values in a group.
y
is the dependent value.x
is the independent value.
- skewness(x) double ¶
Returns the skewness of all input values.
- 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.
Miscellaneous¶
- max_data_size_for_stats(x) bigint ¶
Returns an estimate of the the maximum in-memory size in bytes of
x
.
- sum_data_size_for_stats(x) bigint ¶
Returns an estimate of the sum of in-memory size in bytes of
x
.