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
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
|
<!--
doc/src/sgml/ref/create_aggregate.sgml
PostgreSQL documentation
-->
<refentry id="SQL-CREATEAGGREGATE">
<indexterm zone="sql-createaggregate">
<primary>CREATE AGGREGATE</primary>
</indexterm>
<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>
<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>
|