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