1CREATE AGGREGATE(7) PostgreSQL 13.3 Documentation CREATE AGGREGATE(7)
2
3
4
6 CREATE_AGGREGATE - define a new aggregate function
7
9 CREATE [ OR REPLACE ] AGGREGATE name ( [ argmode ] [ argname ] arg_data_type [ , ... ] ) (
10 SFUNC = sfunc,
11 STYPE = state_data_type
12 [ , SSPACE = state_data_size ]
13 [ , FINALFUNC = ffunc ]
14 [ , FINALFUNC_EXTRA ]
15 [ , FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
16 [ , COMBINEFUNC = combinefunc ]
17 [ , SERIALFUNC = serialfunc ]
18 [ , DESERIALFUNC = deserialfunc ]
19 [ , INITCOND = initial_condition ]
20 [ , MSFUNC = msfunc ]
21 [ , MINVFUNC = minvfunc ]
22 [ , MSTYPE = mstate_data_type ]
23 [ , MSSPACE = mstate_data_size ]
24 [ , MFINALFUNC = mffunc ]
25 [ , MFINALFUNC_EXTRA ]
26 [ , MFINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
27 [ , MINITCOND = minitial_condition ]
28 [ , SORTOP = sort_operator ]
29 [ , PARALLEL = { SAFE | RESTRICTED | UNSAFE } ]
30 )
31
32 CREATE [ OR REPLACE ] AGGREGATE name ( [ [ argmode ] [ argname ] arg_data_type [ , ... ] ]
33 ORDER BY [ argmode ] [ argname ] arg_data_type [ , ... ] ) (
34 SFUNC = sfunc,
35 STYPE = state_data_type
36 [ , SSPACE = state_data_size ]
37 [ , FINALFUNC = ffunc ]
38 [ , FINALFUNC_EXTRA ]
39 [ , FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
40 [ , INITCOND = initial_condition ]
41 [ , PARALLEL = { SAFE | RESTRICTED | UNSAFE } ]
42 [ , HYPOTHETICAL ]
43 )
44
45 or the old syntax
46
47 CREATE [ OR REPLACE ] AGGREGATE name (
48 BASETYPE = base_type,
49 SFUNC = sfunc,
50 STYPE = state_data_type
51 [ , SSPACE = state_data_size ]
52 [ , FINALFUNC = ffunc ]
53 [ , FINALFUNC_EXTRA ]
54 [ , FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
55 [ , COMBINEFUNC = combinefunc ]
56 [ , SERIALFUNC = serialfunc ]
57 [ , DESERIALFUNC = deserialfunc ]
58 [ , INITCOND = initial_condition ]
59 [ , MSFUNC = msfunc ]
60 [ , MINVFUNC = minvfunc ]
61 [ , MSTYPE = mstate_data_type ]
62 [ , MSSPACE = mstate_data_size ]
63 [ , MFINALFUNC = mffunc ]
64 [ , MFINALFUNC_EXTRA ]
65 [ , MFINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
66 [ , MINITCOND = minitial_condition ]
67 [ , SORTOP = sort_operator ]
68 )
69
71 CREATE AGGREGATE defines a new aggregate function. CREATE OR REPLACE
72 AGGREGATE will either define a new aggregate function or replace an
73 existing definition. Some basic and commonly-used aggregate functions
74 are included with the distribution; they are documented in
75 Section 9.21. If one defines new types or needs an aggregate function
76 not already provided, then CREATE AGGREGATE can be used to provide the
77 desired features.
78
79 When replacing an existing definition, the argument types, result type,
80 and number of direct arguments may not be changed. Also, the new
81 definition must be of the same kind (ordinary aggregate, ordered-set
82 aggregate, or hypothetical-set aggregate) as the old one.
83
84 If a schema name is given (for example, CREATE AGGREGATE myschema.myagg
85 ...) then the aggregate function is created in the specified schema.
86 Otherwise it is created in the current schema.
87
88 An aggregate function is identified by its name and input data type(s).
89 Two aggregates in the same schema can have the same name if they
90 operate on different input types. The name and input data type(s) of an
91 aggregate must also be distinct from the name and input data type(s) of
92 every ordinary function in the same schema. This behavior is identical
93 to overloading of ordinary function names (see CREATE FUNCTION
94 (CREATE_FUNCTION(7))).
95
96 A simple aggregate function is made from one or two ordinary functions:
97 a state transition function sfunc, and an optional final calculation
98 function ffunc. These are used as follows:
99
100 sfunc( internal-state, next-data-values ) ---> next-internal-state
101 ffunc( internal-state ) ---> aggregate-value
102
103 PostgreSQL creates a temporary variable of data type stype to hold the
104 current internal state of the aggregate. At each input row, the
105 aggregate argument value(s) are calculated and the state transition
106 function is invoked with the current state value and the new argument
107 value(s) to calculate a new internal state value. After all the rows
108 have been processed, the final function is invoked once to calculate
109 the aggregate's return value. If there is no final function then the
110 ending state value is returned as-is.
111
112 An aggregate function can provide an initial condition, that is, an
113 initial value for the internal state value. This is specified and
114 stored in the database as a value of type text, but it must be a valid
115 external representation of a constant of the state value data type. If
116 it is not supplied then the state value starts out null.
117
118 If the state transition function is declared “strict”, then it cannot
119 be called with null inputs. With such a transition function, aggregate
120 execution behaves as follows. Rows with any null input values are
121 ignored (the function is not called and the previous state value is
122 retained). If the initial state value is null, then at the first row
123 with all-nonnull input values, the first argument value replaces the
124 state value, and the transition function is invoked at each subsequent
125 row with all-nonnull input values. This is handy for implementing
126 aggregates like max. Note that this behavior is only available when
127 state_data_type is the same as the first arg_data_type. When these
128 types are different, you must supply a nonnull initial condition or use
129 a nonstrict transition function.
130
131 If the state transition function is not strict, then it will be called
132 unconditionally at each input row, and must deal with null inputs and
133 null state values for itself. This allows the aggregate author to have
134 full control over the aggregate's handling of null values.
135
136 If the final function is declared “strict”, then it will not be called
137 when the ending state value is null; instead a null result will be
138 returned automatically. (Of course this is just the normal behavior of
139 strict functions.) In any case the final function has the option of
140 returning a null value. For example, the final function for avg returns
141 null when it sees there were zero input rows.
142
143 Sometimes it is useful to declare the final function as taking not just
144 the state value, but extra parameters corresponding to the aggregate's
145 input values. The main reason for doing this is if the final function
146 is polymorphic and the state value's data type would be inadequate to
147 pin down the result type. These extra parameters are always passed as
148 NULL (and so the final function must not be strict when the
149 FINALFUNC_EXTRA option is used), but nonetheless they are valid
150 parameters. The final function could for example make use of
151 get_fn_expr_argtype to identify the actual argument type in the current
152 call.
153
154 An aggregate can optionally support moving-aggregate mode, as described
155 in Section 37.12.1. This requires specifying the MSFUNC, MINVFUNC, and
156 MSTYPE parameters, and optionally the MSSPACE, MFINALFUNC,
157 MFINALFUNC_EXTRA, MFINALFUNC_MODIFY, and MINITCOND parameters. Except
158 for MINVFUNC, these parameters work like the corresponding
159 simple-aggregate parameters without M; they define a separate
160 implementation of the aggregate that includes an inverse transition
161 function.
162
163 The syntax with ORDER BY in the parameter list creates a special type
164 of aggregate called an ordered-set aggregate; or if HYPOTHETICAL is
165 specified, then a hypothetical-set aggregate is created. These
166 aggregates operate over groups of sorted values in order-dependent
167 ways, so that specification of an input sort order is an essential part
168 of a call. Also, they can have direct arguments, which are arguments
169 that are evaluated only once per aggregation rather than once per input
170 row. Hypothetical-set aggregates are a subclass of ordered-set
171 aggregates in which some of the direct arguments are required to match,
172 in number and data types, the aggregated argument columns. This allows
173 the values of those direct arguments to be added to the collection of
174 aggregate-input rows as an additional “hypothetical” row.
175
176 An aggregate can optionally support partial aggregation, as described
177 in Section 37.12.4. This requires specifying the COMBINEFUNC parameter.
178 If the state_data_type is internal, it's usually also appropriate to
179 provide the SERIALFUNC and DESERIALFUNC parameters so that parallel
180 aggregation is possible. Note that the aggregate must also be marked
181 PARALLEL SAFE to enable parallel aggregation.
182
183 Aggregates that behave like MIN or MAX can sometimes be optimized by
184 looking into an index instead of scanning every input row. If this
185 aggregate can be so optimized, indicate it by specifying a sort
186 operator. The basic requirement is that the aggregate must yield the
187 first element in the sort ordering induced by the operator; in other
188 words:
189
190 SELECT agg(col) FROM tab;
191
192 must be equivalent to:
193
194 SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
195
196 Further assumptions are that the aggregate ignores null inputs, and
197 that it delivers a null result if and only if there were no non-null
198 inputs. Ordinarily, a data type's < operator is the proper sort
199 operator for MIN, and > is the proper sort operator for MAX. Note that
200 the optimization will never actually take effect unless the specified
201 operator is the “less than” or “greater than” strategy member of a
202 B-tree index operator class.
203
204 To be able to create an aggregate function, you must have USAGE
205 privilege on the argument types, the state type(s), and the return
206 type, as well as EXECUTE privilege on the supporting functions.
207
209 name
210 The name (optionally schema-qualified) of the aggregate function to
211 create.
212
213 argmode
214 The mode of an argument: IN or VARIADIC. (Aggregate functions do
215 not support OUT arguments.) If omitted, the default is IN. Only the
216 last argument can be marked VARIADIC.
217
218 argname
219 The name of an argument. This is currently only useful for
220 documentation purposes. If omitted, the argument has no name.
221
222 arg_data_type
223 An input data type on which this aggregate function operates. To
224 create a zero-argument aggregate function, write * in place of the
225 list of argument specifications. (An example of such an aggregate
226 is count(*).)
227
228 base_type
229 In the old syntax for CREATE AGGREGATE, the input data type is
230 specified by a basetype parameter rather than being written next to
231 the aggregate name. Note that this syntax allows only one input
232 parameter. To define a zero-argument aggregate function with this
233 syntax, specify the basetype as "ANY" (not *). Ordered-set
234 aggregates cannot be defined with the old syntax.
235
236 sfunc
237 The name of the state transition function to be called for each
238 input row. For a normal N-argument aggregate function, the sfunc
239 must take N+1 arguments, the first being of type state_data_type
240 and the rest matching the declared input data type(s) of the
241 aggregate. The function must return a value of type
242 state_data_type. This function takes the current state value and
243 the current input data value(s), and returns the next state value.
244
245 For ordered-set (including hypothetical-set) aggregates, the state
246 transition function receives only the current state value and the
247 aggregated arguments, not the direct arguments. Otherwise it is the
248 same.
249
250 state_data_type
251 The data type for the aggregate's state value.
252
253 state_data_size
254 The approximate average size (in bytes) of the aggregate's state
255 value. If this parameter is omitted or is zero, a default estimate
256 is used based on the state_data_type. The planner uses this value
257 to estimate the memory required for a grouped aggregate query.
258
259 ffunc
260 The name of the final function called to compute the aggregate's
261 result after all input rows have been traversed. For a normal
262 aggregate, this function must take a single argument of type
263 state_data_type. The return data type of the aggregate is defined
264 as the return type of this function. If ffunc is not specified,
265 then the ending state value is used as the aggregate's result, and
266 the return type is state_data_type.
267
268 For ordered-set (including hypothetical-set) aggregates, the final
269 function receives not only the final state value, but also the
270 values of all the direct arguments.
271
272 If FINALFUNC_EXTRA is specified, then in addition to the final
273 state value and any direct arguments, the final function receives
274 extra NULL values corresponding to the aggregate's regular
275 (aggregated) arguments. This is mainly useful to allow correct
276 resolution of the aggregate result type when a polymorphic
277 aggregate is being defined.
278
279 FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE }
280 This option specifies whether the final function is a pure function
281 that does not modify its arguments. READ_ONLY indicates it does
282 not; the other two values indicate that it may change the
283 transition state value. See Notes below for more detail. The
284 default is READ_ONLY, except for ordered-set aggregates, for which
285 the default is READ_WRITE.
286
287 combinefunc
288 The combinefunc function may optionally be specified to allow the
289 aggregate function to support partial aggregation. If provided, the
290 combinefunc must combine two state_data_type values, each
291 containing the result of aggregation over some subset of the input
292 values, to produce a new state_data_type that represents the result
293 of aggregating over both sets of inputs. This function can be
294 thought of as an sfunc, where instead of acting upon an individual
295 input row and adding it to the running aggregate state, it adds
296 another aggregate state to the running state.
297
298 The combinefunc must be declared as taking two arguments of the
299 state_data_type and returning a value of the state_data_type.
300 Optionally this function may be “strict”. In this case the function
301 will not be called when either of the input states are null; the
302 other state will be taken as the correct result.
303
304 For aggregate functions whose state_data_type is internal, the
305 combinefunc must not be strict. In this case the combinefunc must
306 ensure that null states are handled correctly and that the state
307 being returned is properly stored in the aggregate memory context.
308
309 serialfunc
310 An aggregate function whose state_data_type is internal can
311 participate in parallel aggregation only if it has a serialfunc
312 function, which must serialize the aggregate state into a bytea
313 value for transmission to another process. This function must take
314 a single argument of type internal and return type bytea. A
315 corresponding deserialfunc is also required.
316
317 deserialfunc
318 Deserialize a previously serialized aggregate state back into
319 state_data_type. This function must take two arguments of types
320 bytea and internal, and produce a result of type internal. (Note:
321 the second, internal argument is unused, but is required for type
322 safety reasons.)
323
324 initial_condition
325 The initial setting for the state value. This must be a string
326 constant in the form accepted for the data type state_data_type. If
327 not specified, the state value starts out null.
328
329 msfunc
330 The name of the forward state transition function to be called for
331 each input row in moving-aggregate mode. This is exactly like the
332 regular transition function, except that its first argument and
333 result are of type mstate_data_type, which might be different from
334 state_data_type.
335
336 minvfunc
337 The name of the inverse state transition function to be used in
338 moving-aggregate mode. This function has the same argument and
339 result types as msfunc, but it is used to remove a value from the
340 current aggregate state, rather than add a value to it. The inverse
341 transition function must have the same strictness attribute as the
342 forward state transition function.
343
344 mstate_data_type
345 The data type for the aggregate's state value, when using
346 moving-aggregate mode.
347
348 mstate_data_size
349 The approximate average size (in bytes) of the aggregate's state
350 value, when using moving-aggregate mode. This works the same as
351 state_data_size.
352
353 mffunc
354 The name of the final function called to compute the aggregate's
355 result after all input rows have been traversed, when using
356 moving-aggregate mode. This works the same as ffunc, except that
357 its first argument's type is mstate_data_type and extra dummy
358 arguments are specified by writing MFINALFUNC_EXTRA. The aggregate
359 result type determined by mffunc or mstate_data_type must match
360 that determined by the aggregate's regular implementation.
361
362 MFINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE }
363 This option is like FINALFUNC_MODIFY, but it describes the behavior
364 of the moving-aggregate final function.
365
366 minitial_condition
367 The initial setting for the state value, when using
368 moving-aggregate mode. This works the same as initial_condition.
369
370 sort_operator
371 The associated sort operator for a MIN- or MAX-like aggregate. This
372 is just an operator name (possibly schema-qualified). The operator
373 is assumed to have the same input data types as the aggregate
374 (which must be a single-argument normal aggregate).
375
376 PARALLEL = { SAFE | RESTRICTED | UNSAFE }
377 The meanings of PARALLEL SAFE, PARALLEL RESTRICTED, and PARALLEL
378 UNSAFE are the same as in CREATE FUNCTION (CREATE_FUNCTION(7)). An
379 aggregate will not be considered for parallelization if it is
380 marked PARALLEL UNSAFE (which is the default!) or PARALLEL
381 RESTRICTED. Note that the parallel-safety markings of the
382 aggregate's support functions are not consulted by the planner,
383 only the marking of the aggregate itself.
384
385 HYPOTHETICAL
386 For ordered-set aggregates only, this flag specifies that the
387 aggregate arguments are to be processed according to the
388 requirements for hypothetical-set aggregates: that is, the last few
389 direct arguments must match the data types of the aggregated
390 (WITHIN GROUP) arguments. The HYPOTHETICAL flag has no effect on
391 run-time behavior, only on parse-time resolution of the data types
392 and collations of the aggregate's arguments.
393
394 The parameters of CREATE AGGREGATE can be written in any order, not
395 just the order illustrated above.
396
398 In parameters that specify support function names, you can write a
399 schema name if needed, for example SFUNC = public.sum. Do not write
400 argument types there, however — the argument types of the support
401 functions are determined from other parameters.
402
403 Ordinarily, PostgreSQL functions are expected to be true functions that
404 do not modify their input values. However, an aggregate transition
405 function, when used in the context of an aggregate, is allowed to cheat
406 and modify its transition-state argument in place. This can provide
407 substantial performance benefits compared to making a fresh copy of the
408 transition state each time.
409
410 Likewise, while an aggregate final function is normally expected not to
411 modify its input values, sometimes it is impractical to avoid modifying
412 the transition-state argument. Such behavior must be declared using the
413 FINALFUNC_MODIFY parameter. The READ_WRITE value indicates that the
414 final function modifies the transition state in unspecified ways. This
415 value prevents use of the aggregate as a window function, and it also
416 prevents merging of transition states for aggregate calls that share
417 the same input values and transition functions. The SHAREABLE value
418 indicates that the transition function cannot be applied after the
419 final function, but multiple final-function calls can be performed on
420 the ending transition state value. This value prevents use of the
421 aggregate as a window function, but it allows merging of transition
422 states. (That is, the optimization of interest here is not applying the
423 same final function repeatedly, but applying different final functions
424 to the same ending transition state value. This is allowed as long as
425 none of the final functions are marked READ_WRITE.)
426
427 If an aggregate supports moving-aggregate mode, it will improve
428 calculation efficiency when the aggregate is used as a window function
429 for a window with moving frame start (that is, a frame start mode other
430 than UNBOUNDED PRECEDING). Conceptually, the forward transition
431 function adds input values to the aggregate's state when they enter the
432 window frame from the bottom, and the inverse transition function
433 removes them again when they leave the frame at the top. So, when
434 values are removed, they are always removed in the same order they were
435 added. Whenever the inverse transition function is invoked, it will
436 thus receive the earliest added but not yet removed argument value(s).
437 The inverse transition function can assume that at least one row will
438 remain in the current state after it removes the oldest row. (When this
439 would not be the case, the window function mechanism simply starts a
440 fresh aggregation, rather than using the inverse transition function.)
441
442 The forward transition function for moving-aggregate mode is not
443 allowed to return NULL as the new state value. If the inverse
444 transition function returns NULL, this is taken as an indication that
445 the inverse function cannot reverse the state calculation for this
446 particular input, and so the aggregate calculation will be redone from
447 scratch for the current frame starting position. This convention allows
448 moving-aggregate mode to be used in situations where there are some
449 infrequent cases that are impractical to reverse out of the running
450 state value.
451
452 If no moving-aggregate implementation is supplied, the aggregate can
453 still be used with moving frames, but PostgreSQL will recompute the
454 whole aggregation whenever the start of the frame moves. Note that
455 whether or not the aggregate supports moving-aggregate mode, PostgreSQL
456 can handle a moving frame end without recalculation; this is done by
457 continuing to add new values to the aggregate's state. This is why use
458 of an aggregate as a window function requires that the final function
459 be read-only: it must not damage the aggregate's state value, so that
460 the aggregation can be continued even after an aggregate result value
461 has been obtained for one set of frame boundaries.
462
463 The syntax for ordered-set aggregates allows VARIADIC to be specified
464 for both the last direct parameter and the last aggregated (WITHIN
465 GROUP) parameter. However, the current implementation restricts use of
466 VARIADIC in two ways. First, ordered-set aggregates can only use
467 VARIADIC "any", not other variadic array types. Second, if the last
468 direct parameter is VARIADIC "any", then there can be only one
469 aggregated parameter and it must also be VARIADIC "any". (In the
470 representation used in the system catalogs, these two parameters are
471 merged into a single VARIADIC "any" item, since pg_proc cannot
472 represent functions with more than one VARIADIC parameter.) If the
473 aggregate is a hypothetical-set aggregate, the direct arguments that
474 match the VARIADIC "any" parameter are the hypothetical ones; any
475 preceding parameters represent additional direct arguments that are not
476 constrained to match the aggregated arguments.
477
478 Currently, ordered-set aggregates do not need to support
479 moving-aggregate mode, since they cannot be used as window functions.
480
481 Partial (including parallel) aggregation is currently not supported for
482 ordered-set aggregates. Also, it will never be used for aggregate calls
483 that include DISTINCT or ORDER BY clauses, since those semantics cannot
484 be supported during partial aggregation.
485
487 See Section 37.12.
488
490 CREATE AGGREGATE is a PostgreSQL language extension. The SQL standard
491 does not provide for user-defined aggregate functions.
492
494 ALTER AGGREGATE (ALTER_AGGREGATE(7)), DROP AGGREGATE
495 (DROP_AGGREGATE(7))
496
497
498
499PostgreSQL 13.3 2021 CREATE AGGREGATE(7)