9.21. Aggregate Functions
Aggregate functions compute a single result from a set of input values. The built-in general-purpose aggregate functions are listed in Table 9.60 while statistical aggregates are in Table 9.61 . The built-in within-group ordered-set aggregate functions are listed in Table 9.62 while the built-in within-group hypothetical-set ones are in Table 9.63 . Grouping operations, which are closely related to aggregate functions, are listed in Table 9.64 . The special syntax considerations for aggregate functions are explained in Section 4.2.7 . Consult Section 2.7 for additional introductory information.
Aggregate functions that support Partial Mode are eligible to participate in various optimizations, such as parallel aggregation.
  While all aggregates below accept an optional
  
   ORDER BY
  
  clause (as outlined in
  
   Section 4.2.7
  
  ), the clause has only been added to
   aggregates whose output is affected by ordering.
 
Table 9.60. General-Purpose Aggregate Functions
| Function Description | Partial Mode | 
|---|---|
| 
        
        
         Returns an arbitrary value from the non-null input values. | Yes | 
| 
        
        
         Collects all the input values, including nulls, into an array. | Yes | 
| 
         Concatenates all the input arrays into an array of one higher dimension. (The inputs must all have the same dimensionality, and cannot be empty or null.) | Yes | 
| 
         
         
         
         
         
         Computes the average (arithmetic mean) of all the non-null input values. | Yes | 
| 
        
        
         
         
         
         Computes the bitwise AND of all non-null input values. | Yes | 
| 
        
        
         
         
         
         Computes the bitwise OR of all non-null input values. | Yes | 
| 
        
        
         
         
         
         Computes the bitwise exclusive OR of all non-null input values. Can be useful as a checksum for an unordered set of values. | Yes | 
| 
        
        
         Returns true if all non-null input values are true, otherwise false. | Yes | 
| Returns true if any non-null input value is true, otherwise false. | Yes | 
| Computes the number of input rows. | Yes | 
| 
         Computes the number of input rows in which the input value is not null. | Yes | 
| 
        This is the SQL standard's equivalent to
         | Yes | 
| 
        
        
         
        
        
         
        Collects all the input values, including nulls, into a JSON array.
        Values are converted to JSON as per
         | No | 
| 
        
        
         
        
        
         
        Collects all the input values, skipping nulls, into a JSON array.
        Values are converted to JSON as per
         | No | 
| 
        
        
         
        Behaves in the same way as
         
         | No | 
| 
        
        
         
        Behaves like
         
         | No | 
| 
        
        
         
        
        
         
        Collects all the key/value pairs into a JSON object.  Key arguments
        are coerced to text; value arguments are converted as per
         | No | 
| 
        
        
         
        
        
         
        Collects all the key/value pairs into a JSON object.  Key arguments
        are coerced to text; value arguments are converted as per
         | No | 
| 
        
        
         
        
        
         
        Collects all the key/value pairs into a JSON object.  Key arguments
        are coerced to text; value arguments are converted as per
         | No | 
| 
        
        
         
        
        
         
        Collects all the key/value pairs into a JSON object.  Key arguments
        are coerced to text; value arguments are converted as per
         | No | 
| 
        
        
         
        Computes the maximum of the non-null input
        values.  Available for any numeric, string, date/time, or enum type,
        as well as
         | Yes | 
| 
        
        
         
        Computes the minimum of the non-null input
        values.  Available for any numeric, string, date/time, or enum type,
        as well as
         | Yes | 
| 
        
        
         
         Computes the union of the non-null input values. | No | 
| 
        
        
         
         Computes the intersection of the non-null input values. | No | 
| 
        
        
         
         
        Concatenates the non-null input values into a string.  Each value
        after the first is preceded by the
        corresponding
        
          | Yes | 
| 
         
         
         
         
         
         
         Computes the sum of the non-null input values. | Yes | 
| 
        
        
         Concatenates the non-null XML input values (see Section 9.15.1.8 ). | No | 
  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.
 
  The aggregate functions
  
   array_agg
  
  ,
  
   json_agg
  
  ,
  
   jsonb_agg
  
  ,
  
   json_agg_strict
  
  ,
  
   jsonb_agg_strict
  
  ,
  
   json_object_agg
  
  ,
  
   jsonb_object_agg
  
  ,
  
   json_object_agg_strict
  
  ,
  
   jsonb_object_agg_strict
  
  ,
  
   json_object_agg_unique
  
  ,
  
   jsonb_object_agg_unique
  
  ,
  
   json_object_agg_unique_strict
  
  ,
  
   jsonb_object_agg_unique_strict
  
  ,
  
   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.
Note
   The boolean aggregates
   
    bool_and
   
   and
   
    bool_or
   
   correspond to the standard SQL aggregates
   
    every
   
   and
   
    any
   
   or
   
    some
   
   .
   
    PostgreSQL
   
   supports
   
    every
   
   , but not
   
    any
   
   or
   
    some
   
   , because 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.
  
Note
   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 that includes all rows in the table.
  
   Table 9.61
  
  shows
   aggregate functions typically used in statistical analysis.
   (These are separated out merely to avoid cluttering the listing
   of more-commonly-used aggregates.)  Functions shown as
   accepting
  
   
    numeric_type
   
  
  are available for all
   the types
  
   smallint
  
  ,
  
   integer
  
  ,
  
   bigint
  
  ,
  
   numeric
  
  ,
  
   real
  
  ,
   and
  
   double precision
  
  .
   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.61. Aggregate Functions for Statistics
  
   Table 9.62
  
  shows some
   aggregate functions that use the
  
   ordered-set aggregate
  
  syntax.  These functions are sometimes referred to as
  
   "
   
    inverse
   distribution
   
   "
  
  functions.  Their aggregated input is introduced by
  
   ORDER BY
  
  , and they may also take a
  
   direct
   argument
  
  that is not aggregated, but is computed only once.
   All these functions ignore null values in their aggregated 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.
 
Table 9.62. Ordered-Set Aggregate Functions
  Each of the
  
   "
   
    hypothetical-set
   
   "
  
  aggregates listed in
  
   Table 9.63
  
  is associated with a
   window function of the same name defined in
  
   Section 9.22
  
  .  In each case, the aggregate's 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 represented by the
  
   
    sorted_args
   
  
  .
   For each of these functions, 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.63. Hypothetical-Set Aggregate Functions
Table 9.64. Grouping Operations
  The grouping operations shown in
  
   Table 9.64
  
  are used in conjunction with
    grouping sets (see
  
   Section 7.2.4
  
  ) to distinguish
    result rows.  The arguments to the
  
   GROUPING
  
  function
    are not actually evaluated, but they must exactly match expressions given
    in the
  
   GROUP BY
  
  clause of the associated query level.
    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)
  Here, the
  
   grouping
  
  value
  
   0
  
  in the
    first four rows shows that those have been grouped normally, over both the
    grouping columns.  The value
  
   1
  
  indicates
    that
  
   model
  
  was not grouped by in the next-to-last two
    rows, and the value
  
   3
  
  indicates that
    neither
  
   make
  
  nor
  
   model
  
  was grouped
    by in the last row (which therefore is an aggregate over all the input
    rows).