| Aggregate functions compute a single result
value from a set of input values. Table 8-29 shows the built-in aggregate
functions. The special syntax considerations for aggregate
functions are explained in Section 3.2.3.
Consult Section 1.7 for additional introductory
information.
Table 8-29. Aggregate Functions Function | Argument Type | Return Type | Description |
---|
avg(expression)
| SMALLINT, INTEGER,
BIGINT, REAL, DOUBLE PRECISION, .
| NUMERIC for any integer type argument,
DOUBLE PRECISION for a floating-point argument,
otherwise the same as the argument data type
| the average (arithmetic mean) of all input values |
bit_and(expression)
| SMALLINT, INTEGER, BIGINT.
| same as argument data type
| the bitwise AND of all non-null input values, or null if none |
bit_or(expression)
| SMALLINT, INTEGER, BIGINT.
| same as argument data type
| the bitwise OR of all non-null input values, or null if none |
bool_and(expression)
| BOOL
| BOOL
| true if all input values are true, otherwise false |
bool_or(expression)
| BOOL
| BOOL
| true if at least one input value is true, otherwise false | count(*) | | BIGINT | number of input values | count(expression) | any | BIGINT | number of input values for which the value of expression is not null
|
every(expression)
| BOOL
| BOOL
| equivalent to bool_and | max(expression) | any numeric, string, or date/time type | same as argument type | maximum value of expression across all input
values
| min(expression) | any numeric, string, or date/time type | same as argument type | minimum value of expression across all input
values
|
stddev(expression)
| SMALLINT, INTEGER,
BIGINT, REAL, DOUBLE PRECISION, or NUMERIC
| DOUBLE PRECISION for floating-point arguments,
otherwise NUMERIC
| sample standard deviation of the input values | sum(expression) | SMALLINT, INTEGER,
BIGINT, REAL, DOUBLE PRECISION, NUMERIC.
| BIGINT for SMALLINT or
INTEGER arguments, NUMERIC for
BIGINT arguments, DOUBLE PRECISION
for floating-point arguments, otherwise the same as the
argument data type
| sum of expression across all input values |
variance (expression)
| SMALLINT, INTEGER,
BIGINT, REAL, DOUBLE PRECISION, or NUMERIC
| DOUBLE PRECISION for floating-point arguments,
otherwise NUMERIC
| sample variance of the input values (square of the sample standard deviation) |
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. The function coalesce may be
used to substitute zero for null when necessary.
Note: 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 both as leading
to a subquery or as an aggregate if the select expression returns 1 row.
Thus the standard name cannot be given to these aggregates.
Note: Users accustomed to working with other SQL database management
systems may be surprised by the performance characteristics of
certain aggregate functions in
EnterpriseDB when the aggregate is
applied to the entire table (in other words, no
WHERE clause is specified). In particular, a
query like
SELECT min(col) FROM sometable;
will be executed by EnterpriseDB using a
sequential scan of the entire table. Other database systems may
optimize queries of this form to use an index on the column, if
one is available. Similarly, the aggregate functions
max() and count() always
require a sequential scan if applied to the entire table in
EnterpriseDB.
EnterpriseDB cannot easily implement this
optimization because it also allows for user-defined aggregate
queries. Since min() ,
max() , and count() are
defined using a generic API for aggregate functions, there is no
provision for special-casing the execution of these functions
under certain circumstances.
Fortunately, there is a simple workaround for
min() and max() . The
query shown below is equivalent to the query above, except that it
can take advantage of a B-tree index if there is one present on
the column in question.
SELECT col FROM sometable ORDER BY col ASC LIMIT 1;
A similar query (obtained by substituting DESC
for ASC in the query above) can be used in the
place of max() .
Unfortunately, there is no similarly trivial query that can be
used to improve the performance of count()
when applied to the entire table.
| |
---|