Postgres-XC 1.2.1 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Chapter 34. Extending SQL | Fast Forward | Next |
Note: XCONLY: The following description applies only to Postgres-XC.
Aggregate functions in Postgres-XC are expressed in terms of state values and state functions namely transition function and collection function. That is, an aggregate operates using 1. a transition state value that is updated as each successive input row, in a given set of rows, is processed, and 2. (optionally) collection state value that is updated as each successive transition state value is processed. To define a new aggregate function, one selects a data type for the state value, an initial value for the transition 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 collection function and an initial value for the collection state can also be specified, if one wants to take advantage of distributed aggregation. Similar to transition function, a collection function can be an ordinary function that could also be used outside the context of the aggregate. A final function 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 (either collection or transition) value.
Note: The following description applies both to Postgres-XC and PostgreSQL if not described explicitly. You can read PostgreSQL as Postgres-XC except for version number, which is specific to each product.
Thus, in addition to the argument and result data types seen by a user of the aggregate, there is an internal state-value data type that might be different from both the argument and result types.
If we define an aggregate that does not use a final function,
we have an aggregate that computes a running function of
the column values from each row. sum
is an
example of this kind of aggregate. sum
starts at
zero and always adds the current row's value to
its running total. For example, if we want to make a sum
aggregate to work on a data type for complex numbers,
we only need the addition function for that data type.
The aggregate definition would be:
CREATE AGGREGATE sum (complex) ( sfunc = complex_add, stype = complex, initcond = '(0,0)' ); SELECT sum(a) FROM test_complex; sum ----------- (34,53.9)
(Notice that we are relying on function overloading: there is more than
one aggregate named sum
, but
PostgreSQL can figure out which kind
of sum applies to a column of type complex.)
Note: XCONLY: The following description applies only to Postgres-XC.
In Postgres-XC, a user can provide collection
function if distributed aggregation is expected for improving performance. The
collection function essentially combines the state transition results produced
at different Datanodes. Without a final function the result produced by the
collection function is the result of aggregate. Above definition of aggregate
sum
for complex number data type can be modified to have a
collection function as follows
CREATE AGGREGATE sum (complex) ( sfunc = complex_add, stype = complex, cfunc = complex_add, initcond = '(0,0)' initcollect = '(0.0)' ); SELECT sum(a) FROM test_complex; sum ----------- (34,53.9)
Notice that both the CREATE AGGREGATE commands work in Postgres-XC. Aggregate created by either command produces the same results.
Note: XCONLY: The following description applies only to Postgres-XC.
The above definitions of sum
will return zero (the initial
state condition) if there are no nonnull input values.
Perhaps we want to return null in that case instead — the SQL standard
expects sum
to behave that way. We can do this simply by
omitting the initcond phrase, so that the initial state
condition is null. Ordinarily this would mean that the sfunc
would need to check for a null state-condition input, but for
sum
and some other simple aggregates like
max
and 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. Postgres-XC
will do that automatically if the initial condition is null and
the transition function is marked "strict" (i.e., not to be called
for null inputs).
Note: XCONLY: The following description applies only to Postgres-XC.
Another bit of default behavior for a "strict" transition/collection function is that the previous state value is retained unchanged whenever a null input value is encountered. Thus, null values are ignored. If you need some other behavior for null inputs, do not declare your transition/collection function as strict; instead code it to test for null inputs and do whatever is needed.
Note: XCONLY: The following description applies only to Postgres-XC.
avg
(average) is a more complex example of an aggregate.
It requires
two pieces of running state: the sum of the inputs and the count
of the number of inputs. The final result is obtained by dividing
these quantities. Average is typically implemented by using an
array as the state value. For example,
the built-in implementation of avg(float8)
looks like:
CREATE AGGREGATE avg (float8) ( sfunc = float8_accum, stype = float8[], cfunc = float8_collect, finalfunc = float8_avg, initcond = '{0,0}' initcollect = '{0,0,0}' );
(float8_accum
and float8_collect
require 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 avg
.)
Note: XCONLY: The following description applies only to Postgres-XC.
Aggregate functions can use polymorphic state transition/collection functions or final functions, so that the same functions can be used to implement multiple aggregates. See Section 34.2.5 for an explanation of polymorphic functions. Going a step further, the aggregate function itself can be specified with polymorphic input type(s) and state type, allowing a single aggregate definition to serve for multiple input data types. Here is an example of a polymorphic aggregate:
CREATE AGGREGATE array_accum (anyelement) ( sfunc = array_append, stype = anyarray, initcond = '{}' );
Here, the actual state type for any 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 array_agg
provides similar
functionality, with better performance than this definition would have.)
Note: The following description applies both to Postgres-XC and PostgreSQL if not described explicitly. You can read PostgreSQL as Postgres-XC except for version number, which is specific to each product.
Here's the output using two different actual data types as arguments:
SELECT attrelid::regclass, array_accum(attname) FROM pg_attribute WHERE attnum > 0 AND attrelid = 'pg_tablespace'::regclass GROUP BY attrelid; attrelid | array_accum ---------------+--------------------------------------- pg_tablespace | {spcname,spcowner,spcacl,spcoptions} (1 row) SELECT attrelid::regclass, array_accum(atttypid::regtype) FROM pg_attribute WHERE attnum > 0 AND attrelid = 'pg_tablespace'::regclass GROUP BY attrelid; attrelid | array_accum ---------------+--------------------------- pg_tablespace | {name,oid,aclitem[],text[]} (1 row)
Note: XCONLY: The following description applies only to Postgres-XC.
A function written in C can detect that it is being called as an
aggregate transition or final function by calling
AggCheckCallContext
, for example:
if (AggCheckCallContext(fcinfo, NULL))
One reason for checking this is that when it is true for a transition function, the first input to transition or collection function must be a temporary transition/collection value and can therefore safely be modified in-place rather than allocating a new copy. See int8inc() for an example. (This is the 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.)
For further details see the CREATE AGGREGATE command.