1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
|
<!-- doc/src/sgml/xaggr.sgml -->
<sect1 id="xaggr">
<title>User-defined Aggregates</title>
<indexterm zone="xaggr">
<primary>aggregate function</primary>
<secondary>user-defined</secondary>
</indexterm>
<para>
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 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. 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>
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.
</para>
<para>
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. <function>sum</> is an
example of this kind of aggregate. <function>sum</> starts at
zero and always adds the current row's value to
its running total. For example, if we want to make a <function>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:
<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)
</programlisting>
(Notice that we are relying on function overloading: there is more than
one aggregate named <function>sum</>, but
<productname>PostgreSQL</productname> can figure out which kind
of sum applies to a column of type <type>complex</type>.)
</para>
<para>
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 — 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
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 state value is null and
the transition function is marked <quote>strict</> (i.e., not to be called
for null inputs).
</para>
<para>
Another bit of default behavior for a <quote>strict</> transition 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 function as strict; instead code it to test for null inputs and
do whatever is needed.
</para>
<para>
<function>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 <function>avg(float8)</function>
looks like:
<programlisting>
CREATE AGGREGATE avg (float8)
(
sfunc = float8_accum,
stype = float8[],
finalfunc = float8_avg,
initcond = '{0,0,0}'
);
</programlisting>
</para>
<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>
</note>
<para>
Aggregate functions can use polymorphic
state transition functions or final functions, so that the same functions
can be used to implement multiple aggregates.
See <xref linkend="extend-types-polymorphic">
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:
<programlisting>
CREATE AGGREGATE array_accum (anyelement)
(
sfunc = array_append,
stype = anyarray,
initcond = '{}'
);
</programlisting>
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
functionality, with better performance than this definition would have.)
</para>
<para>
Here's the output using two different actual data types as arguments:
<programlisting>
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)
</programlisting>
</para>
<para>
An aggregate function can be made to accept a varying number of arguments
by declaring its last argument as a <literal>VARIADIC</> array, in much
the same fashion as for regular functions; see
<xref linkend="xfunc-sql-variadic-functions">. The aggregate's transition
function must have the same array type as its last argument. The
transition function typically would also be marked <literal>VARIADIC</>,
but this is not strictly required.
</para>
<note>
<para>
Variadic aggregates are easily misused in connection with
the <literal>ORDER BY</> option (see <xref linkend="syntax-aggregates">),
since the parser cannot tell whether the wrong number of actual arguments
have been given in such a combination. Keep in mind that everything to
the right of <literal>ORDER BY</> is a sort key, not an argument to the
aggregate. For example, in
<programlisting>
SELECT myaggregate(a ORDER BY a, b, c) FROM ...
</programlisting>
the parser will see this as a single aggregate function argument and
three sort keys. However, the user might have intended
<programlisting>
SELECT myaggregate(a, b, c ORDER BY a) FROM ...
</programlisting>
If <literal>myaggregate</> is variadic, both these calls could be
perfectly valid.
</para>
<para>
For the same reason, it's wise to think twice before creating aggregate
functions with the same names and different numbers of regular arguments.
</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</> — 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
<function>AggCheckCallContext</>, for example:
<programlisting>
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 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, 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>
For further details see the
<xref linkend="sql-createaggregate">
command.
</para>
</sect1>
|