1 <!-- doc/src/sgml/xaggr.sgml -->
4 <title>User-Defined Aggregates
</title>
6 <indexterm zone=
"xaggr">
7 <primary>aggregate function
</primary>
8 <secondary>user-defined
</secondary>
12 Aggregate functions in
<productname>PostgreSQL
</productname>
13 are defined in terms of
<firstterm>state values
</firstterm>
14 and
<firstterm>state transition functions
</firstterm>.
15 That is, an aggregate operates using a state value that is updated
16 as each successive input row is processed.
17 To define a new aggregate
18 function, one selects a data type for the state value,
19 an initial value for the state, and a state transition
20 function. The state transition function takes the previous state
21 value and the aggregate's input value(s) for the current row, and
22 returns a new state value.
23 A
<firstterm>final function
</firstterm>
24 can also be specified, in case the desired result of the aggregate
25 is different from the data that needs to be kept in the running
26 state value. The final function takes the ending state value
27 and returns whatever is wanted as the aggregate result.
28 In principle, the transition and final functions are just ordinary
29 functions that could also be used outside the context of the
30 aggregate. (In practice, it's often helpful for performance reasons
31 to create specialized transition functions that can only work when
32 called as part of an aggregate.)
36 Thus, in addition to the argument and result data types seen by a user
37 of the aggregate, there is an internal state-value data type that
38 might be different from both the argument and result types.
42 If we define an aggregate that does not use a final function,
43 we have an aggregate that computes a running function of
44 the column values from each row.
<function>sum
</function> is an
45 example of this kind of aggregate.
<function>sum
</function> starts at
46 zero and always adds the current row's value to
47 its running total. For example, if we want to make a
<function>sum
</function>
48 aggregate to work on a data type for complex numbers,
49 we only need the addition function for that data type.
50 The aggregate definition would be:
53 CREATE AGGREGATE sum (complex)
61 which we might use like this:
64 SELECT sum(a) FROM test_complex;
71 (Notice that we are relying on function overloading: there is more than
72 one aggregate named
<function>sum
</function>, but
73 <productname>PostgreSQL
</productname> can figure out which kind
74 of sum applies to a column of type
<type>complex
</type>.)
78 The above definition of
<function>sum
</function> will return zero
79 (the initial state value) if there are no nonnull input values.
80 Perhaps we want to return null in that case instead
— the SQL standard
81 expects
<function>sum
</function> to behave that way. We can do this simply by
82 omitting the
<literal>initcond
</literal> phrase, so that the initial state
83 value is null. Ordinarily this would mean that the
<literal>sfunc
</literal>
84 would need to check for a null state-value input. But for
85 <function>sum
</function> and some other simple aggregates like
86 <function>max
</function> and
<function>min
</function>,
87 it is sufficient to insert the first nonnull input value into
88 the state variable and then start applying the transition function
89 at the second nonnull input value.
<productname>PostgreSQL
</productname>
90 will do that automatically if the initial state value is null and
91 the transition function is marked
<quote>strict
</quote> (i.e., not to be called
96 Another bit of default behavior for a
<quote>strict
</quote> transition function
97 is that the previous state value is retained unchanged whenever a
98 null input value is encountered. Thus, null values are ignored. If you
99 need some other behavior for null inputs, do not declare your
100 transition function as strict; instead code it to test for null inputs and
101 do whatever is needed.
105 <function>avg
</function> (average) is a more complex example of an aggregate.
107 two pieces of running state: the sum of the inputs and the count
108 of the number of inputs. The final result is obtained by dividing
109 these quantities. Average is typically implemented by using an
110 array as the state value. For example,
111 the built-in implementation of
<function>avg(float8)
</function>
115 CREATE AGGREGATE avg (float8)
117 sfunc = float8_accum,
119 finalfunc = float8_avg,
127 <function>float8_accum
</function> requires a three-element array, not just
128 two elements, because it accumulates the sum of squares as well as
129 the sum and count of the inputs. This is so that it can be used for
130 some other aggregates as well as
<function>avg
</function>.
135 Aggregate function calls in SQL allow
<literal>DISTINCT
</literal>
136 and
<literal>ORDER BY
</literal> options that control which rows are fed
137 to the aggregate's transition function and in what order. These
138 options are implemented behind the scenes and are not the concern
139 of the aggregate's support functions.
143 For further details see the
144 <xref linkend=
"sql-createaggregate"/>
148 <sect2 id=
"xaggr-moving-aggregates">
149 <title>Moving-Aggregate Mode
</title>
152 <primary>moving-aggregate mode
</primary>
156 <primary>aggregate function
</primary>
157 <secondary>moving aggregate
</secondary>
161 Aggregate functions can optionally support
<firstterm>moving-aggregate
162 mode
</firstterm>, which allows substantially faster execution of aggregate
163 functions within windows with moving frame starting points.
164 (See
<xref linkend=
"tutorial-window"/>
165 and
<xref linkend=
"syntax-window-functions"/> for information about use of
166 aggregate functions as window functions.)
167 The basic idea is that in addition to a normal
<quote>forward
</quote>
168 transition function, the aggregate provides an
<firstterm>inverse
169 transition function
</firstterm>, which allows rows to be removed from the
170 aggregate's running state value when they exit the window frame.
171 For example a
<function>sum
</function> aggregate, which uses addition as the
172 forward transition function, would use subtraction as the inverse
173 transition function. Without an inverse transition function, the window
174 function mechanism must recalculate the aggregate from scratch each time
175 the frame starting point moves, resulting in run time proportional to the
176 number of input rows times the average frame length. With an inverse
177 transition function, the run time is only proportional to the number of
182 The inverse transition function is passed the current state value and the
183 aggregate input value(s) for the earliest row included in the current
184 state. It must reconstruct what the state value would have been if the
185 given input row had never been aggregated, but only the rows following
186 it. This sometimes requires that the forward transition function keep
187 more state than is needed for plain aggregation mode. Therefore, the
188 moving-aggregate mode uses a completely separate implementation from the
189 plain mode: it has its own state data type, its own forward transition
190 function, and its own final function if needed. These can be the same as
191 the plain mode's data type and functions, if there is no need for extra
196 As an example, we could extend the
<function>sum
</function> aggregate given above
197 to support moving-aggregate mode like this:
200 CREATE AGGREGATE sum (complex)
205 msfunc = complex_add,
206 minvfunc = complex_sub,
212 The parameters whose names begin with
<literal>m
</literal> define the
213 moving-aggregate implementation. Except for the inverse transition
214 function
<literal>minvfunc
</literal>, they correspond to the plain-aggregate
215 parameters without
<literal>m
</literal>.
219 The forward transition function for moving-aggregate mode is not allowed
220 to return null as the new state value. If the inverse transition
221 function returns null, this is taken as an indication that the inverse
222 function cannot reverse the state calculation for this particular input,
223 and so the aggregate calculation will be redone from scratch for the
224 current frame starting position. This convention allows moving-aggregate
225 mode to be used in situations where there are some infrequent cases that
226 are impractical to reverse out of the running state value. The inverse
227 transition function can
<quote>punt
</quote> on these cases, and yet still come
228 out ahead so long as it can work for most cases. As an example, an
229 aggregate working with floating-point numbers might choose to punt when
230 a
<literal>NaN
</literal> (not a number) input has to be removed from the running
235 When writing moving-aggregate support functions, it is important to be
236 sure that the inverse transition function can reconstruct the correct
237 state value exactly. Otherwise there might be user-visible differences
238 in results depending on whether the moving-aggregate mode is used.
239 An example of an aggregate for which adding an inverse transition
240 function seems easy at first, yet where this requirement cannot be met
241 is
<function>sum
</function> over
<type>float4
</type> or
<type>float8
</type> inputs. A
242 naive declaration of
<function>sum(
<type>float8
</type>)
</function> could be
245 CREATE AGGREGATE unsafe_sum (float8)
255 This aggregate, however, can give wildly different results than it would
256 have without the inverse transition function. For example, consider
260 unsafe_sum(x) OVER (ORDER BY n ROWS BETWEEN CURRENT ROW AND
1 FOLLOWING)
261 FROM (VALUES (
1,
1.0e20::float8),
262 (
2,
1.0::float8)) AS v (n,x);
265 This query returns
<literal>0</literal> as its second result, rather than the
266 expected answer of
<literal>1</literal>. The cause is the limited precision of
267 floating-point values: adding
<literal>1</literal> to
<literal>1e20
</literal> results
268 in
<literal>1e20
</literal> again, and so subtracting
<literal>1e20
</literal> from that
269 yields
<literal>0</literal>, not
<literal>1</literal>. Note that this is a limitation
270 of floating-point arithmetic in general, not a limitation
271 of
<productname>PostgreSQL
</productname>.
276 <sect2 id=
"xaggr-polymorphic-aggregates">
277 <title>Polymorphic and Variadic Aggregates
</title>
280 <primary>aggregate function
</primary>
281 <secondary>polymorphic
</secondary>
285 <primary>aggregate function
</primary>
286 <secondary>variadic
</secondary>
290 Aggregate functions can use polymorphic
291 state transition functions or final functions, so that the same functions
292 can be used to implement multiple aggregates.
293 See
<xref linkend=
"extend-types-polymorphic"/>
294 for an explanation of polymorphic functions.
295 Going a step further, the aggregate function itself can be specified
296 with polymorphic input type(s) and state type, allowing a single
297 aggregate definition to serve for multiple input data types.
298 Here is an example of a polymorphic aggregate:
301 CREATE AGGREGATE array_accum (anycompatible)
303 sfunc = array_append,
304 stype = anycompatiblearray,
309 Here, the actual state type for any given aggregate call is the array type
310 having the actual input type as elements. The behavior of the aggregate
311 is to concatenate all the inputs into an array of that type.
312 (Note: the built-in aggregate
<function>array_agg
</function> provides similar
313 functionality, with better performance than this definition would have.)
317 Here's the output using two different actual data types as arguments:
320 SELECT attrelid::regclass, array_accum(attname)
322 WHERE attnum
> 0 AND attrelid = 'pg_tablespace'::regclass
325 attrelid | array_accum
326 ---------------+---------------------------------------
327 pg_tablespace | {spcname,spcowner,spcacl,spcoptions}
330 SELECT attrelid::regclass, array_accum(atttypid::regtype)
332 WHERE attnum
> 0 AND attrelid = 'pg_tablespace'::regclass
335 attrelid | array_accum
336 ---------------+---------------------------
337 pg_tablespace | {name,oid,aclitem[],text[]}
343 Ordinarily, an aggregate function with a polymorphic result type has a
344 polymorphic state type, as in the above example. This is necessary
345 because otherwise the final function cannot be declared sensibly: it
346 would need to have a polymorphic result type but no polymorphic argument
347 type, which
<command>CREATE FUNCTION
</command> will reject on the grounds that
348 the result type cannot be deduced from a call. But sometimes it is
349 inconvenient to use a polymorphic state type. The most common case is
350 where the aggregate support functions are to be written in C and the
351 state type should be declared as
<type>internal
</type> because there is
352 no SQL-level equivalent for it. To address this case, it is possible to
353 declare the final function as taking extra
<quote>dummy
</quote> arguments
354 that match the input arguments of the aggregate. Such dummy arguments
355 are always passed as null values since no specific value is available when the
356 final function is called. Their only use is to allow a polymorphic
357 final function's result type to be connected to the aggregate's input
358 type(s). For example, the definition of the built-in
359 aggregate
<function>array_agg
</function> is equivalent to
362 CREATE FUNCTION array_agg_transfn(internal, anynonarray)
363 RETURNS internal ...;
364 CREATE FUNCTION array_agg_finalfn(internal, anynonarray)
365 RETURNS anyarray ...;
367 CREATE AGGREGATE array_agg (anynonarray)
369 sfunc = array_agg_transfn,
371 finalfunc = array_agg_finalfn,
376 Here, the
<literal>finalfunc_extra
</literal> option specifies that the final
377 function receives, in addition to the state value, extra dummy
378 argument(s) corresponding to the aggregate's input argument(s).
379 The extra
<type>anynonarray
</type> argument allows the declaration
380 of
<function>array_agg_finalfn
</function> to be valid.
384 An aggregate function can be made to accept a varying number of arguments
385 by declaring its last argument as a
<literal>VARIADIC
</literal> array, in much
386 the same fashion as for regular functions; see
387 <xref linkend=
"xfunc-sql-variadic-functions"/>. The aggregate's transition
388 function(s) must have the same array type as their last argument. The
389 transition function(s) typically would also be marked
<literal>VARIADIC
</literal>,
390 but this is not strictly required.
395 Variadic aggregates are easily misused in connection with
396 the
<literal>ORDER BY
</literal> option (see
<xref linkend=
"syntax-aggregates"/>),
397 since the parser cannot tell whether the wrong number of actual arguments
398 have been given in such a combination. Keep in mind that everything to
399 the right of
<literal>ORDER BY
</literal> is a sort key, not an argument to the
400 aggregate. For example, in
402 SELECT myaggregate(a ORDER BY a, b, c) FROM ...
404 the parser will see this as a single aggregate function argument and
405 three sort keys. However, the user might have intended
407 SELECT myaggregate(a, b, c ORDER BY a) FROM ...
409 If
<literal>myaggregate
</literal> is variadic, both these calls could be
414 For the same reason, it's wise to think twice before creating aggregate
415 functions with the same names and different numbers of regular arguments.
421 <sect2 id=
"xaggr-ordered-set-aggregates">
422 <title>Ordered-Set Aggregates
</title>
425 <primary>aggregate function
</primary>
426 <secondary>ordered set
</secondary>
430 The aggregates we have been describing so far are
<quote>normal
</quote>
431 aggregates.
<productname>PostgreSQL
</productname> also
432 supports
<firstterm>ordered-set aggregates
</firstterm>, which differ from
433 normal aggregates in two key ways. First, in addition to ordinary
434 aggregated arguments that are evaluated once per input row, an
435 ordered-set aggregate can have
<quote>direct
</quote> arguments that are
436 evaluated only once per aggregation operation. Second, the syntax
437 for the ordinary aggregated arguments specifies a sort ordering
438 for them explicitly. An ordered-set aggregate is usually
439 used to implement a computation that depends on a specific row
440 ordering, for instance rank or percentile, so that the sort ordering
441 is a required aspect of any call. For example, the built-in
442 definition of
<function>percentile_disc
</function> is equivalent to:
445 CREATE FUNCTION ordered_set_transition(internal, anyelement)
446 RETURNS internal ...;
447 CREATE FUNCTION percentile_disc_final(internal, float8, anyelement)
448 RETURNS anyelement ...;
450 CREATE AGGREGATE percentile_disc (float8 ORDER BY anyelement)
452 sfunc = ordered_set_transition,
454 finalfunc = percentile_disc_final,
459 This aggregate takes a
<type>float8
</type> direct argument (the percentile
460 fraction) and an aggregated input that can be of any sortable data type.
461 It could be used to obtain a median household income like this:
464 SELECT percentile_disc(
0.5) WITHIN GROUP (ORDER BY income) FROM households;
470 Here,
<literal>0.5</literal> is a direct argument; it would make no sense
471 for the percentile fraction to be a value varying across rows.
475 Unlike the case for normal aggregates, the sorting of input rows for
476 an ordered-set aggregate is
<emphasis>not
</emphasis> done behind the scenes,
477 but is the responsibility of the aggregate's support functions.
478 The typical implementation approach is to keep a reference to
479 a
<quote>tuplesort
</quote> object in the aggregate's state value, feed the
480 incoming rows into that object, and then complete the sorting and
481 read out the data in the final function. This design allows the
482 final function to perform special operations such as injecting
483 additional
<quote>hypothetical
</quote> rows into the data to be sorted.
484 While normal aggregates can often be implemented with support
485 functions written in
<application>PL/pgSQL
</application> or another
486 PL language, ordered-set aggregates generally have to be written in
487 C, since their state values aren't definable as any SQL data type.
488 (In the above example, notice that the state value is declared as
489 type
<type>internal
</type> — this is typical.)
490 Also, because the final function performs the sort, it is not possible
491 to continue adding input rows by executing the transition function again
492 later. This means the final function is not
<literal>READ_ONLY
</literal>;
493 it must be declared in
<link linkend=
"sql-createaggregate"><command>CREATE AGGREGATE
</command></link>
494 as
<literal>READ_WRITE
</literal>, or as
<literal>SHAREABLE
</literal> if
495 it's possible for additional final-function calls to make use of the
496 already-sorted state.
500 The state transition function for an ordered-set aggregate receives
501 the current state value plus the aggregated input values for
502 each row, and returns the updated state value. This is the
503 same definition as for normal aggregates, but note that the direct
504 arguments (if any) are not provided. The final function receives
505 the last state value, the values of the direct arguments if any,
506 and (if
<literal>finalfunc_extra
</literal> is specified) null values
507 corresponding to the aggregated input(s). As with normal
508 aggregates,
<literal>finalfunc_extra
</literal> is only really useful if the
509 aggregate is polymorphic; then the extra dummy argument(s) are needed
510 to connect the final function's result type to the aggregate's input
515 Currently, ordered-set aggregates cannot be used as window functions,
516 and therefore there is no need for them to support moving-aggregate mode.
521 <sect2 id=
"xaggr-partial-aggregates">
522 <title>Partial Aggregation
</title>
525 <primary>aggregate function
</primary>
526 <secondary>partial aggregation
</secondary>
530 Optionally, an aggregate function can support
<firstterm>partial
531 aggregation
</firstterm>. The idea of partial aggregation is to run the aggregate's
532 state transition function over different subsets of the input data
533 independently, and then to combine the state values resulting from those
534 subsets to produce the same state value that would have resulted from
535 scanning all the input in a single operation. This mode can be used for
536 parallel aggregation by having different worker processes scan different
537 portions of a table. Each worker produces a partial state value, and at
538 the end those state values are combined to produce a final state value.
539 (In the future this mode might also be used for purposes such as combining
540 aggregations over local and remote tables; but that is not implemented
545 To support partial aggregation, the aggregate definition must provide
546 a
<firstterm>combine function
</firstterm>, which takes two values of the
547 aggregate's state type (representing the results of aggregating over two
548 subsets of the input rows) and produces a new value of the state type,
549 representing what the state would have been after aggregating over the
550 combination of those sets of rows. It is unspecified what the relative
551 order of the input rows from the two sets would have been. This means
552 that it's usually impossible to define a useful combine function for
553 aggregates that are sensitive to input row order.
557 As simple examples,
<literal>MAX
</literal> and
<literal>MIN
</literal> aggregates can be
558 made to support partial aggregation by specifying the combine function as
559 the same greater-of-two or lesser-of-two comparison function that is used
560 as their transition function.
<literal>SUM
</literal> aggregates just need an
561 addition function as combine function. (Again, this is the same as their
562 transition function, unless the state value is wider than the input data
567 The combine function is treated much like a transition function that
568 happens to take a value of the state type, not of the underlying input
569 type, as its second argument. In particular, the rules for dealing
570 with null values and strict functions are similar. Also, if the aggregate
571 definition specifies a non-null
<literal>initcond
</literal>, keep in mind that
572 that will be used not only as the initial state for each partial
573 aggregation run, but also as the initial state for the combine function,
574 which will be called to combine each partial result into that state.
578 If the aggregate's state type is declared as
<type>internal
</type>, it is
579 the combine function's responsibility that its result is allocated in
580 the correct memory context for aggregate state values. This means in
581 particular that when the first input is
<literal>NULL
</literal> it's invalid
582 to simply return the second input, as that value will be in the wrong
583 context and will not have sufficient lifespan.
587 When the aggregate's state type is declared as
<type>internal
</type>, it is
588 usually also appropriate for the aggregate definition to provide a
589 <firstterm>serialization function
</firstterm> and a
<firstterm>deserialization
590 function
</firstterm>, which allow such a state value to be copied from one process
591 to another. Without these functions, parallel aggregation cannot be
592 performed, and future applications such as local/remote aggregation will
593 probably not work either.
597 A serialization function must take a single argument of
598 type
<type>internal
</type> and return a result of type
<type>bytea
</type>, which
599 represents the state value packaged up into a flat blob of bytes.
600 Conversely, a deserialization function reverses that conversion. It must
601 take two arguments of types
<type>bytea
</type> and
<type>internal
</type>, and
602 return a result of type
<type>internal
</type>. (The second argument is unused
603 and is always zero, but it is required for type-safety reasons.) The
604 result of the deserialization function should simply be allocated in the
605 current memory context, as unlike the combine function's result, it is not
610 Worth noting also is that for an aggregate to be executed in parallel,
611 the aggregate itself must be marked
<literal>PARALLEL SAFE
</literal>. The
612 parallel-safety markings on its support functions are not consulted.
617 <sect2 id=
"xaggr-support-functions">
618 <title>Support Functions for Aggregates
</title>
621 <primary>aggregate function
</primary>
622 <secondary>support functions for
</secondary>
626 A function written in C can detect that it is being called as an
627 aggregate support function by calling
628 <function>AggCheckCallContext
</function>, for example:
630 if (AggCheckCallContext(fcinfo, NULL))
632 One reason for checking this is that when it is true, the first input
633 must be a temporary state value and can therefore safely be modified
634 in-place rather than allocating a new copy.
635 See
<function>int8inc()
</function> for an example.
636 (While aggregate transition functions are always allowed to modify
637 the transition value in-place, aggregate final functions are generally
638 discouraged from doing so; if they do so, the behavior must be declared
639 when creating the aggregate. See
<xref linkend=
"sql-createaggregate"/>
644 The second argument of
<function>AggCheckCallContext
</function> can be used to
645 retrieve the memory context in which aggregate state values are being kept.
646 This is useful for transition functions that wish to use
<quote>expanded
</quote>
647 objects (see
<xref linkend=
"xtypes-toast"/>) as their state values.
648 On first call, the transition function should return an expanded object
649 whose memory context is a child of the aggregate state context, and then
650 keep returning the same expanded object on subsequent calls. See
651 <function>array_append()
</function> for an example. (
<function>array_append()
</function>
652 is not the transition function of any built-in aggregate, but it is written
653 to behave efficiently when used as transition function of a custom
658 Another support routine available to aggregate functions written in C
659 is
<function>AggGetAggref
</function>, which returns the
<literal>Aggref
</literal>
660 parse node that defines the aggregate call. This is mainly useful
661 for ordered-set aggregates, which can inspect the substructure of
662 the
<literal>Aggref
</literal> node to find out what sort ordering they are
663 supposed to implement. Examples can be found
664 in
<filename>orderedsetaggs.c
</filename> in the
<productname>PostgreSQL
</productname>