Aggregate functions compute a single result from a set of input values. The built-in general-purpose aggregate functions are listed in Table 9.55 and statistical aggregates in Table 9.56. The built-in within-group ordered-set aggregate functions are listed in Table 9.57 while the built-in within-group hypothetical-set ones are in Table 9.58. Grouping operations, which are closely related to aggregate functions, are listed in Table 9.59. The special syntax considerations for aggregate functions are explained in Section 4.2.7. Consult Section 2.7 for additional introductory information.
Table 9.55. General-Purpose Aggregate Functions
Function | Argument Type(s) | Return Type | Partial Mode | Description |
---|---|---|---|---|
array_agg(
| any non-array type | array of the argument type | No | input values, including nulls, concatenated into an array |
array_agg(
| any array type | same as argument data type | No | input arrays concatenated into array of one higher dimension (inputs must all have same dimensionality, and cannot be empty or null) |
avg(
|
smallint , int ,
bigint , real , double
precision , numeric , or interval
|
numeric for any integer-type argument,
double precision for a floating-point argument,
otherwise the same as the argument data type
| Yes | the average (arithmetic mean) of all non-null input values |
bit_and(
|
smallint , int , bigint , or
bit
| same as argument data type | Yes | the bitwise AND of all non-null input values, or null if none |
bit_or(
|
smallint , int , bigint , or
bit
| same as argument data type | Yes | the bitwise OR of all non-null input values, or null if none |
bool_and(
|
bool
|
bool
| Yes | true if all input values are true, otherwise false |
bool_or(
|
bool
|
bool
| Yes | true if at least one input value is true, otherwise false |
count(*)
| bigint | Yes | number of input rows | |
count( | any | bigint | Yes |
number of input rows for which the value of expression is not null
|
every(
|
bool
|
bool
| Yes | equivalent to bool_and |
json_agg(
|
any
|
json
| No | aggregates values, including nulls, as a JSON array |
jsonb_agg(
|
any
|
jsonb
| No | aggregates values, including nulls, as a JSON array |
json_object_agg(
|
(any, any)
|
json
| No | aggregates name/value pairs as a JSON object; values can be null, but not names |
jsonb_object_agg(
|
(any, any)
|
jsonb
| No | aggregates name/value pairs as a JSON object; values can be null, but not names |
max(
| any numeric, string, date/time, network, or enum type, or arrays of these types | same as argument type | Yes |
maximum value of expression across all non-null input
values
|
min(
| any numeric, string, date/time, network, or enum type, or arrays of these types | same as argument type | Yes |
minimum value of expression across all non-null input
values
|
string_agg(
|
(text , text ) or (bytea , bytea )
| same as argument types | No | non-null input values concatenated into a string, separated by delimiter |
sum(
|
smallint , int ,
bigint , real , double
precision , numeric ,
interval , or money
|
bigint for smallint or
int arguments, numeric for
bigint arguments, otherwise the same as the
argument data type
| Yes | sum of expression
across all non-null input values |
xmlagg(
|
xml
|
xml
| No | concatenation of non-null XML values (see also Section 9.14.1.7) |
It should be noted that except for count
,
these functions return a null value when no rows are selected. In
particular, sum
of no rows returns null, not
zero as one might expect, and array_agg
returns null rather than an empty array when there are no input
rows. The coalesce
function can be used to
substitute zero or an empty array for null when necessary.
Aggregate functions which support Partial Mode are eligible to participate in various optimizations, such as parallel aggregation.
Boolean aggregates bool_and
and
bool_or
correspond to standard SQL aggregates
every
and any
or
some
.
As for any
and some
,
it seems that there is an ambiguity built into the standard syntax:
SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
Here ANY
can be considered either as introducing
a subquery, or as being an aggregate function, if the subquery
returns one row with a Boolean value.
Thus the standard name cannot be given to these aggregates.
Users accustomed to working with other SQL database management
systems might be disappointed by the performance of the
count
aggregate when it is applied to the
entire table. A query like:
SELECT count(*) FROM sometable;
will require effort proportional to the size of the table: PostgreSQL will need to scan either the entire table or the entirety of an index which includes all rows in the table.
The aggregate functions array_agg
,
json_agg
, jsonb_agg
,
json_object_agg
, jsonb_object_agg
,
string_agg
,
and xmlagg
, as well as similar user-defined
aggregate functions, produce meaningfully different result values
depending on the order of the input values. This ordering is
unspecified by default, but can be controlled by writing an
ORDER BY
clause within the aggregate call, as shown in
Section 4.2.7.
Alternatively, supplying the input values from a sorted subquery
will usually work. For example:
SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
Beware that this approach can fail if the outer query level contains additional processing, such as a join, because that might cause the subquery's output to be reordered before the aggregate is computed.
Table 9.56 shows
aggregate functions typically used in statistical analysis.
(These are separated out merely to avoid cluttering the listing
of more-commonly-used aggregates.) Where the description mentions
N
, it means the
number of input rows for which all the input expressions are non-null.
In all cases, null is returned if the computation is meaningless,
for example when N
is zero.
Table 9.56. Aggregate Functions for Statistics
Table 9.57 shows some aggregate functions that use the ordered-set aggregate syntax. These functions are sometimes referred to as “inverse distribution” functions.
Table 9.57. Ordered-Set Aggregate Functions
All the aggregates listed in Table 9.57
ignore null values in their sorted input. For those that take
a fraction
parameter, the fraction value must be
between 0 and 1; an error is thrown if not. However, a null fraction value
simply produces a null result.
Each of the aggregates listed in
Table 9.58 is associated with a
window function of the same name defined in
Section 9.21. In each case, the aggregate result
is the value that the associated window function would have
returned for the “hypothetical” row constructed from
args
, if such a row had been added to the sorted
group of rows computed from the sorted_args
.
Table 9.58. Hypothetical-Set Aggregate Functions
For each of these hypothetical-set aggregates, the list of direct arguments
given in args
must match the number and types of
the aggregated arguments given in sorted_args
.
Unlike most built-in aggregates, these aggregates are not strict, that is
they do not drop input rows containing nulls. Null values sort according
to the rule specified in the ORDER BY
clause.
Table 9.59. Grouping Operations
Grouping operations are used in conjunction with grouping sets (see
Section 7.2.4) to distinguish result rows. The
arguments to the GROUPING
operation are not actually evaluated,
but they must match exactly expressions given in the GROUP BY
clause of the associated query level. Bits are assigned with the rightmost
argument being the least-significant bit; each bit is 0 if the corresponding
expression is included in the grouping criteria of the grouping set generating
the result row, and 1 if it is not. For example:
=>
SELECT * FROM items_sold;
make | model | sales -------+-------+------- Foo | GT | 10 Foo | Tour | 20 Bar | City | 15 Bar | Sport | 5 (4 rows)=>
SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);
make | model | grouping | sum -------+-------+----------+----- Foo | GT | 0 | 10 Foo | Tour | 0 | 20 Bar | City | 0 | 15 Bar | Sport | 0 | 5 Foo | | 1 | 30 Bar | | 1 | 20 | | 3 | 50 (7 rows)