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 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. 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 is TRUE, otherwise FALSE.

bool_or(boolean) boolean

Returns TRUE if any input value is TRUE, otherwise FALSE.

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 to count(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 a integer 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(x) double

Returns the geometric mean of all input values.

Supported types are BIGINT and DOUBLE.

max_by(x, y) [same as x]

Returns the value of x associated with the maximum value of y over all input values.

max_by(x, y, n) -> array([same as x])

Returns n values of x associated with the n largest values of y in descending order of y.

min_by(x, y) [same as x]

Returns the value of x associated with the minimum value of y over all input values.

min_by(x, y, n) -> array([same as x])

Returns n values of x associated with the n smallest values of y in ascending order of y.

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 of x.

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 of x.

multimap_agg(key, value)

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, initially initialState, 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 if initialState is NULL or inputFunction or combineFunction returns a NULL.

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

Returns an array created from the distinct input x elements.

set_union(array(T)) -> array(T)

Returns an array of all the distinct values contained in each array of the input.

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

map_agg(key, value)

Returns a map created from the input key / value pairs.

map_union(map(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.

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 that e 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. Larger capacity 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.

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 and capacity must be bigint. 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 given percentage. The value of percentage 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 of accuracy. The value of accuracy 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 the percentages 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 of accuracy.

approx_percentile(x, w, percentage) [same as x]

Returns the approximate weighed percentile for all input values of x using the per-item weight w at the percentage p. The weight must be an integer value of at least one. It is effectively a replication count for the value x in the percentile set. The value of p 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 of accuracy.

approx_percentile(x, w, percentages) array<[same as x]>

Returns the approximate weighed percentile for all input values of x using the per-item weight w 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 value x 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 of accuracy.

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_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.

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.