1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-30 11:03:19 +03:00

Support ordered-set (WITHIN GROUP) aggregates.

This patch introduces generic support for ordered-set and hypothetical-set
aggregate functions, as well as implementations of the instances defined in
SQL:2008 (percentile_cont(), percentile_disc(), rank(), dense_rank(),
percent_rank(), cume_dist()).  We also added mode() though it is not in the
spec, as well as versions of percentile_cont() and percentile_disc() that
can compute multiple percentile values in one pass over the data.

Unlike the original submission, this patch puts full control of the sorting
process in the hands of the aggregate's support functions.  To allow the
support functions to find out how they're supposed to sort, a new API
function AggGetAggref() is added to nodeAgg.c.  This allows retrieval of
the aggregate call's Aggref node, which may have other uses beyond the
immediate need.  There is also support for ordered-set aggregates to
install cleanup callback functions, so that they can be sure that
infrastructure such as tuplesort objects gets cleaned up.

In passing, make some fixes in the recently-added support for variadic
aggregates, and make some editorial adjustments in the recent FILTER
additions for aggregates.  Also, simplify use of IsBinaryCoercible() by
allowing it to succeed whenever the target type is ANY or ANYELEMENT.
It was inconsistent that it dealt with other polymorphic target types
but not these.

Atri Sharma and Andrew Gierth; reviewed by Pavel Stehule and Vik Fearing,
and rather heavily editorialized upon by Tom Lane
This commit is contained in:
Tom Lane
2013-12-23 16:11:35 -05:00
parent 37484ad2aa
commit 8d65da1f01
64 changed files with 4686 additions and 755 deletions

View File

@ -348,6 +348,27 @@
<entry><literal><link linkend="catalog-pg-proc"><structname>pg_proc</structname></link>.oid</literal></entry>
<entry><structname>pg_proc</structname> OID of the aggregate function</entry>
</row>
<row>
<entry><structfield>aggkind</structfield></entry>
<entry><type>char</type></entry>
<entry></entry>
<entry>Aggregate kind:
<literal>n</literal> for <quote>normal</> aggregates,
<literal>o</literal> for <quote>ordered-set</> aggregates, or
<literal>h</literal> for <quote>hypothetical-set</> aggregates
</entry>
</row>
<row>
<entry><structfield>aggnumdirectargs</structfield></entry>
<entry><type>int2</type></entry>
<entry></entry>
<entry>Number of direct (non-aggregated) arguments of an ordered-set or
hypothetical-set aggregate, counting a variadic array as one argument.
If equal to <structfield>pronargs</>, the aggregate must be variadic
and the variadic array describes the aggregated arguments as well as
the final direct arguments.
Always zero for normal aggregates.</entry>
</row>
<row>
<entry><structfield>aggtransfn</structfield></entry>
<entry><type>regproc</type></entry>

View File

@ -11560,10 +11560,13 @@ NULL baz</literallayout>(3 rows)</entry>
<para>
<firstterm>Aggregate functions</firstterm> compute a single result
from a set of input values. The built-in aggregate functions
from a set of input values. The built-in normal aggregate functions
are listed in
<xref linkend="functions-aggregate-table"> and
<xref linkend="functions-aggregate-statistics-table">.
The built-in ordered-set aggregate functions
are listed in <xref linkend="functions-orderedset-table"> and
<xref linkend="functions-hypothetical-table">.
The special syntax considerations for aggregate
functions are explained in <xref linkend="syntax-aggregates">.
Consult <xref linkend="tutorial-agg"> for additional introductory
@ -12307,6 +12310,290 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
</tgroup>
</table>
<para>
<xref linkend="functions-orderedset-table"> shows some
aggregate functions that use the <firstterm>ordered-set aggregate</>
syntax. These functions are sometimes referred to as <quote>inverse
distribution</> functions.
</para>
<indexterm>
<primary>ordered-set aggregate</primary>
<secondary>built-in</secondary>
</indexterm>
<indexterm>
<primary>inverse distribution</primary>
</indexterm>
<table id="functions-orderedset-table">
<title>Ordered-Set Aggregate Functions</title>
<tgroup cols="5">
<thead>
<row>
<entry>Function</entry>
<entry>Direct Argument Type(s)</entry>
<entry>Aggregated Argument Type(s)</entry>
<entry>Return Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>
<indexterm>
<primary>mode</primary>
<secondary>statistical</secondary>
</indexterm>
<function>mode() WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
</entry>
<entry>
</entry>
<entry>
any sortable type
</entry>
<entry>
same as sort expression
</entry>
<entry>
returns the most frequent input value (arbitrarily choosing the first
one if there are multiple equally-frequent results)
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>percentile</primary>
<secondary>continuous</secondary>
</indexterm>
<indexterm>
<primary>median</primary>
</indexterm>
<function>percentile_cont(<replaceable class="parameter">fraction</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
</entry>
<entry>
<type>double precision</type>
</entry>
<entry>
<type>double precision</type> or <type>interval</type>
</entry>
<entry>
same as sort expression
</entry>
<entry>
continuous percentile: returns a value corresponding to the specified
fraction in the ordering, interpolating between adjacent input items if
needed
</entry>
</row>
<row>
<entry>
<function>percentile_cont(<replaceable class="parameter">fractions</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
</entry>
<entry>
<type>double precision[]</type>
</entry>
<entry>
<type>double precision</type> or <type>interval</type>
</entry>
<entry>
array of sort expression's type
</entry>
<entry>
multiple continuous percentile: returns an array of results matching
the shape of the <literal>fractions</literal> parameter, with each
non-null element replaced by the value corresponding to that percentile
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>percentile</primary>
<secondary>discrete</secondary>
</indexterm>
<function>percentile_disc(<replaceable class="parameter">fraction</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
</entry>
<entry>
<type>double precision</type>
</entry>
<entry>
any sortable type
</entry>
<entry>
same as sort expression
</entry>
<entry>
discrete percentile: returns the first input value whose position in
the ordering equals or exceeds the specified fraction
</entry>
</row>
<row>
<entry>
<function>percentile_disc(<replaceable class="parameter">fractions</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
</entry>
<entry>
<type>double precision[]</type>
</entry>
<entry>
any sortable type
</entry>
<entry>
array of sort expression's type
</entry>
<entry>
multiple discrete percentile: returns an array of results matching the
shape of the <literal>fractions</literal> parameter, with each non-null
element replaced by the input value corresponding to that percentile
</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
All the aggregates listed in <xref linkend="functions-orderedset-table">
ignore null values in their sorted input. For those that take
a <replaceable>fraction</replaceable> 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.
</para>
<para>
Each of the aggregates listed in
<xref linkend="functions-hypothetical-table"> is associated with a
window function of the same name defined in
<xref linkend="functions-window">. In each case, the aggregate result
is the value that the associated window function would have
returned for the <quote>hypothetical</> row constructed from
<replaceable>args</replaceable>, if such a row had been added to the sorted
group of rows computed from the <replaceable>sorted_args</replaceable>.
</para>
<table id="functions-hypothetical-table">
<title>Hypothetical-Set Aggregate Functions</title>
<tgroup cols="5">
<thead>
<row>
<entry>Function</entry>
<entry>Direct Argument Type(s)</entry>
<entry>Aggregated Argument Type(s)</entry>
<entry>Return Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>
<indexterm>
<primary>rank</primary>
<secondary>hypothetical</secondary>
</indexterm>
<function>rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
</entry>
<entry>
<literal>VARIADIC</> <type>"any"</type>
</entry>
<entry>
<literal>VARIADIC</> <type>"any"</type>
</entry>
<entry>
<type>bigint</type>
</entry>
<entry>
rank of the hypothetical row, with gaps for duplicate rows
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>dense_rank</primary>
<secondary>hypothetical</secondary>
</indexterm>
<function>dense_rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
</entry>
<entry>
<literal>VARIADIC</> <type>"any"</type>
</entry>
<entry>
<literal>VARIADIC</> <type>"any"</type>
</entry>
<entry>
<type>bigint</type>
</entry>
<entry>
rank of the hypothetical row, without gaps
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>percent_rank</primary>
<secondary>hypothetical</secondary>
</indexterm>
<function>percent_rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
</entry>
<entry>
<literal>VARIADIC</> <type>"any"</type>
</entry>
<entry>
<literal>VARIADIC</> <type>"any"</type>
</entry>
<entry>
<type>double precision</type>
</entry>
<entry>
relative rank of the hypothetical row, ranging from 0 to 1
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>cume_dist</primary>
<secondary>hypothetical</secondary>
</indexterm>
<function>cume_dist(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
</entry>
<entry>
<literal>VARIADIC</> <type>"any"</type>
</entry>
<entry>
<literal>VARIADIC</> <type>"any"</type>
</entry>
<entry>
<type>double precision</type>
</entry>
<entry>
relative rank of the hypothetical row, ranging from
1/<replaceable>N</> to 1
</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
For each of these hypothetical-set aggregates, the list of direct arguments
given in <replaceable>args</replaceable> must match the number and types of
the aggregated arguments given in <replaceable>sorted_args</replaceable>.
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 <literal>ORDER BY</> clause.
</para>
</sect1>
<sect1 id="functions-window">
@ -12332,9 +12619,10 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
</para>
<para>
In addition to these functions, any built-in or user-defined aggregate
function can be used as a window function (see
<xref linkend="functions-aggregate"> for a list of the built-in aggregates).
In addition to these functions, any built-in or user-defined normal
aggregate function (but not ordered-set or hypothetical-set aggregates)
can be used as a window function; see
<xref linkend="functions-aggregate"> for a list of the built-in aggregates.
Aggregate functions act as window functions only when an <literal>OVER</>
clause follows the call; otherwise they act as regular aggregates.
</para>

View File

@ -21,12 +21,15 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
ALTER AGGREGATE <replaceable>name</replaceable> ( [ <replaceable>argmode</replaceable> ] [ <replaceable>arg_name</replaceable> ] <replaceable>arg_data_type</replaceable> [ , ... ] )
RENAME TO <replaceable>new_name</replaceable>
ALTER AGGREGATE <replaceable>name</replaceable> ( [ <replaceable>argmode</replaceable> ] [ <replaceable>arg_name</replaceable> ] <replaceable>arg_data_type</replaceable> [ , ... ] )
OWNER TO <replaceable>new_owner</replaceable>
ALTER AGGREGATE <replaceable>name</replaceable> ( [ <replaceable>argmode</replaceable> ] [ <replaceable>arg_name</replaceable> ] <replaceable>arg_data_type</replaceable> [ , ... ] )
SET SCHEMA <replaceable>new_schema</replaceable>
ALTER AGGREGATE <replaceable>name</replaceable> ( <replaceable>aggregate_signature</replaceable> ) RENAME TO <replaceable>new_name</replaceable>
ALTER AGGREGATE <replaceable>name</replaceable> ( <replaceable>aggregate_signature</replaceable> ) OWNER TO <replaceable>new_owner</replaceable>
ALTER AGGREGATE <replaceable>name</replaceable> ( <replaceable>aggregate_signature</replaceable> ) SET SCHEMA <replaceable>new_schema</replaceable>
<phrase>where <replaceable>aggregate_signature</replaceable> is:</phrase>
* |
[ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] |
[ [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] ] ORDER BY [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ]
</synopsis>
</refsynopsisdiv>
@ -76,7 +79,7 @@ ALTER AGGREGATE <replaceable>name</replaceable> ( [ <replaceable>argmode</replac
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">arg_name</replaceable></term>
<term><replaceable class="parameter">argname</replaceable></term>
<listitem>
<para>
@ -89,12 +92,15 @@ ALTER AGGREGATE <replaceable>name</replaceable> ( [ <replaceable>argmode</replac
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">arg_data_type</replaceable></term>
<term><replaceable class="parameter">argtype</replaceable></term>
<listitem>
<para>
An input data type on which the aggregate function operates.
To reference a zero-argument aggregate function, write <literal>*</>
in place of the list of argument specifications.
To reference an ordered-set aggregate function, write
<literal>ORDER BY</> between the direct and aggregated argument
specifications.
</para>
</listitem>
</varlistentry>
@ -128,6 +134,21 @@ ALTER AGGREGATE <replaceable>name</replaceable> ( [ <replaceable>argmode</replac
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
The recommended syntax for referencing an ordered-set aggregate
is to write <literal>ORDER BY</> between the direct and aggregated
argument specifications, in the same style as in
<xref linkend="sql-createaggregate">. However, it will also work to
omit <literal>ORDER BY</> and just run the direct and aggregated
argument specifications into a single list. In this abbreviated form,
if <literal>VARIADIC "any"</> was used in both the direct and
aggregated argument lists, write <literal>VARIADIC "any"</> only once.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
@ -148,11 +169,17 @@ ALTER AGGREGATE myavg(integer) OWNER TO joe;
</para>
<para>
To move the aggregate function <literal>myavg</literal> for type
<type>integer</type> into schema <literal>myschema</literal>:
To move the ordered-set aggregate <literal>mypercentile</literal> with
direct argument of type <type>float8</type> and aggregated argument
of type <type>integer</type> into schema <literal>myschema</literal>:
<programlisting>
ALTER AGGREGATE myavg(integer) SET SCHEMA myschema;
</programlisting></para>
ALTER AGGREGATE mypercentile(float8 ORDER BY integer) SET SCHEMA myschema;
</programlisting>
This will work too:
<programlisting>
ALTER AGGREGATE mypercentile(float8, integer) SET SCHEMA myschema;
</programlisting>
</para>
</refsect1>
<refsect1>

View File

@ -30,7 +30,7 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
<phrase>where <replaceable class="PARAMETER">member_object</replaceable> is:</phrase>
AGGREGATE <replaceable class="PARAMETER">agg_name</replaceable> ( [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">agg_type</replaceable> [, ...] ) |
AGGREGATE <replaceable class="PARAMETER">aggregate_name</replaceable> ( <replaceable>aggregate_signature</replaceable> ) |
CAST (<replaceable>source_type</replaceable> AS <replaceable>target_type</replaceable>) |
COLLATION <replaceable class="PARAMETER">object_name</replaceable> |
CONVERSION <replaceable class="PARAMETER">object_name</replaceable> |
@ -54,6 +54,12 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
TEXT SEARCH TEMPLATE <replaceable class="PARAMETER">object_name</replaceable> |
TYPE <replaceable class="PARAMETER">object_name</replaceable> |
VIEW <replaceable class="PARAMETER">object_name</replaceable>
<phrase>and <replaceable>aggregate_signature</replaceable> is:</phrase>
* |
[ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] |
[ [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] ] ORDER BY [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ]
</synopsis>
</refsynopsisdiv>
@ -159,7 +165,7 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
<varlistentry>
<term><replaceable class="parameter">object_name</replaceable></term>
<term><replaceable class="parameter">agg_name</replaceable></term>
<term><replaceable class="parameter">aggregate_name</replaceable></term>
<term><replaceable class="parameter">function_name</replaceable></term>
<term><replaceable class="parameter">operator_name</replaceable></term>
<listitem>
@ -173,17 +179,6 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">agg_type</replaceable></term>
<listitem>
<para>
An input data type on which the aggregate function operates.
To reference a zero-argument aggregate function, write <literal>*</>
in place of the list of argument specifications.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>source_type</replaceable></term>
<listitem>
@ -207,7 +202,8 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
<listitem>
<para>
The mode of a function argument: <literal>IN</>, <literal>OUT</>,
The mode of a function or aggregate
argument: <literal>IN</>, <literal>OUT</>,
<literal>INOUT</>, or <literal>VARIADIC</>.
If omitted, the default is <literal>IN</>.
Note that <command>ALTER EXTENSION</command> does not actually pay
@ -224,7 +220,7 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
<listitem>
<para>
The name of a function argument.
The name of a function or aggregate argument.
Note that <command>ALTER EXTENSION</command> does not actually pay
any attention to argument names, since only the argument data
types are needed to determine the function's identity.
@ -237,8 +233,7 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
<listitem>
<para>
The data type(s) of the function's arguments (optionally
schema-qualified), if any.
The data type of a function or aggregate argument.
</para>
</listitem>
</varlistentry>

View File

@ -23,7 +23,7 @@ PostgreSQL documentation
<synopsis>
COMMENT ON
{
AGGREGATE <replaceable class="PARAMETER">agg_name</replaceable> ( [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">agg_type</replaceable> [, ...] ) |
AGGREGATE <replaceable class="PARAMETER">aggregate_name</replaceable> ( <replaceable>aggregate_signature</replaceable> ) |
CAST (<replaceable>source_type</replaceable> AS <replaceable>target_type</replaceable>) |
COLLATION <replaceable class="PARAMETER">object_name</replaceable> |
COLUMN <replaceable class="PARAMETER">relation_name</replaceable>.<replaceable class="PARAMETER">column_name</replaceable> |
@ -58,6 +58,12 @@ COMMENT ON
TYPE <replaceable class="PARAMETER">object_name</replaceable> |
VIEW <replaceable class="PARAMETER">object_name</replaceable>
} IS '<replaceable class="PARAMETER">text</replaceable>'
<phrase>where <replaceable>aggregate_signature</replaceable> is:</phrase>
* |
[ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] |
[ [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] ] ORDER BY [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ]
</synopsis>
</refsynopsisdiv>
@ -101,7 +107,7 @@ COMMENT ON
<varlistentry>
<term><replaceable class="parameter">object_name</replaceable></term>
<term><replaceable class="parameter">relation_name</replaceable>.<replaceable>column_name</replaceable></term>
<term><replaceable class="parameter">agg_name</replaceable></term>
<term><replaceable class="parameter">aggregate_name</replaceable></term>
<term><replaceable class="parameter">constraint_name</replaceable></term>
<term><replaceable class="parameter">function_name</replaceable></term>
<term><replaceable class="parameter">operator_name</replaceable></term>
@ -120,17 +126,6 @@ COMMENT ON
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">agg_type</replaceable></term>
<listitem>
<para>
An input data type on which the aggregate function operates.
To reference a zero-argument aggregate function, write <literal>*</>
in place of the list of argument specifications.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>source_type</replaceable></term>
<listitem>
@ -153,7 +148,8 @@ COMMENT ON
<term><replaceable class="parameter">argmode</replaceable></term>
<listitem>
<para>
The mode of a function argument: <literal>IN</>, <literal>OUT</>,
The mode of a function or aggregate
argument: <literal>IN</>, <literal>OUT</>,
<literal>INOUT</>, or <literal>VARIADIC</>.
If omitted, the default is <literal>IN</>.
Note that <command>COMMENT</command> does not actually pay
@ -169,7 +165,7 @@ COMMENT ON
<term><replaceable class="parameter">argname</replaceable></term>
<listitem>
<para>
The name of a function argument.
The name of a function or aggregate argument.
Note that <command>COMMENT</command> does not actually pay
any attention to argument names, since only the argument data
types are needed to determine the function's identity.
@ -181,8 +177,7 @@ COMMENT ON
<term><replaceable class="parameter">argtype</replaceable></term>
<listitem>
<para>
The data type(s) of the function's arguments (optionally
schema-qualified), if any.
The data type of a function or aggregate argument.
</para>
</listitem>
</varlistentry>

View File

@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
CREATE AGGREGATE <replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_data_type</replaceable> [ , ... ] ) (
CREATE AGGREGATE <replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">arg_data_type</replaceable> [ , ... ] ) (
SFUNC = <replaceable class="PARAMETER">sfunc</replaceable>,
STYPE = <replaceable class="PARAMETER">state_data_type</replaceable>
[ , SSPACE = <replaceable class="PARAMETER">state_data_size</replaceable> ]
@ -30,6 +30,16 @@ CREATE AGGREGATE <replaceable class="parameter">name</replaceable> ( [ <replacea
[ , SORTOP = <replaceable class="PARAMETER">sort_operator</replaceable> ]
)
CREATE AGGREGATE <replaceable class="parameter">name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">arg_data_type</replaceable> [ , ... ] ]
ORDER BY [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">arg_data_type</replaceable> [ , ... ] ) (
SFUNC = <replaceable class="PARAMETER">sfunc</replaceable>,
STYPE = <replaceable class="PARAMETER">state_data_type</replaceable>
[ , SSPACE = <replaceable class="PARAMETER">state_data_size</replaceable> ]
[ , FINALFUNC = <replaceable class="PARAMETER">ffunc</replaceable> ]
[ , INITCOND = <replaceable class="PARAMETER">initial_condition</replaceable> ]
[ , HYPOTHETICAL ]
)
<phrase>or the old syntax</phrase>
CREATE AGGREGATE <replaceable class="PARAMETER">name</replaceable> (
@ -69,6 +79,8 @@ CREATE AGGREGATE <replaceable class="PARAMETER">name</replaceable> (
name and input data type(s) of an aggregate must also be distinct from
the name and input data type(s) of every ordinary function in the same
schema.
This behavior is identical to overloading of ordinary function names
(see <xref linkend="sql-createfunction">).
</para>
<para>
@ -128,7 +140,7 @@ CREATE AGGREGATE <replaceable class="PARAMETER">name</replaceable> (
<para>
If the state transition function is not strict, then it will be called
unconditionally at each input row, and must deal with null inputs
and null transition values for itself. This allows the aggregate
and null state values for itself. This allows the aggregate
author to have full control over the aggregate's handling of null values.
</para>
@ -142,6 +154,22 @@ CREATE AGGREGATE <replaceable class="PARAMETER">name</replaceable> (
input rows.
</para>
<para>
The syntax with <literal>ORDER BY</literal> in the parameter list creates
a special type of aggregate called an <firstterm>ordered-set
aggregate</firstterm>; or if <literal>HYPOTHETICAL</> is specified, then
a <firstterm>hypothetical-set aggregate</firstterm> is created. These
aggregates operate over groups of sorted values in order-dependent ways,
so that specification of an input sort order is an essential part of a
call. Also, they can have <firstterm>direct</> arguments, which are
arguments that are evaluated only once per aggregation rather than once
per input row. Hypothetical-set aggregates are a subclass of ordered-set
aggregates in which some of the direct arguments are required to match,
in number and datatypes, the aggregated argument columns. This allows
the values of those direct arguments to be added to the collection of
aggregate-input rows as an additional <quote>hypothetical</> row.
</para>
<para>
Aggregates that behave like <function>MIN</> or <function>MAX</> can
sometimes be optimized by looking into an index instead of scanning every
@ -202,7 +230,7 @@ SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">arg_name</replaceable></term>
<term><replaceable class="parameter">argname</replaceable></term>
<listitem>
<para>
@ -234,6 +262,7 @@ SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
only one input parameter. To define a zero-argument aggregate function
with this syntax, specify the <literal>basetype</> as
<literal>"ANY"</> (not <literal>*</>).
Ordered-set aggregates cannot be defined with the old syntax.
</para>
</listitem>
</varlistentry>
@ -243,7 +272,7 @@ SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
<listitem>
<para>
The name of the state transition function to be called for each
input row. For an <replaceable class="PARAMETER">N</>-argument
input row. For a normal <replaceable class="PARAMETER">N</>-argument
aggregate function, the <replaceable class="PARAMETER">sfunc</>
must take <replaceable class="PARAMETER">N</>+1 arguments,
the first being of type <replaceable
@ -254,6 +283,13 @@ SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
takes the current state value and the current input data value(s),
and returns the next state value.
</para>
<para>
For ordered-set (including hypothetical-set) aggregates, the state
transition function receives only the current state value and the
aggregated arguments, not the direct arguments. Otherwise it is the
same.
</para>
</listitem>
</varlistentry>
@ -287,7 +323,8 @@ SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
<listitem>
<para>
The name of the final function called to compute the aggregate's
result after all input rows have been traversed. The function
result after all input rows have been traversed.
For a normal aggregate, this function
must take a single argument of type <replaceable
class="PARAMETER">state_data_type</replaceable>. The return
data type of the aggregate is defined as the return type of this
@ -296,6 +333,17 @@ SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
aggregate's result, and the return type is <replaceable
class="PARAMETER">state_data_type</replaceable>.
</para>
<para>
For ordered-set (including hypothetical-set) aggregates, the
final function receives not only the final state value,
but also the values of all the direct arguments, followed by
null values corresponding to each aggregated argument.
(The reason for including the aggregated arguments in the function
signature is that this may be necessary to allow correct resolution
of the aggregate result type, when a polymorphic aggregate is
being defined.)
</para>
</listitem>
</varlistentry>
@ -319,7 +367,22 @@ SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
<function>MAX</>-like aggregate.
This is just an operator name (possibly schema-qualified).
The operator is assumed to have the same input data types as
the aggregate (which must be a single-argument aggregate).
the aggregate (which must be a single-argument normal aggregate).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>HYPOTHETICAL</literal></term>
<listitem>
<para>
For ordered-set aggregates only, this flag specifies that the aggregate
arguments are to be processed according to the requirements for
hypothetical-set aggregates: that is, the last few direct arguments must
match the data types of the aggregated (<literal>WITHIN GROUP</>)
arguments. The <literal>HYPOTHETICAL</literal> flag has no effect on
run-time behavior, only on parse-time resolution of the data types and
collations of the aggregate's arguments.
</para>
</listitem>
</varlistentry>
@ -331,6 +394,29 @@ SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
</para>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
The syntax for ordered-set aggregates allows <literal>VARIADIC</>
to be specified for both the last direct parameter and the last
aggregated (<literal>WITHIN GROUP</>) parameter. However, the
current implementation restricts use of <literal>VARIADIC</>
in two ways. First, ordered-set aggregates can only use
<literal>VARIADIC "any"</>, not other variadic array types.
Second, if the last direct parameter is <literal>VARIADIC "any"</>,
then there can be only one aggregated parameter and it must also
be <literal>VARIADIC "any"</>. (In the representation used in the
system catalogs, these two parameters are merged into a single
<literal>VARIADIC "any"</> item, since <structname>pg_proc</> cannot
represent functions with more than one <literal>VARIADIC</> parameter.)
If the aggregate is a hypothetical-set aggregate, the direct arguments
that match the <literal>VARIADIC "any"</> parameter are the hypothetical
ones; any preceding parameters represent additional direct arguments
that are not constrained to match the aggregated arguments.
</para>
</refsect1>
<refsect1>
<title>Examples</title>

View File

@ -21,9 +21,13 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
DROP AGGREGATE [ IF EXISTS ]
<replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_data_type</replaceable> [ , ... ] )
[ CASCADE | RESTRICT ]
DROP AGGREGATE [ IF EXISTS ] <replaceable>name</replaceable> ( <replaceable>aggregate_signature</replaceable> ) [ CASCADE | RESTRICT ]
<phrase>where <replaceable>aggregate_signature</replaceable> is:</phrase>
* |
[ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] |
[ [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] ] ORDER BY [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ]
</synopsis>
</refsynopsisdiv>
@ -73,7 +77,7 @@ DROP AGGREGATE [ IF EXISTS ]
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">arg_name</replaceable></term>
<term><replaceable class="parameter">argname</replaceable></term>
<listitem>
<para>
@ -86,12 +90,15 @@ DROP AGGREGATE [ IF EXISTS ]
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">arg_data_type</replaceable></term>
<term><replaceable class="parameter">argtype</replaceable></term>
<listitem>
<para>
An input data type on which the aggregate function operates.
To reference a zero-argument aggregate function, write <literal>*</>
in place of the list of argument specifications.
To reference an ordered-set aggregate function, write
<literal>ORDER BY</> between the direct and aggregated argument
specifications.
</para>
</listitem>
</varlistentry>
@ -117,6 +124,15 @@ DROP AGGREGATE [ IF EXISTS ]
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
Alternative syntaxes for referencing ordered-set aggregates
are described under <xref linkend="sql-alteraggregate">.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
@ -125,7 +141,17 @@ DROP AGGREGATE [ IF EXISTS ]
<type>integer</type>:
<programlisting>
DROP AGGREGATE myavg(integer);
</programlisting></para>
</programlisting>
</para>
<para>
To remove the hypothetical-set aggregate function <literal>myrank</>,
which takes an arbitrary list of ordering columns and a matching list
of direct arguments:
<programlisting>
DROP AGGREGATE myrank(VARIADIC "any" ORDER BY VARIADIC "any");
</programlisting>
</para>
</refsect1>
<refsect1>

View File

@ -25,7 +25,7 @@ SECURITY LABEL [ FOR <replaceable class="PARAMETER">provider</replaceable> ] ON
{
TABLE <replaceable class="PARAMETER">object_name</replaceable> |
COLUMN <replaceable class="PARAMETER">table_name</replaceable>.<replaceable class="PARAMETER">column_name</replaceable> |
AGGREGATE <replaceable class="PARAMETER">agg_name</replaceable> ( [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">agg_type</replaceable> [, ...] ) |
AGGREGATE <replaceable class="PARAMETER">aggregate_name</replaceable> ( <replaceable>aggregate_signature</replaceable> ) |
DATABASE <replaceable class="PARAMETER">object_name</replaceable> |
DOMAIN <replaceable class="PARAMETER">object_name</replaceable> |
EVENT TRIGGER <replaceable class="PARAMETER">object_name</replaceable> |
@ -41,6 +41,12 @@ SECURITY LABEL [ FOR <replaceable class="PARAMETER">provider</replaceable> ] ON
TYPE <replaceable class="PARAMETER">object_name</replaceable> |
VIEW <replaceable class="PARAMETER">object_name</replaceable>
} IS '<replaceable class="PARAMETER">label</replaceable>'
<phrase>where <replaceable>aggregate_signature</replaceable> is:</phrase>
* |
[ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] |
[ [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ] ] ORDER BY [ <replaceable>argmode</replaceable> ] [ <replaceable>argname</replaceable> ] <replaceable>argtype</replaceable> [ , ... ]
</synopsis>
</refsynopsisdiv>
@ -83,7 +89,7 @@ SECURITY LABEL [ FOR <replaceable class="PARAMETER">provider</replaceable> ] ON
<varlistentry>
<term><replaceable class="parameter">object_name</replaceable></term>
<term><replaceable class="parameter">table_name.column_name</replaceable></term>
<term><replaceable class="parameter">agg_name</replaceable></term>
<term><replaceable class="parameter">aggregate_name</replaceable></term>
<term><replaceable class="parameter">function_name</replaceable></term>
<listitem>
<para>
@ -106,23 +112,13 @@ SECURITY LABEL [ FOR <replaceable class="PARAMETER">provider</replaceable> ] ON
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">agg_type</replaceable></term>
<listitem>
<para>
An input data type on which the aggregate function operates.
To reference a zero-argument aggregate function, write <literal>*</>
in place of the list of argument specifications.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">argmode</replaceable></term>
<listitem>
<para>
The mode of a function argument: <literal>IN</>, <literal>OUT</>,
The mode of a function or aggregate
argument: <literal>IN</>, <literal>OUT</>,
<literal>INOUT</>, or <literal>VARIADIC</>.
If omitted, the default is <literal>IN</>.
Note that <command>SECURITY LABEL</command> does not actually
@ -139,7 +135,7 @@ SECURITY LABEL [ FOR <replaceable class="PARAMETER">provider</replaceable> ] ON
<listitem>
<para>
The name of a function argument.
The name of a function or aggregate argument.
Note that <command>SECURITY LABEL</command> does not actually
pay any attention to argument names, since only the argument data
types are needed to determine the function's identity.
@ -152,8 +148,7 @@ SECURITY LABEL [ FOR <replaceable class="PARAMETER">provider</replaceable> ] ON
<listitem>
<para>
The data type(s) of the function's arguments (optionally
schema-qualified), if any.
The data type of a function or aggregate argument.
</para>
</listitem>
</varlistentry>

View File

@ -1555,7 +1555,15 @@ sqrt(2)
</indexterm>
<indexterm zone="syntax-aggregates">
<primary>filter</primary>
<primary>ordered-set aggregate</primary>
</indexterm>
<indexterm zone="syntax-aggregates">
<primary>WITHIN GROUP</primary>
</indexterm>
<indexterm zone="syntax-aggregates">
<primary>FILTER</primary>
</indexterm>
<para>
@ -1570,6 +1578,7 @@ sqrt(2)
<replaceable>aggregate_name</replaceable> (ALL <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
<replaceable>aggregate_name</replaceable> (DISTINCT <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
<replaceable>aggregate_name</replaceable> ( * ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
<replaceable>aggregate_name</replaceable> ( [ <replaceable>expression</replaceable> [ , ... ] ] ) WITHIN GROUP ( <replaceable>order_by_clause</replaceable> ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
</synopsis>
where <replaceable>aggregate_name</replaceable> is a previously
@ -1589,9 +1598,11 @@ sqrt(2)
The third form invokes the aggregate once for each distinct value
of the expression (or distinct set of values, for multiple expressions)
found in the input rows.
The last form invokes the aggregate once for each input row; since no
The fourth form invokes the aggregate once for each input row; since no
particular input value is specified, it is generally only useful
for the <function>count(*)</function> aggregate function.
The last form is used with <firstterm>ordered-set</> aggregate
functions, which are described below.
</para>
<para>
@ -1610,23 +1621,6 @@ sqrt(2)
distinct non-null values of <literal>f1</literal>.
</para>
<para>
If <literal>FILTER</literal> is specified, then only the input
rows for which the <replaceable>filter_clause</replaceable>
evaluates to true are fed to the aggregate function; other rows
are discarded. For example:
<programlisting>
SELECT
count(*) AS unfiltered,
count(*) FILTER (WHERE i < 5) AS filtered
FROM generate_series(1,10) AS s(i);
unfiltered | filtered
------------+----------
10 | 4
(1 row)
</programlisting>
</para>
<para>
Ordinarily, the input rows are fed to the aggregate function in an
unspecified order. In many cases this does not matter; for example,
@ -1676,6 +1670,71 @@ SELECT string_agg(a ORDER BY a, ',') FROM table; -- incorrect
</para>
</note>
<para>
Placing <literal>ORDER BY</> within the aggregate's regular argument
list, as described so far, is used when ordering the input rows for
a <quote>normal</> aggregate for which ordering is optional. There is a
subclass of aggregate functions called <firstterm>ordered-set
aggregates</> for which an <replaceable>order_by_clause</replaceable>
is <emphasis>required</>, usually because the aggregate's computation is
only sensible in terms of a specific ordering of its input rows.
Typical examples of ordered-set aggregates include rank and percentile
calculations. For an ordered-set aggregate,
the <replaceable>order_by_clause</replaceable> is written
inside <literal>WITHIN GROUP (...)</>, as shown in the final syntax
alternative above. The expressions in
the <replaceable>order_by_clause</replaceable> are evaluated once per
input row just like normal aggregate arguments, sorted as per
the <replaceable>order_by_clause</replaceable>'s requirements, and fed
to the aggregate function as input arguments. (This is unlike the case
for a non-<literal>WITHIN GROUP</> <replaceable>order_by_clause</>,
which is not treated as argument(s) to the aggregate function.) The
argument expressions preceding <literal>WITHIN GROUP</>, if any, are
called <firstterm>direct arguments</> to distinguish them from
the <firstterm>aggregated arguments</> listed in
the <replaceable>order_by_clause</replaceable>. Unlike normal aggregate
arguments, direct arguments are evaluated only once per aggregate call,
not once per input row. This means that they can contain variables only
if those variables are grouped by <literal>GROUP BY</>; this restriction
is the same as if the direct arguments were not inside an aggregate
expression at all. Direct arguments are typically used for things like
percentile fractions, which only make sense as a single value per
aggregation calculation. The direct argument list can be empty; in this
case, write just <literal>()</> not <literal>(*)</>.
(<productname>PostgreSQL</> will actually accept either spelling, but
only the first way conforms to the SQL standard.)
An example of an ordered-set aggregate call is:
<programlisting>
SELECT percentile_disc(0.5) WITHIN GROUP (ORDER BY income) FROM households;
percentile_disc
-----------------
50489
</programlisting>
which obtains the 50th percentile, or median, value of
the <structfield>income</> column from table <structname>households</>.
Here, <literal>0.5</> is a direct argument; it would make no sense
for the percentile fraction to be a value varying across rows.
</para>
<para>
If <literal>FILTER</literal> is specified, then only the input
rows for which the <replaceable>filter_clause</replaceable>
evaluates to true are fed to the aggregate function; other rows
are discarded. For example:
<programlisting>
SELECT
count(*) AS unfiltered,
count(*) FILTER (WHERE i < 5) AS filtered
FROM generate_series(1,10) AS s(i);
unfiltered | filtered
------------+----------
10 | 4
(1 row)
</programlisting>
</para>
<para>
The predefined aggregate functions are described in <xref
linkend="functions-aggregate">. Other aggregate functions can be added
@ -1695,7 +1754,8 @@ SELECT string_agg(a ORDER BY a, ',') FROM table; -- incorrect
<xref linkend="sql-syntax-scalar-subqueries"> and
<xref linkend="functions-subquery">), the aggregate is normally
evaluated over the rows of the subquery. But an exception occurs
if the aggregate's arguments contain only outer-level variables:
if the aggregate's arguments (and <replaceable>filter_clause</replaceable>
if any) contain only outer-level variables:
the aggregate then belongs to the nearest such outer level, and is
evaluated over the rows of that query. The aggregate expression
as a whole is then an outer reference for the subquery it appears in,
@ -1856,15 +1916,16 @@ UNBOUNDED FOLLOWING
If <literal>FILTER</literal> is specified, then only the input
rows for which the <replaceable>filter_clause</replaceable>
evaluates to true are fed to the window function; other rows
are discarded. Only aggregate window functions accept
are discarded. Only window functions that are aggregates accept
a <literal>FILTER</literal> clause.
</para>
<para>
The built-in window functions are described in <xref
linkend="functions-window-table">. Other window functions can be added by
the user. Also, any built-in or user-defined aggregate function can be
used as a window function.
the user. Also, any built-in or user-defined normal aggregate function
can be used as a window function. Ordered-set aggregates presently
cannot be used as window functions, however.
</para>
<para>
@ -1885,7 +1946,7 @@ UNBOUNDED FOLLOWING
<para>
More information about window functions can be found in
<xref linkend="tutorial-window">,
<xref linkend="functions-window">,
<xref linkend="functions-window">, and
<xref linkend="queries-window">.
</para>
</sect2>

View File

@ -9,20 +9,27 @@
</indexterm>
<para>
Aggregate functions in <productname>PostgreSQL</productname>
are expressed in terms of <firstterm>state values</firstterm>
Aggregate functions in <productname>PostgreSQL</productname>
are defined in terms of <firstterm>state values</firstterm>
and <firstterm>state transition functions</firstterm>.
That is, an aggregate operates using a state value that is updated
as each successive input row is processed.
To define a new aggregate
function, one selects a data type for the state value,
an initial value for the state, and a state transition
function. The state transition function is just an
ordinary function that could also be used outside the
context of the aggregate. A <firstterm>final function</firstterm>
function. The state transition function takes the previous state
value and the aggregate's input value(s) for the current row, and
returns a new state value.
A <firstterm>final function</firstterm>
can also be specified, in case the desired result of the aggregate
is different from the data that needs to be kept in the running
state value.
state value. The final function takes the last state value
and returns whatever is wanted as the aggregate result.
In principle, the transition and final functions are just ordinary
functions that could also be used outside the context of the
aggregate. (In practice, it's often helpful for performance reasons
to create specialized transition functions that can only work when
called as part of an aggregate.)
</para>
<para>
@ -42,20 +49,24 @@
we only need the addition function for that data type.
The aggregate definition would be:
<screen>
<programlisting>
CREATE AGGREGATE sum (complex)
(
sfunc = complex_add,
stype = complex,
initcond = '(0,0)'
);
</programlisting>
which we might use like this:
<programlisting>
SELECT sum(a) FROM test_complex;
sum
-----------
(34,53.9)
</screen>
</programlisting>
(Notice that we are relying on function overloading: there is more than
one aggregate named <function>sum</>, but
@ -64,19 +75,19 @@ SELECT sum(a) FROM test_complex;
</para>
<para>
The above definition of <function>sum</function> will return zero (the initial
state condition) if there are no nonnull input values.
The above definition of <function>sum</function> will return zero
(the initial state value) if there are no nonnull input values.
Perhaps we want to return null in that case instead &mdash; the SQL standard
expects <function>sum</function> to behave that way. We can do this simply by
omitting the <literal>initcond</literal> phrase, so that the initial state
condition is null. Ordinarily this would mean that the <literal>sfunc</literal>
would need to check for a null state-condition input. But for
value is null. Ordinarily this would mean that the <literal>sfunc</literal>
would need to check for a null state-value input. But for
<function>sum</function> and some other simple aggregates like
<function>max</> and <function>min</>,
it is sufficient to insert the first nonnull input value into
the state variable and then start applying the transition function
at the second nonnull input value. <productname>PostgreSQL</productname>
will do that automatically if the initial condition is null and
will do that automatically if the initial state value is null and
the transition function is marked <quote>strict</> (i.e., not to be called
for null inputs).
</para>
@ -109,12 +120,16 @@ CREATE AGGREGATE avg (float8)
initcond = '{0,0,0}'
);
</programlisting>
</para>
(<function>float8_accum</> requires a three-element array, not just
<note>
<para>
<function>float8_accum</> requires a three-element array, not just
two elements, because it accumulates the sum of squares as well as
the sum and count of the inputs. This is so that it can be used for
some other aggregates besides <function>avg</>.)
</para>
some other aggregates besides <function>avg</>.
</para>
</note>
<para>
Aggregate functions can use polymorphic
@ -136,7 +151,7 @@ CREATE AGGREGATE array_accum (anyelement)
);
</programlisting>
Here, the actual state type for any aggregate call is the array type
Here, the actual state type for any given aggregate call is the array type
having the actual input type as elements. The behavior of the aggregate
is to concatenate all the inputs into an array of that type.
(Note: the built-in aggregate <function>array_agg</> provides similar
@ -205,6 +220,97 @@ SELECT myaggregate(a, b, c ORDER BY a) FROM ...
</para>
</note>
<para>
Aggregate function calls in SQL allow <literal>DISTINCT</>
and <literal>ORDER BY</> options that control which rows are fed
to the aggregate's transition function and in what order. These
options are implemented behind the scenes and are not the concern
of the aggregate's support functions.
</para>
<para>
The aggregates we have been describing so far are <quote>normal</>
aggregates. <productname>PostgreSQL</> also
supports <firstterm>ordered-set aggregates</>, which differ from
normal aggregates in two key ways. First, in addition to ordinary
aggregated arguments that are evaluated once per input row, an
ordered-set aggregate can have <quote>direct</> arguments that are
evaluated only once per aggregation operation. Second, the syntax
for the ordinary aggregated arguments specifies a sort ordering
for them explicitly. An ordered-set aggregate is usually
used to implement a computation that depends on a specific row
ordering, for instance rank or percentile, so that the sort ordering
is a required aspect of any call. For example, the built-in
definition of <function>percentile_disc</> is equivalent to:
<programlisting>
CREATE AGGREGATE percentile_disc (float8 ORDER BY anyelement)
(
sfunc = ordered_set_transition,
stype = internal,
finalfunc = percentile_disc_final
);
</programlisting>
which could be used to obtain a median household income like this:
<programlisting>
SELECT percentile_disc(0.5) WITHIN GROUP (ORDER BY income) FROM households;
percentile_disc
-----------------
50489
</programlisting>
Here, <literal>0.5</> is a direct argument; it would make no sense
for the percentile fraction to be a value varying across rows.
</para>
<para>
Unlike the case for normal aggregates, the sorting of input rows for
an ordered-set aggregate is <emphasis>not</> done behind the scenes,
but is the responsibility of the aggregate's support functions.
The typical implementation approach is to keep a reference to
a <quote>tuplesort</> object in the aggregate's state value, feed the
incoming rows into that object, and then complete the sorting and
read out the data in the final function. This design allows the
final function to perform special operations such as injecting
additional <quote>hypothetical</> rows into the data to be sorted.
While normal aggregates can often be implemented with support
functions written in <application>PL/pgSQL</application> or another
PL language, ordered-set aggregates generally have to be written in
C, since their state values aren't definable as any SQL datatype.
(In the above example, notice that the state value is declared as
type <type>internal</> &mdash; this is typical.)
</para>
<para>
The state transition function for an ordered-set aggregate receives
the current state value plus the aggregated input values for
each row, and returns the updated state value. This is the
same definition as for normal aggregates, but note that the direct
arguments (if any) are not provided. The final function receives
the last state value, the values of the direct arguments if any,
and null values corresponding to the aggregated input(s). While the
null values seem useless at first sight, they are important because
they make it possible to include the data types of the aggregated
input(s) in the final function's signature, which may be necessary
to resolve the output type of a polymorphic aggregate. For example,
the built-in <function>mode()</> ordered-set aggregate takes a
single aggregated column of any sortable data type and returns a
value of that same type. This is possible because the final function
is declared as <literal>mode_final(internal, anyelement) returns
anyelement</>, with the <type>anyelement</> parameter corresponding
to the dummy null argument that represents the aggregated column.
The actual data is conveyed in the <type>internal</>-type state
value, but type resolution needs a parse-time indication of what the
result data type will be, and the dummy argument provides that.
In the example of <function>percentile_disc</>, the support functions
are respectively declared as
<literal>ordered_set_transition(internal, "any") returns internal</>
and <literal>percentile_disc_final(internal, float8, anyelement)
returns anyelement</>.
</para>
<para>
A function written in C can detect that it is being called as an
aggregate transition or final function by calling
@ -214,14 +320,25 @@ if (AggCheckCallContext(fcinfo, NULL))
</programlisting>
One reason for checking this is that when it is true for a transition
function, the first input
must be a temporary transition value and can therefore safely be modified
must be a temporary state value and can therefore safely be modified
in-place rather than allocating a new copy.
See <literal>int8inc()</> for an example.
(This is the <emphasis>only</>
case where it is safe for a function to modify a pass-by-reference input.
In particular, aggregate final functions should not modify their inputs in
any case, because in some cases they will be re-executed on the same
final transition value.)
In particular, final functions for normal aggregates must not
modify their inputs in any case, because in some cases they will be
re-executed on the same final state value.)
</para>
<para>
Another support routine available to aggregate functions written in C
is <function>AggGetAggref</>, which returns the <literal>Aggref</>
parse node that defines the aggregate call. This is mainly useful
for ordered-set aggregates, which can inspect the substructure of
the <literal>Aggref</> node to find out what sort ordering they are
supposed to implement. Examples can be found
in <filename>orderedsetaggs.c</> in the <productname>PostgreSQL</>
source code.
</para>
<para>