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