mirror of
https://github.com/postgres/postgres.git
synced 2025-08-30 06:01:21 +03:00
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
447 lines
18 KiB
Plaintext
447 lines
18 KiB
Plaintext
<!--
|
|
doc/src/sgml/ref/create_aggregate.sgml
|
|
PostgreSQL documentation
|
|
-->
|
|
|
|
<refentry id="SQL-CREATEAGGREGATE">
|
|
<refmeta>
|
|
<refentrytitle>CREATE AGGREGATE</refentrytitle>
|
|
<manvolnum>7</manvolnum>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>CREATE AGGREGATE</refname>
|
|
<refpurpose>define a new aggregate function</refpurpose>
|
|
</refnamediv>
|
|
|
|
<indexterm zone="sql-createaggregate">
|
|
<primary>CREATE AGGREGATE</primary>
|
|
</indexterm>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
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> ]
|
|
[ , FINALFUNC = <replaceable class="PARAMETER">ffunc</replaceable> ]
|
|
[ , INITCOND = <replaceable class="PARAMETER">initial_condition</replaceable> ]
|
|
[ , 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> (
|
|
BASETYPE = <replaceable class="PARAMETER">base_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> ]
|
|
[ , SORTOP = <replaceable class="PARAMETER">sort_operator</replaceable> ]
|
|
)
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1>
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
<command>CREATE AGGREGATE</command> defines a new aggregate
|
|
function. Some basic and commonly-used aggregate functions are
|
|
included with the distribution; they are documented in <xref
|
|
linkend="functions-aggregate">. If one defines new types or needs
|
|
an aggregate function not already provided, then <command>CREATE
|
|
AGGREGATE</command> can be used to provide the desired features.
|
|
</para>
|
|
|
|
<para>
|
|
If a schema name is given (for example, <literal>CREATE AGGREGATE
|
|
myschema.myagg ...</>) then the aggregate function is created in the
|
|
specified schema. Otherwise it is created in the current schema.
|
|
</para>
|
|
|
|
<para>
|
|
An aggregate function is identified by its name and input data type(s).
|
|
Two aggregates in the same schema can have the same name if they operate on
|
|
different input types. The
|
|
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>
|
|
An aggregate function is made from one or two ordinary
|
|
functions:
|
|
a state transition function
|
|
<replaceable class="PARAMETER">sfunc</replaceable>,
|
|
and an optional final calculation function
|
|
<replaceable class="PARAMETER">ffunc</replaceable>.
|
|
These are used as follows:
|
|
<programlisting>
|
|
<replaceable class="PARAMETER">sfunc</replaceable>( internal-state, next-data-values ) ---> next-internal-state
|
|
<replaceable class="PARAMETER">ffunc</replaceable>( internal-state ) ---> aggregate-value
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> creates a temporary variable
|
|
of data type <replaceable class="PARAMETER">stype</replaceable>
|
|
to hold the current internal state of the aggregate. At each input row,
|
|
the aggregate argument value(s) are calculated and
|
|
the state transition function is invoked with the current state value
|
|
and the new argument value(s) to calculate a new
|
|
internal state value. After all the rows have been processed,
|
|
the final function is invoked once to calculate the aggregate's return
|
|
value. If there is no final function then the ending state value
|
|
is returned as-is.
|
|
</para>
|
|
|
|
<para>
|
|
An aggregate function can provide an initial condition,
|
|
that is, an initial value for the internal state value.
|
|
This is specified and stored in the database as a value of type
|
|
<type>text</type>, but it must be a valid external representation
|
|
of a constant of the state value data type. If it is not supplied
|
|
then the state value starts out null.
|
|
</para>
|
|
|
|
<para>
|
|
If the state transition function is declared <quote>strict</quote>,
|
|
then it cannot be called with null inputs. With such a transition
|
|
function, aggregate execution behaves as follows. Rows with any null input
|
|
values are ignored (the function is not called and the previous state value
|
|
is retained). If the initial state value is null, then at the first row
|
|
with all-nonnull input values, the first argument value replaces the state
|
|
value, and the transition function is invoked at subsequent rows with
|
|
all-nonnull input values.
|
|
This is handy for implementing aggregates like <function>max</function>.
|
|
Note that this behavior is only available when
|
|
<replaceable class="PARAMETER">state_data_type</replaceable>
|
|
is the same as the first
|
|
<replaceable class="PARAMETER">arg_data_type</replaceable>.
|
|
When these types are different, you must supply a nonnull initial
|
|
condition or use a nonstrict transition function.
|
|
</para>
|
|
|
|
<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 state values for itself. This allows the aggregate
|
|
author to have full control over the aggregate's handling of null values.
|
|
</para>
|
|
|
|
<para>
|
|
If the final function is declared <quote>strict</quote>, then it will not
|
|
be called when the ending state value is null; instead a null result
|
|
will be returned automatically. (Of course this is just the normal
|
|
behavior of strict functions.) In any case the final function has
|
|
the option of returning a null value. For example, the final function for
|
|
<function>avg</function> returns null when it sees there were zero
|
|
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
|
|
input row. If this aggregate can be so optimized, indicate it by
|
|
specifying a <firstterm>sort operator</>. The basic requirement is that
|
|
the aggregate must yield the first element in the sort ordering induced by
|
|
the operator; in other words:
|
|
<programlisting>
|
|
SELECT agg(col) FROM tab;
|
|
</programlisting>
|
|
must be equivalent to:
|
|
<programlisting>
|
|
SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
|
|
</programlisting>
|
|
Further assumptions are that the aggregate ignores null inputs, and that
|
|
it delivers a null result if and only if there were no non-null inputs.
|
|
Ordinarily, a data type's <literal><</> operator is the proper sort
|
|
operator for <function>MIN</>, and <literal>></> is the proper sort
|
|
operator for <function>MAX</>. Note that the optimization will never
|
|
actually take effect unless the specified operator is the <quote>less
|
|
than</quote> or <quote>greater than</quote> strategy member of a B-tree
|
|
index operator class.
|
|
</para>
|
|
|
|
<para>
|
|
To be able to create an aggregate function, you must
|
|
have <literal>USAGE</literal> privilege on the argument types, the state
|
|
type, and the return type, as well as <literal>EXECUTE</literal> privilege
|
|
on the transition and final functions.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name (optionally schema-qualified) of the aggregate function
|
|
to create.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">argmode</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The mode of an argument: <literal>IN</> or <literal>VARIADIC</>.
|
|
(Aggregate functions do not support <literal>OUT</> arguments.)
|
|
If omitted, the default is <literal>IN</>. Only the last argument
|
|
can be marked <literal>VARIADIC</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">argname</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The name of an argument. This is currently only useful for
|
|
documentation purposes. If omitted, the argument has no name.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">arg_data_type</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
An input data type on which this aggregate function operates.
|
|
To create a zero-argument aggregate function, write <literal>*</>
|
|
in place of the list of argument specifications. (An example of such an
|
|
aggregate is <function>count(*)</function>.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">base_type</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
In the old syntax for <command>CREATE AGGREGATE</>, the input data type
|
|
is specified by a <literal>basetype</> parameter rather than being
|
|
written next to the aggregate name. Note that this syntax allows
|
|
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>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">sfunc</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name of the state transition function to be called for each
|
|
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
|
|
class="PARAMETER">state_data_type</replaceable> and the rest
|
|
matching the declared input data type(s) of the aggregate.
|
|
The function must return a value of type <replaceable
|
|
class="PARAMETER">state_data_type</replaceable>. This function
|
|
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>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">state_data_type</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The data type for the aggregate's state value.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">state_data_size</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The approximate average size (in bytes) of the aggregate's state value.
|
|
If this parameter is omitted or is zero, a default estimate is used
|
|
based on the <replaceable>state_data_type</>.
|
|
The planner uses this value to estimate the memory required for a
|
|
grouped aggregate query. The planner will consider using hash
|
|
aggregation for such a query only if the hash table is estimated to fit
|
|
in <xref linkend="guc-work-mem">; therefore, large values of this
|
|
parameter discourage use of hash aggregation.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">ffunc</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name of the final function called to compute the aggregate's
|
|
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
|
|
function. If <replaceable class="PARAMETER">ffunc</replaceable>
|
|
is not specified, then the ending state value is used as the
|
|
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>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">initial_condition</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The initial setting for the state value. This must be a string
|
|
constant in the form accepted for the data type <replaceable
|
|
class="PARAMETER">state_data_type</replaceable>. If not
|
|
specified, the state value starts out null.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">sort_operator</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The associated sort operator for a <function>MIN</>- or
|
|
<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 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>
|
|
</variablelist>
|
|
|
|
<para>
|
|
The parameters of <command>CREATE AGGREGATE</command> can be
|
|
written in any order, not just the order illustrated above.
|
|
</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>
|
|
|
|
<para>
|
|
See <xref linkend="xaggr">.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
<command>CREATE AGGREGATE</command> is a
|
|
<productname>PostgreSQL</productname> language extension. The SQL
|
|
standard does not provide for user-defined aggregate functions.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>See Also</title>
|
|
|
|
<simplelist type="inline">
|
|
<member><xref linkend="sql-alteraggregate"></member>
|
|
<member><xref linkend="sql-dropaggregate"></member>
|
|
</simplelist>
|
|
</refsect1>
|
|
</refentry>
|