This page in other versions: 9.0 / 9.1 / 9.2 / 9.3  |  Development versions: devel / 9.4  |  Unsupported versions: 7.1 / 7.2 / 7.3 / 7.4 / 8.0 / 8.1 / 8.2 / 8.3 / 8.4

6.14. Aggregate Functions

Aggregate functions compute a single result value from a set of input values. Table 6-33 show the built-in aggregate functions. The special syntax considerations for aggregate functions are explained in Section 1.2.5. Consult the PostgreSQL 7.3.21 Tutorial for additional introductory information.

Table 6-33. Aggregate Functions

Function Argument Type Return Type Description  
avg(expression) smallint, integer, 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 the average (arithmetic mean) of all input values  
count(*)   bigint number of input values  
count(expression) any bigint number of input values for which the value of expression is not null  
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, or interval 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.

Comments


Jan. 6, 2003, 6:27 p.m.

The aggregates do not make use of indexes. If I understand correctly, they do a seq scan even if an index is available. Thus, on tables larger that a few thousand rows they take forever to complete.

For production use all queries with MIN() and MAX() should be rewritten with SELECT ... ORDER BY ... LIMIT 1.


Sept. 9, 2003, 5:10 p.m.

The lack of support for indexing with aggregates has been discussed ad nauseum on the mailing lists and is in the FAQ. Suffice it to say that our inability to use indexes for MIN() and MAX() is due to the ectensibility of PostgreSQL; it is the price we pay for supporting custom aggregates and data types.

Fixes for MIN() and MAX() have been proposed for PostgreSQL 7.5, but the implementation is far more difficult than it would appear to the layman.


Nov. 24, 2004, 4:45 p.m.

Here\'s how I\'ve been able to do a \"conditional count\":

Define a table:
create table cities (id serial not null unique, title varchar, state varchar);

Assume that you want a count of all the cities, as well as a count of those just in California:

select count(*) as total, sum(case when state=\'CA\' then 1 else 0 end) as ca_total from cities;

No need to group by - you\'ll get a count of all the cities, as well as just those in California!

I think that case bypasses indexes, so this might not be a good performer.

Privacy Policy | About PostgreSQL
Copyright © 1996-2014 The PostgreSQL Global Development Group