1<!--
2doc/src/sgml/ref/create_aggregate.sgml
3PostgreSQL documentation
4-->
5
6<refentry id="sql-createaggregate">
7 <indexterm zone="sql-createaggregate">
8  <primary>CREATE AGGREGATE</primary>
9 </indexterm>
10
11 <refmeta>
12  <refentrytitle>CREATE AGGREGATE</refentrytitle>
13  <manvolnum>7</manvolnum>
14  <refmiscinfo>SQL - Language Statements</refmiscinfo>
15 </refmeta>
16
17 <refnamediv>
18  <refname>CREATE AGGREGATE</refname>
19  <refpurpose>define a new aggregate function</refpurpose>
20 </refnamediv>
21
22 <refsynopsisdiv>
23<synopsis>
24CREATE AGGREGATE <replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">arg_data_type</replaceable> [ , ... ] ) (
25    SFUNC = <replaceable class="parameter">sfunc</replaceable>,
26    STYPE = <replaceable class="parameter">state_data_type</replaceable>
27    [ , SSPACE = <replaceable class="parameter">state_data_size</replaceable> ]
28    [ , FINALFUNC = <replaceable class="parameter">ffunc</replaceable> ]
29    [ , FINALFUNC_EXTRA ]
30    [ , FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
31    [ , COMBINEFUNC = <replaceable class="parameter">combinefunc</replaceable> ]
32    [ , SERIALFUNC = <replaceable class="parameter">serialfunc</replaceable> ]
33    [ , DESERIALFUNC = <replaceable class="parameter">deserialfunc</replaceable> ]
34    [ , INITCOND = <replaceable class="parameter">initial_condition</replaceable> ]
35    [ , MSFUNC = <replaceable class="parameter">msfunc</replaceable> ]
36    [ , MINVFUNC = <replaceable class="parameter">minvfunc</replaceable> ]
37    [ , MSTYPE = <replaceable class="parameter">mstate_data_type</replaceable> ]
38    [ , MSSPACE = <replaceable class="parameter">mstate_data_size</replaceable> ]
39    [ , MFINALFUNC = <replaceable class="parameter">mffunc</replaceable> ]
40    [ , MFINALFUNC_EXTRA ]
41    [ , MFINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
42    [ , MINITCOND = <replaceable class="parameter">minitial_condition</replaceable> ]
43    [ , SORTOP = <replaceable class="parameter">sort_operator</replaceable> ]
44    [ , PARALLEL = { SAFE | RESTRICTED | UNSAFE } ]
45)
46
47CREATE AGGREGATE <replaceable class="parameter">name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">arg_data_type</replaceable> [ , ... ] ]
48                        ORDER BY [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">arg_data_type</replaceable> [ , ... ] ) (
49    SFUNC = <replaceable class="parameter">sfunc</replaceable>,
50    STYPE = <replaceable class="parameter">state_data_type</replaceable>
51    [ , SSPACE = <replaceable class="parameter">state_data_size</replaceable> ]
52    [ , FINALFUNC = <replaceable class="parameter">ffunc</replaceable> ]
53    [ , FINALFUNC_EXTRA ]
54    [ , FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
55    [ , INITCOND = <replaceable class="parameter">initial_condition</replaceable> ]
56    [ , PARALLEL = { SAFE | RESTRICTED | UNSAFE } ]
57    [ , HYPOTHETICAL ]
58)
59
60<phrase>or the old syntax</phrase>
61
62CREATE AGGREGATE <replaceable class="parameter">name</replaceable> (
63    BASETYPE = <replaceable class="parameter">base_type</replaceable>,
64    SFUNC = <replaceable class="parameter">sfunc</replaceable>,
65    STYPE = <replaceable class="parameter">state_data_type</replaceable>
66    [ , SSPACE = <replaceable class="parameter">state_data_size</replaceable> ]
67    [ , FINALFUNC = <replaceable class="parameter">ffunc</replaceable> ]
68    [ , FINALFUNC_EXTRA ]
69    [ , FINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
70    [ , COMBINEFUNC = <replaceable class="parameter">combinefunc</replaceable> ]
71    [ , SERIALFUNC = <replaceable class="parameter">serialfunc</replaceable> ]
72    [ , DESERIALFUNC = <replaceable class="parameter">deserialfunc</replaceable> ]
73    [ , INITCOND = <replaceable class="parameter">initial_condition</replaceable> ]
74    [ , MSFUNC = <replaceable class="parameter">msfunc</replaceable> ]
75    [ , MINVFUNC = <replaceable class="parameter">minvfunc</replaceable> ]
76    [ , MSTYPE = <replaceable class="parameter">mstate_data_type</replaceable> ]
77    [ , MSSPACE = <replaceable class="parameter">mstate_data_size</replaceable> ]
78    [ , MFINALFUNC = <replaceable class="parameter">mffunc</replaceable> ]
79    [ , MFINALFUNC_EXTRA ]
80    [ , MFINALFUNC_MODIFY = { READ_ONLY | SHAREABLE | READ_WRITE } ]
81    [ , MINITCOND = <replaceable class="parameter">minitial_condition</replaceable> ]
82    [ , SORTOP = <replaceable class="parameter">sort_operator</replaceable> ]
83)
84</synopsis>
85 </refsynopsisdiv>
86
87 <refsect1>
88  <title>Description</title>
89
90  <para>
91   <command>CREATE AGGREGATE</command> defines a new aggregate
92   function. Some basic and commonly-used aggregate functions are
93   included with the distribution; they are documented in <xref
94   linkend="functions-aggregate"/>. If one defines new types or needs
95   an aggregate function not already provided, then <command>CREATE
96   AGGREGATE</command> can be used to provide the desired features.
97  </para>
98
99  <para>
100   If a schema name is given (for example, <literal>CREATE AGGREGATE
101   myschema.myagg ...</literal>) then the aggregate function is created in the
102   specified schema.  Otherwise it is created in the current schema.
103  </para>
104
105  <para>
106   An aggregate function is identified by its name and input data type(s).
107   Two aggregates in the same schema can have the same name if they operate on
108   different input types.  The
109   name and input data type(s) of an aggregate must also be distinct from
110   the name and input data type(s) of every ordinary function in the same
111   schema.
112   This behavior is identical to overloading of ordinary function names
113   (see <xref linkend="sql-createfunction"/>).
114  </para>
115
116  <para>
117   A simple aggregate function is made from one or two ordinary
118   functions:
119   a state transition function
120   <replaceable class="parameter">sfunc</replaceable>,
121   and an optional final calculation function
122   <replaceable class="parameter">ffunc</replaceable>.
123   These are used as follows:
124<programlisting>
125<replaceable class="parameter">sfunc</replaceable>( internal-state, next-data-values ) ---> next-internal-state
126<replaceable class="parameter">ffunc</replaceable>( internal-state ) ---> aggregate-value
127</programlisting>
128  </para>
129
130  <para>
131   <productname>PostgreSQL</productname> creates a temporary variable
132   of data type <replaceable class="parameter">stype</replaceable>
133   to hold the current internal state of the aggregate.  At each input row,
134   the aggregate argument value(s) are calculated and
135   the state transition function is invoked with the current state value
136   and the new argument value(s) to calculate a new
137   internal state value.  After all the rows have been processed,
138   the final function is invoked once to calculate the aggregate's return
139   value.  If there is no final function then the ending state value
140   is returned as-is.
141  </para>
142
143  <para>
144   An aggregate function can provide an initial condition,
145   that is, an initial value for the internal state value.
146   This is specified and stored in the database as a value of type
147   <type>text</type>, but it must be a valid external representation
148   of a constant of the state value data type.  If it is not supplied
149   then the state value starts out null.
150  </para>
151
152  <para>
153   If the state transition function is declared <quote>strict</quote>,
154   then it cannot be called with null inputs.  With such a transition
155   function, aggregate execution behaves as follows.  Rows with any null input
156   values are ignored (the function is not called and the previous state value
157   is retained).  If the initial state value is null, then at the first row
158   with all-nonnull input values, the first argument value replaces the state
159   value, and the transition function is invoked at each subsequent row with
160   all-nonnull input values.
161   This is handy for implementing aggregates like <function>max</function>.
162   Note that this behavior is only available when
163   <replaceable class="parameter">state_data_type</replaceable>
164   is the same as the first
165   <replaceable class="parameter">arg_data_type</replaceable>.
166   When these types are different, you must supply a nonnull initial
167   condition or use a nonstrict transition function.
168  </para>
169
170  <para>
171   If the state transition function is not strict, then it will be called
172   unconditionally at each input row, and must deal with null inputs
173   and null state values for itself.  This allows the aggregate
174   author to have full control over the aggregate's handling of null values.
175  </para>
176
177  <para>
178   If the final function is declared <quote>strict</quote>, then it will not
179   be called when the ending state value is null; instead a null result
180   will be returned automatically.  (Of course this is just the normal
181   behavior of strict functions.)  In any case the final function has
182   the option of returning a null value.  For example, the final function for
183   <function>avg</function> returns null when it sees there were zero
184   input rows.
185  </para>
186
187  <para>
188   Sometimes it is useful to declare the final function as taking not just
189   the state value, but extra parameters corresponding to the aggregate's
190   input values.  The main reason for doing this is if the final function
191   is polymorphic and the state value's data type would be inadequate to
192   pin down the result type.  These extra parameters are always passed as
193   NULL (and so the final function must not be strict when
194   the <literal>FINALFUNC_EXTRA</literal> option is used), but nonetheless they
195   are valid parameters.  The final function could for example make use
196   of <function>get_fn_expr_argtype</function> to identify the actual argument type
197   in the current call.
198  </para>
199
200  <para>
201   An aggregate can optionally support <firstterm>moving-aggregate mode</firstterm>,
202   as described in <xref linkend="xaggr-moving-aggregates"/>.  This requires
203   specifying the <literal>MSFUNC</literal>, <literal>MINVFUNC</literal>,
204   and <literal>MSTYPE</literal> parameters, and optionally
205   the <literal>MSSPACE</literal>, <literal>MFINALFUNC</literal>,
206   <literal>MFINALFUNC_EXTRA</literal>, <literal>MFINALFUNC_MODIFY</literal>,
207   and <literal>MINITCOND</literal> parameters.  Except for <literal>MINVFUNC</literal>,
208   these parameters work like the corresponding simple-aggregate parameters
209   without <literal>M</literal>; they define a separate implementation of the
210   aggregate that includes an inverse transition function.
211  </para>
212
213  <para>
214   The syntax with <literal>ORDER BY</literal> in the parameter list creates
215   a special type of aggregate called an <firstterm>ordered-set
216   aggregate</firstterm>; or if <literal>HYPOTHETICAL</literal> is specified, then
217   a <firstterm>hypothetical-set aggregate</firstterm> is created.  These
218   aggregates operate over groups of sorted values in order-dependent ways,
219   so that specification of an input sort order is an essential part of a
220   call.  Also, they can have <firstterm>direct</firstterm> arguments, which are
221   arguments that are evaluated only once per aggregation rather than once
222   per input row.  Hypothetical-set aggregates are a subclass of ordered-set
223   aggregates in which some of the direct arguments are required to match,
224   in number and data types, the aggregated argument columns.  This allows
225   the values of those direct arguments to be added to the collection of
226   aggregate-input rows as an additional <quote>hypothetical</quote> row.
227  </para>
228
229  <para>
230   An aggregate can optionally support <firstterm>partial aggregation</firstterm>,
231   as described in <xref linkend="xaggr-partial-aggregates"/>.
232   This requires specifying the <literal>COMBINEFUNC</literal> parameter.
233   If the <replaceable class="parameter">state_data_type</replaceable>
234   is <type>internal</type>, it's usually also appropriate to provide the
235   <literal>SERIALFUNC</literal> and <literal>DESERIALFUNC</literal> parameters so that
236   parallel aggregation is possible.  Note that the aggregate must also be
237   marked <literal>PARALLEL SAFE</literal> to enable parallel aggregation.
238  </para>
239
240  <para>
241   Aggregates that behave like <function>MIN</function> or <function>MAX</function> can
242   sometimes be optimized by looking into an index instead of scanning every
243   input row.  If this aggregate can be so optimized, indicate it by
244   specifying a <firstterm>sort operator</firstterm>.  The basic requirement is that
245   the aggregate must yield the first element in the sort ordering induced by
246   the operator; in other words:
247<programlisting>
248SELECT agg(col) FROM tab;
249</programlisting>
250   must be equivalent to:
251<programlisting>
252SELECT col FROM tab ORDER BY col USING sortop LIMIT 1;
253</programlisting>
254   Further assumptions are that the aggregate ignores null inputs, and that
255   it delivers a null result if and only if there were no non-null inputs.
256   Ordinarily, a data type's <literal>&lt;</literal> operator is the proper sort
257   operator for <function>MIN</function>, and <literal>&gt;</literal> is the proper sort
258   operator for <function>MAX</function>.  Note that the optimization will never
259   actually take effect unless the specified operator is the <quote>less
260   than</quote> or <quote>greater than</quote> strategy member of a B-tree
261   index operator class.
262  </para>
263
264  <para>
265   To be able to create an aggregate function, you must
266   have <literal>USAGE</literal> privilege on the argument types, the state
267   type(s), and the return type, as well as <literal>EXECUTE</literal>
268   privilege on the supporting functions.
269  </para>
270 </refsect1>
271
272 <refsect1>
273  <title>Parameters</title>
274
275  <variablelist>
276   <varlistentry>
277    <term><replaceable class="parameter">name</replaceable></term>
278    <listitem>
279     <para>
280      The name (optionally schema-qualified) of the aggregate function
281      to create.
282     </para>
283    </listitem>
284   </varlistentry>
285
286   <varlistentry>
287    <term><replaceable class="parameter">argmode</replaceable></term>
288
289    <listitem>
290     <para>
291      The mode of an argument: <literal>IN</literal> or <literal>VARIADIC</literal>.
292      (Aggregate functions do not support <literal>OUT</literal> arguments.)
293      If omitted, the default is <literal>IN</literal>.  Only the last argument
294      can be marked <literal>VARIADIC</literal>.
295     </para>
296    </listitem>
297   </varlistentry>
298
299   <varlistentry>
300    <term><replaceable class="parameter">argname</replaceable></term>
301
302    <listitem>
303     <para>
304      The name of an argument.  This is currently only useful for
305      documentation purposes.  If omitted, the argument has no name.
306     </para>
307    </listitem>
308   </varlistentry>
309
310   <varlistentry>
311    <term><replaceable class="parameter">arg_data_type</replaceable></term>
312    <listitem>
313     <para>
314      An input data type on which this aggregate function operates.
315      To create a zero-argument aggregate function, write <literal>*</literal>
316      in place of the list of argument specifications.  (An example of such an
317      aggregate is <function>count(*)</function>.)
318     </para>
319    </listitem>
320   </varlistentry>
321
322   <varlistentry>
323    <term><replaceable class="parameter">base_type</replaceable></term>
324    <listitem>
325     <para>
326      In the old syntax for <command>CREATE AGGREGATE</command>, the input data type
327      is specified by a <literal>basetype</literal> parameter rather than being
328      written next to the aggregate name.  Note that this syntax allows
329      only one input parameter.  To define a zero-argument aggregate function
330      with this syntax, specify the <literal>basetype</literal> as
331      <literal>"ANY"</literal> (not <literal>*</literal>).
332      Ordered-set aggregates cannot be defined with the old syntax.
333     </para>
334    </listitem>
335   </varlistentry>
336
337   <varlistentry>
338    <term><replaceable class="parameter">sfunc</replaceable></term>
339    <listitem>
340     <para>
341      The name of the state transition function to be called for each
342      input row.  For a normal <replaceable class="parameter">N</replaceable>-argument
343      aggregate function, the <replaceable class="parameter">sfunc</replaceable>
344      must take <replaceable class="parameter">N</replaceable>+1 arguments,
345      the first being of type <replaceable
346      class="parameter">state_data_type</replaceable> and the rest
347      matching the declared input data type(s) of the aggregate.
348      The function must return a value of type <replaceable
349      class="parameter">state_data_type</replaceable>.  This function
350      takes the current state value and the current input data value(s),
351      and returns the next state value.
352     </para>
353
354     <para>
355      For ordered-set (including hypothetical-set) aggregates, the state
356      transition function receives only the current state value and the
357      aggregated arguments, not the direct arguments.  Otherwise it is the
358      same.
359     </para>
360    </listitem>
361   </varlistentry>
362
363   <varlistentry>
364    <term><replaceable class="parameter">state_data_type</replaceable></term>
365    <listitem>
366     <para>
367      The data type for the aggregate's state value.
368     </para>
369    </listitem>
370   </varlistentry>
371
372   <varlistentry>
373    <term><replaceable class="parameter">state_data_size</replaceable></term>
374    <listitem>
375     <para>
376      The approximate average size (in bytes) of the aggregate's state value.
377      If this parameter is omitted or is zero, a default estimate is used
378      based on the <replaceable>state_data_type</replaceable>.
379      The planner uses this value to estimate the memory required for a
380      grouped aggregate query.  The planner will consider using hash
381      aggregation for such a query only if the hash table is estimated to fit
382      in <xref linkend="guc-work-mem"/>; therefore, large values of this
383      parameter discourage use of hash aggregation.
384     </para>
385    </listitem>
386   </varlistentry>
387
388   <varlistentry>
389    <term><replaceable class="parameter">ffunc</replaceable></term>
390    <listitem>
391     <para>
392      The name of the final function called to compute the aggregate's
393      result after all input rows have been traversed.
394      For a normal aggregate, this function
395      must take a single argument of type <replaceable
396      class="parameter">state_data_type</replaceable>.  The return
397      data type of the aggregate is defined as the return type of this
398      function.  If <replaceable class="parameter">ffunc</replaceable>
399      is not specified, then the ending state value is used as the
400      aggregate's result, and the return type is <replaceable
401      class="parameter">state_data_type</replaceable>.
402     </para>
403
404     <para>
405      For ordered-set (including hypothetical-set) aggregates, the
406      final function receives not only the final state value,
407      but also the values of all the direct arguments.
408     </para>
409
410     <para>
411      If <literal>FINALFUNC_EXTRA</literal> is specified, then in addition to the
412      final state value and any direct arguments, the final function
413      receives extra NULL values corresponding to the aggregate's regular
414      (aggregated) arguments.  This is mainly useful to allow correct
415      resolution of the aggregate result type when a polymorphic aggregate
416      is being defined.
417     </para>
418    </listitem>
419   </varlistentry>
420
421   <varlistentry>
422    <term><literal>FINALFUNC_MODIFY</literal> = { <literal>READ_ONLY</literal> | <literal>SHAREABLE</literal> | <literal>READ_WRITE</literal> }</term>
423    <listitem>
424     <para>
425      This option specifies whether the final function is a pure function
426      that does not modify its arguments.  <literal>READ_ONLY</literal> indicates
427      it does not; the other two values indicate that it may change the
428      transition state value.  See <xref linkend="sql-createaggregate-notes"
429      endterm="sql-createaggregate-notes-title"/> below for more detail.  The
430      default is <literal>READ_ONLY</literal>, except for ordered-set aggregates,
431      for which the default is <literal>READ_WRITE</literal>.
432     </para>
433    </listitem>
434   </varlistentry>
435
436   <varlistentry>
437    <term><replaceable class="parameter">combinefunc</replaceable></term>
438    <listitem>
439     <para>
440      The <replaceable class="parameter">combinefunc</replaceable> function
441      may optionally be specified to allow the aggregate function to support
442      partial aggregation.  If provided,
443      the <replaceable class="parameter">combinefunc</replaceable> must
444      combine two <replaceable class="parameter">state_data_type</replaceable>
445      values, each containing the result of aggregation over some subset of
446      the input values, to produce a
447      new <replaceable class="parameter">state_data_type</replaceable> that
448      represents the result of aggregating over both sets of inputs.  This
449      function can be thought of as
450      an <replaceable class="parameter">sfunc</replaceable>, where instead of
451      acting upon an individual input row and adding it to the running
452      aggregate state, it adds another aggregate state to the running state.
453     </para>
454
455     <para>
456      The <replaceable class="parameter">combinefunc</replaceable> must be
457      declared as taking two arguments of
458      the <replaceable class="parameter">state_data_type</replaceable> and
459      returning a value of
460      the <replaceable class="parameter">state_data_type</replaceable>.
461      Optionally this function may be <quote>strict</quote>. In this case the
462      function will not be called when either of the input states are null;
463      the other state will be taken as the correct result.
464     </para>
465
466     <para>
467      For aggregate functions
468      whose <replaceable class="parameter">state_data_type</replaceable>
469      is <type>internal</type>,
470      the <replaceable class="parameter">combinefunc</replaceable> must not
471      be strict. In this case
472      the <replaceable class="parameter">combinefunc</replaceable> must
473      ensure that null states are handled correctly and that the state being
474      returned is properly stored in the aggregate memory context.
475     </para>
476    </listitem>
477   </varlistentry>
478
479   <varlistentry>
480    <term><replaceable class="parameter">serialfunc</replaceable></term>
481    <listitem>
482     <para>
483      An aggregate function
484      whose <replaceable class="parameter">state_data_type</replaceable>
485      is <type>internal</type> can participate in parallel aggregation only if it
486      has a <replaceable class="parameter">serialfunc</replaceable> function,
487      which must serialize the aggregate state into a <type>bytea</type> value for
488      transmission to another process.  This function must take a single
489      argument of type <type>internal</type> and return type <type>bytea</type>.  A
490      corresponding <replaceable class="parameter">deserialfunc</replaceable>
491      is also required.
492     </para>
493    </listitem>
494   </varlistentry>
495
496   <varlistentry>
497    <term><replaceable class="parameter">deserialfunc</replaceable></term>
498    <listitem>
499     <para>
500      Deserialize a previously serialized aggregate state back into
501      <replaceable class="parameter">state_data_type</replaceable>. This
502      function must take two arguments of types <type>bytea</type>
503      and <type>internal</type>, and produce a result of type <type>internal</type>.
504      (Note: the second, <type>internal</type> argument is unused, but is required
505      for type safety reasons.)
506     </para>
507    </listitem>
508   </varlistentry>
509
510   <varlistentry>
511    <term><replaceable class="parameter">initial_condition</replaceable></term>
512    <listitem>
513     <para>
514      The initial setting for the state value.  This must be a string
515      constant in the form accepted for the data type <replaceable
516      class="parameter">state_data_type</replaceable>.  If not
517      specified, the state value starts out null.
518     </para>
519    </listitem>
520   </varlistentry>
521
522   <varlistentry>
523    <term><replaceable class="parameter">msfunc</replaceable></term>
524    <listitem>
525     <para>
526      The name of the forward state transition function to be called for each
527      input row in moving-aggregate mode.  This is exactly like the regular
528      transition function, except that its first argument and result are of
529      type <replaceable>mstate_data_type</replaceable>, which might be different
530      from <replaceable>state_data_type</replaceable>.
531     </para>
532    </listitem>
533   </varlistentry>
534
535   <varlistentry>
536    <term><replaceable class="parameter">minvfunc</replaceable></term>
537    <listitem>
538     <para>
539      The name of the inverse state transition function to be used in
540      moving-aggregate mode.  This function has the same argument and
541      result types as <replaceable>msfunc</replaceable>, but it is used to remove
542      a value from the current aggregate state, rather than add a value to
543      it.  The inverse transition function must have the same strictness
544      attribute as the forward state transition function.
545     </para>
546    </listitem>
547   </varlistentry>
548
549   <varlistentry>
550    <term><replaceable class="parameter">mstate_data_type</replaceable></term>
551    <listitem>
552     <para>
553      The data type for the aggregate's state value, when using
554      moving-aggregate mode.
555     </para>
556    </listitem>
557   </varlistentry>
558
559   <varlistentry>
560    <term><replaceable class="parameter">mstate_data_size</replaceable></term>
561    <listitem>
562     <para>
563      The approximate average size (in bytes) of the aggregate's state
564      value, when using moving-aggregate mode.  This works the same as
565      <replaceable>state_data_size</replaceable>.
566     </para>
567    </listitem>
568   </varlistentry>
569
570   <varlistentry>
571    <term><replaceable class="parameter">mffunc</replaceable></term>
572    <listitem>
573     <para>
574      The name of the final function called to compute the aggregate's
575      result after all input rows have been traversed, when using
576      moving-aggregate mode.  This works the same as <replaceable>ffunc</replaceable>,
577      except that its first argument's type
578      is <replaceable>mstate_data_type</replaceable> and extra dummy arguments are
579      specified by writing <literal>MFINALFUNC_EXTRA</literal>.
580      The aggregate result type determined by <replaceable>mffunc</replaceable>
581      or <replaceable>mstate_data_type</replaceable> must match that determined by the
582      aggregate's regular implementation.
583     </para>
584    </listitem>
585   </varlistentry>
586
587   <varlistentry>
588    <term><literal>MFINALFUNC_MODIFY</literal> = { <literal>READ_ONLY</literal> | <literal>SHAREABLE</literal> | <literal>READ_WRITE</literal> }</term>
589    <listitem>
590     <para>
591      This option is like <literal>FINALFUNC_MODIFY</literal>, but it describes
592      the behavior of the moving-aggregate final function.
593     </para>
594    </listitem>
595   </varlistentry>
596
597   <varlistentry>
598    <term><replaceable class="parameter">minitial_condition</replaceable></term>
599    <listitem>
600     <para>
601      The initial setting for the state value, when using moving-aggregate
602      mode.  This works the same as <replaceable>initial_condition</replaceable>.
603     </para>
604    </listitem>
605   </varlistentry>
606
607   <varlistentry>
608    <term><replaceable class="parameter">sort_operator</replaceable></term>
609    <listitem>
610     <para>
611      The associated sort operator for a <function>MIN</function>- or
612      <function>MAX</function>-like aggregate.
613      This is just an operator name (possibly schema-qualified).
614      The operator is assumed to have the same input data types as
615      the aggregate (which must be a single-argument normal aggregate).
616     </para>
617    </listitem>
618   </varlistentry>
619
620   <varlistentry>
621    <term><literal>PARALLEL =</literal> { <literal>SAFE</literal> | <literal>RESTRICTED</literal> | <literal>UNSAFE</literal> }</term>
622    <listitem>
623     <para>
624      The meanings of <literal>PARALLEL SAFE</literal>, <literal>PARALLEL
625      RESTRICTED</literal>, and <literal>PARALLEL UNSAFE</literal> are the same as
626      in <xref linkend="sql-createfunction"/>.  An aggregate will not be
627      considered for parallelization if it is marked <literal>PARALLEL
628      UNSAFE</literal> (which is the default!) or <literal>PARALLEL RESTRICTED</literal>.
629      Note that the parallel-safety markings of the aggregate's support
630      functions are not consulted by the planner, only the marking of the
631      aggregate itself.
632     </para>
633    </listitem>
634   </varlistentry>
635
636   <varlistentry>
637    <term><literal>HYPOTHETICAL</literal></term>
638    <listitem>
639     <para>
640      For ordered-set aggregates only, this flag specifies that the aggregate
641      arguments are to be processed according to the requirements for
642      hypothetical-set aggregates: that is, the last few direct arguments must
643      match the data types of the aggregated (<literal>WITHIN GROUP</literal>)
644      arguments.  The <literal>HYPOTHETICAL</literal> flag has no effect on
645      run-time behavior, only on parse-time resolution of the data types and
646      collations of the aggregate's arguments.
647     </para>
648    </listitem>
649   </varlistentry>
650  </variablelist>
651
652  <para>
653   The parameters of <command>CREATE AGGREGATE</command> can be
654   written in any order, not just the order illustrated above.
655  </para>
656 </refsect1>
657
658 <refsect1 id="sql-createaggregate-notes">
659  <title id="sql-createaggregate-notes-title">Notes</title>
660
661   <para>
662    In parameters that specify support function names, you can write
663    a schema name if needed, for example <literal>SFUNC = public.sum</literal>.
664    Do not write argument types there, however &mdash; the argument types
665    of the support functions are determined from other parameters.
666   </para>
667
668   <para>
669    Ordinarily, PostgreSQL functions are expected to be true functions that
670    do not modify their input values.  However, an aggregate transition
671    function, <emphasis>when used in the context of an aggregate</emphasis>,
672    is allowed to cheat and modify its transition-state argument in place.
673    This can provide substantial performance benefits compared to making
674    a fresh copy of the transition state each time.
675   </para>
676
677   <para>
678    Likewise, while an aggregate final function is normally expected not to
679    modify its input values, sometimes it is impractical to avoid modifying
680    the transition-state argument.  Such behavior must be declared using
681    the <literal>FINALFUNC_MODIFY</literal> parameter.
682    The <literal>READ_WRITE</literal>
683    value indicates that the final function modifies the transition state in
684    unspecified ways.  This value prevents use of the aggregate as a window
685    function, and it also prevents merging of transition states for aggregate
686    calls that share the same input values and transition functions.
687    The <literal>SHAREABLE</literal> value indicates that the transition function
688    cannot be applied after the final function, but multiple final-function
689    calls can be performed on the ending transition state value.  This value
690    prevents use of the aggregate as a window function, but it allows merging
691    of transition states.  (That is, the optimization of interest here is not
692    applying the same final function repeatedly, but applying different final
693    functions to the same ending transition state value.  This is allowed as
694    long as none of the final functions are marked <literal>READ_WRITE</literal>.)
695   </para>
696
697   <para>
698    If an aggregate supports moving-aggregate mode, it will improve
699    calculation efficiency when the aggregate is used as a window function
700    for a window with moving frame start (that is, a frame start mode other
701    than <literal>UNBOUNDED PRECEDING</literal>).  Conceptually, the forward
702    transition function adds input values to the aggregate's state when
703    they enter the window frame from the bottom, and the inverse transition
704    function removes them again when they leave the frame at the top.  So,
705    when values are removed, they are always removed in the same order they
706    were added.  Whenever the inverse transition function is invoked, it will
707    thus receive the earliest added but not yet removed argument value(s).
708    The inverse transition function can assume that at least one row will
709    remain in the current state after it removes the oldest row.  (When this
710    would not be the case, the window function mechanism simply starts a
711    fresh aggregation, rather than using the inverse transition function.)
712   </para>
713
714   <para>
715    The forward transition function for moving-aggregate mode is not
716    allowed to return NULL as the new state value. If the inverse
717    transition function returns NULL, this is taken as an indication that
718    the inverse function cannot reverse the state calculation for this
719    particular input, and so the aggregate calculation will be redone from
720    scratch for the current frame starting position.  This convention
721    allows moving-aggregate mode to be used in situations where there are
722    some infrequent cases that are impractical to reverse out of the
723    running state value.
724   </para>
725
726   <para>
727    If no moving-aggregate implementation is supplied,
728    the aggregate can still be used with moving frames,
729    but <productname>PostgreSQL</productname> will recompute the whole
730    aggregation whenever the start of the frame moves.
731    Note that whether or not the aggregate supports moving-aggregate
732    mode, <productname>PostgreSQL</productname> can handle a moving frame
733    end without recalculation; this is done by continuing to add new values
734    to the aggregate's state.  This is why use of an aggregate as a window
735    function requires that the final function be read-only: it must
736    not damage the aggregate's state value, so that the aggregation can be
737    continued even after an aggregate result value has been obtained for
738    one set of frame boundaries.
739   </para>
740
741   <para>
742    The syntax for ordered-set aggregates allows <literal>VARIADIC</literal>
743    to be specified for both the last direct parameter and the last
744    aggregated (<literal>WITHIN GROUP</literal>) parameter.  However, the
745    current implementation restricts use of <literal>VARIADIC</literal>
746    in two ways.  First, ordered-set aggregates can only use
747    <literal>VARIADIC "any"</literal>, not other variadic array types.
748    Second, if the last direct parameter is <literal>VARIADIC "any"</literal>,
749    then there can be only one aggregated parameter and it must also
750    be <literal>VARIADIC "any"</literal>.  (In the representation used in the
751    system catalogs, these two parameters are merged into a single
752    <literal>VARIADIC "any"</literal> item, since <structname>pg_proc</structname> cannot
753    represent functions with more than one <literal>VARIADIC</literal> parameter.)
754    If the aggregate is a hypothetical-set aggregate, the direct arguments
755    that match the <literal>VARIADIC "any"</literal> parameter are the hypothetical
756    ones; any preceding parameters represent additional direct arguments
757    that are not constrained to match the aggregated arguments.
758   </para>
759
760   <para>
761    Currently, ordered-set aggregates do not need to support
762    moving-aggregate mode, since they cannot be used as window functions.
763   </para>
764
765   <para>
766    Partial (including parallel) aggregation is currently not supported for
767    ordered-set aggregates.  Also, it will never be used for aggregate calls
768    that include <literal>DISTINCT</literal> or <literal>ORDER BY</literal> clauses, since
769    those semantics cannot be supported during partial aggregation.
770  </para>
771 </refsect1>
772
773 <refsect1>
774  <title>Examples</title>
775
776  <para>
777   See <xref linkend="xaggr"/>.
778  </para>
779 </refsect1>
780
781 <refsect1>
782  <title>Compatibility</title>
783
784  <para>
785   <command>CREATE AGGREGATE</command> is a
786   <productname>PostgreSQL</productname> language extension.  The SQL
787   standard does not provide for user-defined aggregate functions.
788  </para>
789 </refsect1>
790
791 <refsect1>
792  <title>See Also</title>
793
794  <simplelist type="inline">
795   <member><xref linkend="sql-alteraggregate"/></member>
796   <member><xref linkend="sql-dropaggregate"/></member>
797  </simplelist>
798 </refsect1>
799</refentry>
800