1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>32.10.User-Defined Aggregates</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="extend.html" title="Chapter32.Extending SQL">
<link rel="prev" href="xfunc-c.html" title="32.9.C-Language Functions">
<link rel="next" href="xtypes.html" title="32.11.User-Defined Types">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="xaggr"></a>32.10.User-Defined Aggregates</h2></div></div></div>
<a name="id710567"></a><p> Aggregate functions in <span class="productname">PostgreSQL</span>
are expressed as <em class="firstterm">state values</em>
and <em class="firstterm">state transition functions</em>.
That is, an aggregate can be
defined in terms of state that is modified whenever an
input item is processed. To define a new aggregate
function, one selects a data type for the state value,
an initial value for the state, and a state transition
function. The state transition function is just an
ordinary function that could also be used outside the
context of the aggregate. A <em class="firstterm">final function</em>
can also be specified, in case the desired result of the aggregate
is different from the data that needs to be kept in the running
state value.
</p>
<p> Thus, in addition to the argument and result data types seen by a user
of the aggregate, there is an internal state-value data type that
may be different from both the argument and result types.
</p>
<p> If we define an aggregate that does not use a final function,
we have an aggregate that computes a running function of
the column values from each row. <code class="function">sum</code> is an
example of this kind of aggregate. <code class="function">sum</code> starts at
zero and always adds the current row's value to
its running total. For example, if we want to make a <code class="function">sum</code>
aggregate to work on a data type for complex numbers,
we only need the addition function for that data type.
The aggregate definition would be:
</p>
<pre class="screen">CREATE AGGREGATE complex_sum (
sfunc = complex_add,
basetype = complex,
stype = complex,
initcond = '(0,0)'
);
SELECT complex_sum(a) FROM test_complex;
complex_sum
-------------
(34,53.9)</pre>
<p>
(In practice, we'd just name the aggregate <code class="function">sum</code> and rely on
<span class="productname">PostgreSQL</span> to figure out which kind
of sum to apply to a column of type <code class="type">complex</code>.)
</p>
<p> The above definition of <code class="function">sum</code> will return zero (the initial
state condition) if there are no nonnull input values.
Perhaps we want to return null in that case instead [mdash ] the SQL standard
expects <code class="function">sum</code> to behave that way. We can do this simply by
omitting the <code class="literal">initcond</code> phrase, so that the initial state
condition is null. Ordinarily this would mean that the <code class="literal">sfunc</code>
would need to check for a null state-condition input, but for
<code class="function">sum</code> and some other simple aggregates like
<code class="function">max</code> and <code class="function">min</code>,
it is sufficient to insert the first nonnull input value into
the state variable and then start applying the transition function
at the second nonnull input value. <span class="productname">PostgreSQL</span>
will do that automatically if the initial condition is null and
the transition function is marked “<span class="quote">strict</span>” (i.e., not to be called
for null inputs).
</p>
<p> Another bit of default behavior for a “<span class="quote">strict</span>” transition function
is that the previous state value is retained unchanged whenever a
null input value is encountered. Thus, null values are ignored. If you
need some other behavior for null inputs, just do not define your transition
function as strict, and code it to test for null inputs and do
whatever is needed.
</p>
<p> <code class="function">avg</code> (average) is a more complex example of an aggregate. It requires
two pieces of running state: the sum of the inputs and the count
of the number of inputs. The final result is obtained by dividing
these quantities. Average is typically implemented by using a
two-element array as the state value. For example,
the built-in implementation of <code class="function">avg(float8)</code>
looks like:
</p>
<pre class="programlisting">CREATE AGGREGATE avg (
sfunc = float8_accum,
basetype = float8,
stype = float8[],
finalfunc = float8_avg,
initcond = '{0,0}'
);</pre>
<p>
</p>
<p> Aggregate functions may use polymorphic
state transition functions or final functions, so that the same functions
can be used to implement multiple aggregates.
See <a href="extend-type-system.html#extend-types-polymorphic" title="32.2.5.Polymorphic Types">Section32.2.5, “Polymorphic Types”</a>
for an explanation of polymorphic functions.
Going a step further, the aggregate function itself may be specified
with a polymorphic base type and state type, allowing a single
aggregate definition to serve for multiple input data types.
Here is an example of a polymorphic aggregate:
</p>
<pre class="programlisting">CREATE AGGREGATE array_accum (
sfunc = array_append,
basetype = anyelement,
stype = anyarray,
initcond = '{}'
);</pre>
<p>
Here, the actual state type for any aggregate call is the array type
having the actual input type as elements.
</p>
<p> Here's the output using two different actual data types as arguments:
</p>
<pre class="programlisting">SELECT attrelid::regclass, array_accum(attname)
FROM pg_attribute
WHERE attnum > 0 AND attrelid = 'pg_tablespace'::regclass
GROUP BY attrelid;
attrelid | array_accum
---------------+---------------------------------------
pg_tablespace | {spcname,spcowner,spclocation,spcacl}
(1 row)
SELECT attrelid::regclass, array_accum(atttypid)
FROM pg_attribute
WHERE attnum > 0 AND attrelid = 'pg_tablespace'::regclass
GROUP BY attrelid;
attrelid | array_accum
---------------+-----------------
pg_tablespace | {19,26,25,1034}
(1 row)</pre>
<p>
</p>
<p> A function written in C can detect that it is being called as an
aggregate transition or final function by seeing if it was passed
an <code class="structname">AggState</code> node as the function call “<span class="quote">context</span>”,
for example by
</p>
<pre class="programlisting"> if (fcinfo->context && IsA(fcinfo->context, AggState))</pre>
<p>
One reason for checking this is that when it is true, the left input
must be a temporary transition value and can therefore safely be modified
in-place rather than allocating a new copy. (This is the <span class="emphasis"><em>only</em></span>
case where it is safe for a function to modify a pass-by-reference input.)
See <code class="literal">int8inc()</code> for an example.
</p>
<p> For further details see the
<a href="sql-createaggregate.html">CREATE AGGREGATE</a>
command.
</p>
</div></body>
</html>
|