Defines a new aggregate function.
CREATE [ OR REPLACE ] AGGREGATE <name> ( [ <argmode> ] [ <argname> ] <arg_data_type> [ , ... ] ) (
SFUNC = <sfunc>,
STYPE = <state_data_type>
[ , SSPACE = <state_data_size> ]
[ , FINALFUNC = <ffunc> ]
[ , FINALFUNC_EXTRA ]
[ , FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
[ , COMBINEFUNC = <combinefunc> ]
[ , SERIALFUNC = <serialfunc> ]
[ , DESERIALFUNC = <deserialfunc> ]
[ , INITCOND = <initial_condition> ]
[ , MSFUNC = <msfunc> ]
[ , MINVFUNC = <minvfunc> ]
[ , MSTYPE = <mstate_data_type> ]
[ , MSSPACE = <mstate_data_size> ]
[ , MFINALFUNC = <mffunc> ]
[ , MFINALFUNC_EXTRA ]
[ , MFINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
[ , MINITCOND = <minitial_condition> ]
[ , SORTOP = <sort_operator> ]
[ , PARALLEL = { SAFE | RESTRICTED | UNSAFE } ]
[ , REPSAFE = <boolean> ]
)
CREATE [ OR REPLACE ] AGGREGATE <name> ( [ [ <argmode> ] [ <argname> ] <arg_data_type> [ , ... ] ]
ORDER BY [ <argmode> ] [ <argname> ] <arg_data_type> [ , ... ] ) (
SFUNC = <sfunc>,
STYPE = <state_data_type>
[ , SSPACE = <state_data_size> ]
[ , FINALFUNC = <ffunc> ]
[ , FINALFUNC_EXTRA ]
[ , FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
[ , COMBINEFUNC = <combinefunc> ]
[ , INITCOND = <initial_condition> ]
[ , PARALLEL = { SAFE | RESTRICTED | UNSAFE } ]
[ , REPSAFE = <boolean> ]
[ , HYPOTHETICAL ]
)
or the old syntax
CREATE [ OR REPLACE ] AGGREGATE <name> (
BASETYPE = <base_type>,
SFUNC = <sfunc>,
STYPE = <state_data_type>
[ , SSPACE = <state_data_size> ]
[ , FINALFUNC = <ffunc> ]
[ , FINALFUNC_EXTRA ]
[ , FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
[ , COMBINEFUNC = <combinefunc> ]
[ , SERIALFUNC = <serialfunc> ]
[ , DESERIALFUNC = <deserialfunc> ]
[ , INITCOND = <initial_condition> ]
[ , MSFUNC = <msfunc> ]
[ , MINVFUNC = <minvfunc> ]
[ , MSTYPE = <mstate_data_type> ]
[ , MSSPACE = <mstate_data_size> ]
[ , MFINALFUNC = <mffunc> ]
[ , MFINALFUNC_EXTRA ]
[ , MFINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
[ , MINITCOND = <minitial_condition> ]
[ , SORTOP = <sort_operator> ]
[ , REPSAFE = <boolean> ]
)
CREATE AGGREGATE defines a new aggregate function. CREATE OR REPLACE AGGREGATE will either define a new aggregate function or replace an existing definition. Some basic and commonly-used aggregate functions such as count(), min(), max(), sum(), avg() and so on are already provided in Database. If you define new types or need an aggregate function not already provided, you can use CREATE AGGREGATE to provide the desired features.
When replacing an existing definition, the argument types, result type, and number of direct arguments may not be changed. Also, the new definition must be of the same kind (ordinary aggregate, ordered-set aggregate, or hypothetical-set aggregate) as the old one.
If a schema name is given (for example, CREATE AGGREGATE myschema.myagg ...) then the aggregate function is created in the specified schema. Otherwise it is created in the current schema.
An aggregate function is identified by its name and input data type(s). Two aggregate functions 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 function 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 CREATE FUNCTION.
A simple aggregate function is made from one or two ordinary functions; a state transition function sfunc, and an optional final calculation function ffunc.
These functions are used as follows:
sfunc( internal-state, next-data-values ) ---> next-internal-state
ffunc( internal-state ) ---> aggregate-value
Database creates a temporary variable of data type state_data_type to hold the current internal state of the aggregate function. 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.
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 text, 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.
If the state transition function is declared STRICT, 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 non-null input values, the first argument value replaces the state value, and the transition function is invoked at subsequent rows with all non-null input values. This is useful for implementing aggregates like max(). Note that this behavior is only available when state_data_type is the same as the first arg_data_type. When these types are different, you must supply a non-null initial condition or use a nonstrict transition function.
If the state transition function is not declared 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.
If the final function is declared STRICT, then it will not be called when the ending state value is null; instead a null result will be returned automatically. (This is 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 avg() returns null when it sees there were zero input rows.
Sometimes it is useful to declare the final function as taking not just the state value, but extra parameters corresponding to the aggregate's input values. The main reason for doing this is if the final function is polymorphic and the state value's data type would be inadequate to pin down the result type. These extra parameters are always passed as NULL (and so the final function must not be strict when the FINALFUNC_EXTRA option is used), but nonetheless they are valid parameters. The final function could for example make use of get_fn_expr_argtype to identify the actual argument type in the current call.
An aggregate can optionally support moving-aggregate mode, as described in Moving-Aggregate Mode in the PostgreSQL documentation. This requires specifying the MSFUNC, MINVFUNC, and MSTYPE functions, and optionally the MSSPACE, MFINALFUNC, MFINALFUNC_EXTRA, MFINALFUNC_MODIFY, and MINITCOND functions. Except for MINVFUNC, these functions work like the corresponding simple-aggregate functions without M; they define a separate implementation of the aggregate that includes an inverse transition function.
The syntax with ORDER BY in the parameter list creates a special type of aggregate called an ordered-set aggregate; or if HYPOTHETICAL is specified, then a hypothetical-set aggregate 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 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 data types, 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 "hypothetical" row.
An aggregate can optionally support partial aggregation. This requires specifying the COMBINEFUNC parameter. If the state_data_type is internal, it's usually also appropriate to provide the SERIALFUNC and DESERIALFUNC parameters so that parallel aggregation is possible. Note that the aggregate must also be marked PARALLEL SAFE to enable parallel aggregation.
Aggregates that behave like min() or 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 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:
SELECT agg(col) FROM tab;
must be equivalent to:
SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
Further assumptions are that the aggregate function 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 < operator is the proper sort operator for min(), and > is the proper sort operator for max(). Note that the optimization will never actually take effect unless the specified operator is the "less than" or "greater than" strategy member of a B-tree index operator class.
To be able to create an aggregate function, you must have USAGE privilege on the argument types, the state type(s), and the return type, as well as EXECUTE privilege on the supporting functions.
You can specify combinefunc as a method for optimizing aggregate execution. By specifying combinefunc, the aggregate can be run in parallel on segments first and then on the coordinator. When a two-level execution is performed, the sfunc is run on the segments to generate partial aggregate results, and combinefunc is run on the coordinator to aggregate the partial results from segments. If single-level aggregation is performed, all the rows are sent to the coordinator and the sfunc is applied to the rows.
Single-level aggregation and two-level aggregation are equivalent execution strategies. Either type of aggregation can be implemented in a query plan. When you implement the functions combinefunc and sfunc, you must ensure that the invocation of the sfunc on the segment instances followed by combinefunc on the coordinator produce the same result as single-level aggregation that sends all the rows to the coordinator and then applies only the sfunc to the rows.
name
argmode
argname
arg_data_type
base_type
sfunc
state_data_type
state_data_size
ffunc
The name of the final function called to compute the aggregate result after all input rows have been traversed. The function must take a single argument of type state_data_type. The return data type of the aggregate is defined as the return type of this function. If ffunc is not specified, then the ending state value is used as the aggregate result, and the return type is state_data_type.
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.
If FINALFUNC_EXTRA is specified, then in addition to the final state value and any direct arguments, the final function receives extra NULL values corresponding to the aggregate's regular (aggregated) arguments. This is mainly useful to allow correct resolution of the aggregate result type when a polymorphic aggregate is being defined.
FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE }
combinefunc
serialfunc
deserialfunc
initial_condition
msfunc
minvfunc
mstate_data_type
mstate_data_size
mffunc
MFINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE }
minitial_condition
sort_operator
PARALLEL = { SAFE | RESTRICTED | UNSAFE }
REPSAFE = boolean
REPSAFE = true
instructs the optimizer to perform additional optimizations that specifically suppress certain broadcast motions.Caution!
Incorrectly settingREPSAFE = true
for an order-dependent aggregate may produce incorrect results.
The ordinary functions used to define a new aggregate function must be defined first.
If the value of the Database server configuration parameter gp_enable_multiphase_agg is off, only single-level aggregation is performed by the Postgres-based planner. There is no equivalent parameter for GPORCA.
Any compiled code (shared library files) for custom functions must be placed in the same location on every host in your Database array (coordinator and all segments). This location must also be in the LD_LIBRARY_PATH so that the server can locate the files.
In previous versions of Database, there was a concept of ordered aggregates. Since version 6, any aggregate can be called as an ordered aggregate, using the syntax:
name ( arg [ , ... ] [ORDER BY sortspec [ , ...]] )
The ORDERED keyword is accepted for backwards compatibility, but is ignored.
In previous versions of Database, the COMBINEFUNC option was called PREFUNC. It is still accepted for backwards compatibility, as a synonym for COMBINEFUNC.
The following simple example creates an aggregate function that computes the sum of two columns.
Before creating the aggregate function, create two functions that are used as the sfunc and combinefunc functions of the aggregate function.
This function is specified as the sfunc function in the aggregate function.
CREATE FUNCTION mysfunc_accum(numeric, numeric, numeric)
RETURNS numeric
AS 'select $1 + $2 + $3'
LANGUAGE SQL
RETURNS NULL ON NULL INPUT;
This function is specified as the combinefunc function in the aggregate function.
CREATE FUNCTION mycombine_accum(numeric, numeric )
RETURNS numeric
AS 'select $1 + $2'
LANGUAGE SQL
RETURNS NULL ON NULL INPUT;
This CREATE AGGREGATE command creates the aggregate function that adds two columns.
CREATE AGGREGATE agg_twocols(numeric, numeric) (
SFUNC = mysfunc_accum,
STYPE = numeric,
COMBINEFUNC = mycombine_accum,
INITCOND = 0 );
The following commands create a table, adds some rows, and runs the aggregate function.
CREATE TABLE t1 (a int, b int) DISTRIBUTED BY (a);
INSERT INTO t1 VALUES
(10, 1),
(20, 2),
(30, 3);
SELECT agg_twocols(a, b) FROM t1;
Refer to User-Defined Aggregates in the PostgreSQL documentation for more examples of creating aggregates.
CREATE AGGREGATE is a Database language extension. The SQL standard does not provide for user-defined aggregate functions.