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>9.21. Aggregate Functions</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="functions-range.html" title="9.20. Range/Multirange Functions and Operators" /><link rel="next" href="functions-window.html" title="9.22. Window Functions" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">9.21. Aggregate Functions</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="functions-range.html" title="9.20. Range/Multirange Functions and Operators">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><th width="60%" align="center">Chapter 9. Functions and Operators</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="functions-window.html" title="9.22. Window Functions">Next</a></td></tr></table><hr /></div><div class="sect1" id="FUNCTIONS-AGGREGATE"><div class="titlepage"><div><div><h2 class="title" style="clear: both">9.21. Aggregate Functions <a href="#FUNCTIONS-AGGREGATE" class="id_link">#</a></h2></div></div></div><a id="id-1.5.8.27.2" class="indexterm"></a><p>
3 <em class="firstterm">Aggregate functions</em> compute a single result
4 from a set of input values. The built-in general-purpose aggregate
5 functions are listed in <a class="xref" href="functions-aggregate.html#FUNCTIONS-AGGREGATE-TABLE" title="Table 9.62. General-Purpose Aggregate Functions">Table 9.62</a>
6 while statistical aggregates are in <a class="xref" href="functions-aggregate.html#FUNCTIONS-AGGREGATE-STATISTICS-TABLE" title="Table 9.63. Aggregate Functions for Statistics">Table 9.63</a>.
7 The built-in within-group ordered-set aggregate functions
8 are listed in <a class="xref" href="functions-aggregate.html#FUNCTIONS-ORDEREDSET-TABLE" title="Table 9.64. Ordered-Set Aggregate Functions">Table 9.64</a>
9 while the built-in within-group hypothetical-set ones are in <a class="xref" href="functions-aggregate.html#FUNCTIONS-HYPOTHETICAL-TABLE" title="Table 9.65. Hypothetical-Set Aggregate Functions">Table 9.65</a>. Grouping operations,
10 which are closely related to aggregate functions, are listed in
11 <a class="xref" href="functions-aggregate.html#FUNCTIONS-GROUPING-TABLE" title="Table 9.66. Grouping Operations">Table 9.66</a>.
12 The special syntax considerations for aggregate
13 functions are explained in <a class="xref" href="sql-expressions.html#SYNTAX-AGGREGATES" title="4.2.7. Aggregate Expressions">Section 4.2.7</a>.
14 Consult <a class="xref" href="tutorial-agg.html" title="2.7. Aggregate Functions">Section 2.7</a> for additional introductory
17 Aggregate functions that support <em class="firstterm">Partial Mode</em>
18 are eligible to participate in various optimizations, such as parallel
21 While all aggregates below accept an optional
22 <code class="literal">ORDER BY</code> clause (as outlined in <a class="xref" href="sql-expressions.html#SYNTAX-AGGREGATES" title="4.2.7. Aggregate Expressions">Section 4.2.7</a>), the clause has only been added to
23 aggregates whose output is affected by ordering.
24 </p><div class="table" id="FUNCTIONS-AGGREGATE-TABLE"><p class="title"><strong>Table 9.62. General-Purpose Aggregate Functions</strong></p><div class="table-contents"><table class="table" summary="General-Purpose Aggregate Functions" border="1"><colgroup><col class="col1" /><col class="col2" /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
29 </p></th><th>Partial Mode</th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
30 <a id="id-1.5.8.27.6.2.4.1.1.1.1" class="indexterm"></a>
31 <code class="function">any_value</code> ( <code class="type">anyelement</code> )
32 → <code class="returnvalue"><em class="replaceable"><code>same as input type</code></em></code>
35 Returns an arbitrary value from the non-null input values.
36 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
37 <a id="id-1.5.8.27.6.2.4.2.1.1.1" class="indexterm"></a>
38 <code class="function">array_agg</code> ( <code class="type">anynonarray</code> <code class="literal">ORDER BY</code> <code class="literal">input_sort_columns</code> )
39 → <code class="returnvalue">anyarray</code>
42 Collects all the input values, including nulls, into an array.
43 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
44 <code class="function">array_agg</code> ( <code class="type">anyarray</code> <code class="literal">ORDER BY</code> <code class="literal">input_sort_columns</code> )
45 → <code class="returnvalue">anyarray</code>
48 Concatenates all the input arrays into an array of one higher
49 dimension. (The inputs must all have the same dimensionality, and
50 cannot be empty or null.)
51 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
52 <a id="id-1.5.8.27.6.2.4.4.1.1.1" class="indexterm"></a>
53 <a id="id-1.5.8.27.6.2.4.4.1.1.2" class="indexterm"></a>
54 <code class="function">avg</code> ( <code class="type">smallint</code> )
55 → <code class="returnvalue">numeric</code>
57 <p class="func_signature">
58 <code class="function">avg</code> ( <code class="type">integer</code> )
59 → <code class="returnvalue">numeric</code>
61 <p class="func_signature">
62 <code class="function">avg</code> ( <code class="type">bigint</code> )
63 → <code class="returnvalue">numeric</code>
65 <p class="func_signature">
66 <code class="function">avg</code> ( <code class="type">numeric</code> )
67 → <code class="returnvalue">numeric</code>
69 <p class="func_signature">
70 <code class="function">avg</code> ( <code class="type">real</code> )
71 → <code class="returnvalue">double precision</code>
73 <p class="func_signature">
74 <code class="function">avg</code> ( <code class="type">double precision</code> )
75 → <code class="returnvalue">double precision</code>
77 <p class="func_signature">
78 <code class="function">avg</code> ( <code class="type">interval</code> )
79 → <code class="returnvalue">interval</code>
82 Computes the average (arithmetic mean) of all the non-null input
84 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
85 <a id="id-1.5.8.27.6.2.4.5.1.1.1" class="indexterm"></a>
86 <code class="function">bit_and</code> ( <code class="type">smallint</code> )
87 → <code class="returnvalue">smallint</code>
89 <p class="func_signature">
90 <code class="function">bit_and</code> ( <code class="type">integer</code> )
91 → <code class="returnvalue">integer</code>
93 <p class="func_signature">
94 <code class="function">bit_and</code> ( <code class="type">bigint</code> )
95 → <code class="returnvalue">bigint</code>
97 <p class="func_signature">
98 <code class="function">bit_and</code> ( <code class="type">bit</code> )
99 → <code class="returnvalue">bit</code>
102 Computes the bitwise AND of all non-null input values.
103 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
104 <a id="id-1.5.8.27.6.2.4.6.1.1.1" class="indexterm"></a>
105 <code class="function">bit_or</code> ( <code class="type">smallint</code> )
106 → <code class="returnvalue">smallint</code>
108 <p class="func_signature">
109 <code class="function">bit_or</code> ( <code class="type">integer</code> )
110 → <code class="returnvalue">integer</code>
112 <p class="func_signature">
113 <code class="function">bit_or</code> ( <code class="type">bigint</code> )
114 → <code class="returnvalue">bigint</code>
116 <p class="func_signature">
117 <code class="function">bit_or</code> ( <code class="type">bit</code> )
118 → <code class="returnvalue">bit</code>
121 Computes the bitwise OR of all non-null input values.
122 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
123 <a id="id-1.5.8.27.6.2.4.7.1.1.1" class="indexterm"></a>
124 <code class="function">bit_xor</code> ( <code class="type">smallint</code> )
125 → <code class="returnvalue">smallint</code>
127 <p class="func_signature">
128 <code class="function">bit_xor</code> ( <code class="type">integer</code> )
129 → <code class="returnvalue">integer</code>
131 <p class="func_signature">
132 <code class="function">bit_xor</code> ( <code class="type">bigint</code> )
133 → <code class="returnvalue">bigint</code>
135 <p class="func_signature">
136 <code class="function">bit_xor</code> ( <code class="type">bit</code> )
137 → <code class="returnvalue">bit</code>
140 Computes the bitwise exclusive OR of all non-null input values.
141 Can be useful as a checksum for an unordered set of values.
142 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
143 <a id="id-1.5.8.27.6.2.4.8.1.1.1" class="indexterm"></a>
144 <code class="function">bool_and</code> ( <code class="type">boolean</code> )
145 → <code class="returnvalue">boolean</code>
148 Returns true if all non-null input values are true, otherwise false.
149 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
150 <a id="id-1.5.8.27.6.2.4.9.1.1.1" class="indexterm"></a>
151 <code class="function">bool_or</code> ( <code class="type">boolean</code> )
152 → <code class="returnvalue">boolean</code>
155 Returns true if any non-null input value is true, otherwise false.
156 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
157 <a id="id-1.5.8.27.6.2.4.10.1.1.1" class="indexterm"></a>
158 <code class="function">count</code> ( <code class="literal">*</code> )
159 → <code class="returnvalue">bigint</code>
162 Computes the number of input rows.
163 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
164 <code class="function">count</code> ( <code class="type">"any"</code> )
165 → <code class="returnvalue">bigint</code>
168 Computes the number of input rows in which the input value is not
170 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
171 <a id="id-1.5.8.27.6.2.4.12.1.1.1" class="indexterm"></a>
172 <code class="function">every</code> ( <code class="type">boolean</code> )
173 → <code class="returnvalue">boolean</code>
176 This is the SQL standard's equivalent to <code class="function">bool_and</code>.
177 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
178 <a id="id-1.5.8.27.6.2.4.13.1.1.1" class="indexterm"></a>
179 <code class="function">json_agg</code> ( <code class="type">anyelement</code> <code class="literal">ORDER BY</code> <code class="literal">input_sort_columns</code> )
180 → <code class="returnvalue">json</code>
182 <p class="func_signature">
183 <a id="id-1.5.8.27.6.2.4.13.1.2.1" class="indexterm"></a>
184 <code class="function">jsonb_agg</code> ( <code class="type">anyelement</code> <code class="literal">ORDER BY</code> <code class="literal">input_sort_columns</code> )
185 → <code class="returnvalue">jsonb</code>
188 Collects all the input values, including nulls, into a JSON array.
189 Values are converted to JSON as per <code class="function">to_json</code>
190 or <code class="function">to_jsonb</code>.
191 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
192 <a id="id-1.5.8.27.6.2.4.14.1.1.1" class="indexterm"></a>
193 <code class="function">json_agg_strict</code> ( <code class="type">anyelement</code> )
194 → <code class="returnvalue">json</code>
196 <p class="func_signature">
197 <a id="id-1.5.8.27.6.2.4.14.1.2.1" class="indexterm"></a>
198 <code class="function">jsonb_agg_strict</code> ( <code class="type">anyelement</code> )
199 → <code class="returnvalue">jsonb</code>
202 Collects all the input values, skipping nulls, into a JSON array.
203 Values are converted to JSON as per <code class="function">to_json</code>
204 or <code class="function">to_jsonb</code>.
205 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
206 <a id="id-1.5.8.27.6.2.4.15.1.1.1" class="indexterm"></a>
207 <code class="function">json_arrayagg</code> (
208 [<span class="optional"> <em class="replaceable"><code>value_expression</code></em> </span>]
209 [<span class="optional"> <code class="literal">ORDER BY</code> <em class="replaceable"><code>sort_expression</code></em> </span>]
210 [<span class="optional"> { <code class="literal">NULL</code> | <code class="literal">ABSENT</code> } <code class="literal">ON NULL</code> </span>]
211 [<span class="optional"> <code class="literal">RETURNING</code> <em class="replaceable"><code>data_type</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>] </span>] </span>])
214 Behaves in the same way as <code class="function">json_array</code>
215 but as an aggregate function so it only takes one
216 <em class="replaceable"><code>value_expression</code></em> parameter.
217 If <code class="literal">ABSENT ON NULL</code> is specified, any NULL
219 If <code class="literal">ORDER BY</code> is specified, the elements will
220 appear in the array in that order rather than in the input order.
223 <code class="literal">SELECT json_arrayagg(v) FROM (VALUES(2),(1)) t(v)</code>
224 → <code class="returnvalue">[2, 1]</code>
225 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
226 <a id="id-1.5.8.27.6.2.4.16.1.1.1" class="indexterm"></a>
227 <code class="function">json_objectagg</code> (
228 [<span class="optional"> { <em class="replaceable"><code>key_expression</code></em> { <code class="literal">VALUE</code> | ':' } <em class="replaceable"><code>value_expression</code></em> } </span>]
229 [<span class="optional"> { <code class="literal">NULL</code> | <code class="literal">ABSENT</code> } <code class="literal">ON NULL</code> </span>]
230 [<span class="optional"> { <code class="literal">WITH</code> | <code class="literal">WITHOUT</code> } <code class="literal">UNIQUE</code> [<span class="optional"> <code class="literal">KEYS</code> </span>] </span>]
231 [<span class="optional"> <code class="literal">RETURNING</code> <em class="replaceable"><code>data_type</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>] </span>] </span>])
234 Behaves like <code class="function">json_object</code>, but as an
235 aggregate function, so it only takes one
236 <em class="replaceable"><code>key_expression</code></em> and one
237 <em class="replaceable"><code>value_expression</code></em> parameter.
240 <code class="literal">SELECT json_objectagg(k:v) FROM (VALUES ('a'::text,current_date),('b',current_date + 1)) AS t(k,v)</code>
241 → <code class="returnvalue">{ "a" : "2022-05-10", "b" : "2022-05-11" }</code>
242 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
243 <a id="id-1.5.8.27.6.2.4.17.1.1.1" class="indexterm"></a>
244 <code class="function">json_object_agg</code> ( <em class="parameter"><code>key</code></em>
245 <code class="type">"any"</code>, <em class="parameter"><code>value</code></em>
246 <code class="type">"any"</code>
247 <code class="literal">ORDER BY</code> <code class="literal">input_sort_columns</code> )
248 → <code class="returnvalue">json</code>
250 <p class="func_signature">
251 <a id="id-1.5.8.27.6.2.4.17.1.2.1" class="indexterm"></a>
252 <code class="function">jsonb_object_agg</code> ( <em class="parameter"><code>key</code></em>
253 <code class="type">"any"</code>, <em class="parameter"><code>value</code></em>
254 <code class="type">"any"</code>
255 <code class="literal">ORDER BY</code> <code class="literal">input_sort_columns</code> )
256 → <code class="returnvalue">jsonb</code>
259 Collects all the key/value pairs into a JSON object. Key arguments
260 are coerced to text; value arguments are converted as per
261 <code class="function">to_json</code> or <code class="function">to_jsonb</code>.
262 Values can be null, but keys cannot.
263 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
264 <a id="id-1.5.8.27.6.2.4.18.1.1.1" class="indexterm"></a>
265 <code class="function">json_object_agg_strict</code> (
266 <em class="parameter"><code>key</code></em> <code class="type">"any"</code>,
267 <em class="parameter"><code>value</code></em> <code class="type">"any"</code> )
268 → <code class="returnvalue">json</code>
270 <p class="func_signature">
271 <a id="id-1.5.8.27.6.2.4.18.1.2.1" class="indexterm"></a>
272 <code class="function">jsonb_object_agg_strict</code> (
273 <em class="parameter"><code>key</code></em> <code class="type">"any"</code>,
274 <em class="parameter"><code>value</code></em> <code class="type">"any"</code> )
275 → <code class="returnvalue">jsonb</code>
278 Collects all the key/value pairs into a JSON object. Key arguments
279 are coerced to text; value arguments are converted as per
280 <code class="function">to_json</code> or <code class="function">to_jsonb</code>.
281 The <em class="parameter"><code>key</code></em> can not be null. If the
282 <em class="parameter"><code>value</code></em> is null then the entry is skipped,
283 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
284 <a id="id-1.5.8.27.6.2.4.19.1.1.1" class="indexterm"></a>
285 <code class="function">json_object_agg_unique</code> (
286 <em class="parameter"><code>key</code></em> <code class="type">"any"</code>,
287 <em class="parameter"><code>value</code></em> <code class="type">"any"</code> )
288 → <code class="returnvalue">json</code>
290 <p class="func_signature">
291 <a id="id-1.5.8.27.6.2.4.19.1.2.1" class="indexterm"></a>
292 <code class="function">jsonb_object_agg_unique</code> (
293 <em class="parameter"><code>key</code></em> <code class="type">"any"</code>,
294 <em class="parameter"><code>value</code></em> <code class="type">"any"</code> )
295 → <code class="returnvalue">jsonb</code>
298 Collects all the key/value pairs into a JSON object. Key arguments
299 are coerced to text; value arguments are converted as per
300 <code class="function">to_json</code> or <code class="function">to_jsonb</code>.
301 Values can be null, but keys cannot.
302 If there is a duplicate key an error is thrown.
303 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
304 <a id="id-1.5.8.27.6.2.4.20.1.1.1" class="indexterm"></a>
305 <code class="function">json_object_agg_unique_strict</code> (
306 <em class="parameter"><code>key</code></em> <code class="type">"any"</code>,
307 <em class="parameter"><code>value</code></em> <code class="type">"any"</code> )
308 → <code class="returnvalue">json</code>
310 <p class="func_signature">
311 <a id="id-1.5.8.27.6.2.4.20.1.2.1" class="indexterm"></a>
312 <code class="function">jsonb_object_agg_unique_strict</code> (
313 <em class="parameter"><code>key</code></em> <code class="type">"any"</code>,
314 <em class="parameter"><code>value</code></em> <code class="type">"any"</code> )
315 → <code class="returnvalue">jsonb</code>
318 Collects all the key/value pairs into a JSON object. Key arguments
319 are coerced to text; value arguments are converted as per
320 <code class="function">to_json</code> or <code class="function">to_jsonb</code>.
321 The <em class="parameter"><code>key</code></em> can not be null. If the
322 <em class="parameter"><code>value</code></em> is null then the entry is skipped.
323 If there is a duplicate key an error is thrown.
324 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
325 <a id="id-1.5.8.27.6.2.4.21.1.1.1" class="indexterm"></a>
326 <code class="function">max</code> ( <em class="replaceable"><code>see text</code></em> )
327 → <code class="returnvalue"><em class="replaceable"><code>same as input type</code></em></code>
330 Computes the maximum of the non-null input
331 values. Available for any numeric, string, date/time, or enum type,
332 as well as <code class="type">bytea</code>, <code class="type">inet</code>, <code class="type">interval</code>,
333 <code class="type">money</code>, <code class="type">oid</code>, <code class="type">pg_lsn</code>,
334 <code class="type">tid</code>, <code class="type">xid8</code>,
335 and also arrays and composite types containing sortable data types.
336 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
337 <a id="id-1.5.8.27.6.2.4.22.1.1.1" class="indexterm"></a>
338 <code class="function">min</code> ( <em class="replaceable"><code>see text</code></em> )
339 → <code class="returnvalue"><em class="replaceable"><code>same as input type</code></em></code>
342 Computes the minimum of the non-null input
343 values. Available for any numeric, string, date/time, or enum type,
344 as well as <code class="type">bytea</code>, <code class="type">inet</code>, <code class="type">interval</code>,
345 <code class="type">money</code>, <code class="type">oid</code>, <code class="type">pg_lsn</code>,
346 <code class="type">tid</code>, <code class="type">xid8</code>,
347 and also arrays and composite types containing sortable data types.
348 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
349 <a id="id-1.5.8.27.6.2.4.23.1.1.1" class="indexterm"></a>
350 <code class="function">range_agg</code> ( <em class="parameter"><code>value</code></em>
351 <code class="type">anyrange</code> )
352 → <code class="returnvalue">anymultirange</code>
354 <p class="func_signature">
355 <code class="function">range_agg</code> ( <em class="parameter"><code>value</code></em>
356 <code class="type">anymultirange</code> )
357 → <code class="returnvalue">anymultirange</code>
360 Computes the union of the non-null input values.
361 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
362 <a id="id-1.5.8.27.6.2.4.24.1.1.1" class="indexterm"></a>
363 <code class="function">range_intersect_agg</code> ( <em class="parameter"><code>value</code></em>
364 <code class="type">anyrange</code> )
365 → <code class="returnvalue">anyrange</code>
367 <p class="func_signature">
368 <code class="function">range_intersect_agg</code> ( <em class="parameter"><code>value</code></em>
369 <code class="type">anymultirange</code> )
370 → <code class="returnvalue">anymultirange</code>
373 Computes the intersection of the non-null input values.
374 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
375 <a id="id-1.5.8.27.6.2.4.25.1.1.1" class="indexterm"></a>
376 <code class="function">string_agg</code> ( <em class="parameter"><code>value</code></em>
377 <code class="type">text</code>, <em class="parameter"><code>delimiter</code></em> <code class="type">text</code> )
378 → <code class="returnvalue">text</code>
380 <p class="func_signature">
381 <code class="function">string_agg</code> ( <em class="parameter"><code>value</code></em>
382 <code class="type">bytea</code>, <em class="parameter"><code>delimiter</code></em> <code class="type">bytea</code>
383 <code class="literal">ORDER BY</code> <code class="literal">input_sort_columns</code> )
384 → <code class="returnvalue">bytea</code>
387 Concatenates the non-null input values into a string. Each value
388 after the first is preceded by the
389 corresponding <em class="parameter"><code>delimiter</code></em> (if it's not null).
390 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
391 <a id="id-1.5.8.27.6.2.4.26.1.1.1" class="indexterm"></a>
392 <code class="function">sum</code> ( <code class="type">smallint</code> )
393 → <code class="returnvalue">bigint</code>
395 <p class="func_signature">
396 <code class="function">sum</code> ( <code class="type">integer</code> )
397 → <code class="returnvalue">bigint</code>
399 <p class="func_signature">
400 <code class="function">sum</code> ( <code class="type">bigint</code> )
401 → <code class="returnvalue">numeric</code>
403 <p class="func_signature">
404 <code class="function">sum</code> ( <code class="type">numeric</code> )
405 → <code class="returnvalue">numeric</code>
407 <p class="func_signature">
408 <code class="function">sum</code> ( <code class="type">real</code> )
409 → <code class="returnvalue">real</code>
411 <p class="func_signature">
412 <code class="function">sum</code> ( <code class="type">double precision</code> )
413 → <code class="returnvalue">double precision</code>
415 <p class="func_signature">
416 <code class="function">sum</code> ( <code class="type">interval</code> )
417 → <code class="returnvalue">interval</code>
419 <p class="func_signature">
420 <code class="function">sum</code> ( <code class="type">money</code> )
421 → <code class="returnvalue">money</code>
424 Computes the sum of the non-null input values.
425 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
426 <a id="id-1.5.8.27.6.2.4.27.1.1.1" class="indexterm"></a>
427 <code class="function">xmlagg</code> ( <code class="type">xml</code> <code class="literal">ORDER BY</code> <code class="literal">input_sort_columns</code> )
428 → <code class="returnvalue">xml</code>
431 Concatenates the non-null XML input values (see
432 <a class="xref" href="functions-xml.html#FUNCTIONS-XML-XMLAGG" title="9.15.1.8. xmlagg">Section 9.15.1.8</a>).
433 </p></td><td>No</td></tr></tbody></table></div></div><br class="table-break" /><p>
434 It should be noted that except for <code class="function">count</code>,
435 these functions return a null value when no rows are selected. In
436 particular, <code class="function">sum</code> of no rows returns null, not
437 zero as one might expect, and <code class="function">array_agg</code>
438 returns null rather than an empty array when there are no input
439 rows. The <code class="function">coalesce</code> function can be used to
440 substitute zero or an empty array for null when necessary.
442 The aggregate functions <code class="function">array_agg</code>,
443 <code class="function">json_agg</code>, <code class="function">jsonb_agg</code>,
444 <code class="function">json_agg_strict</code>, <code class="function">jsonb_agg_strict</code>,
445 <code class="function">json_object_agg</code>, <code class="function">jsonb_object_agg</code>,
446 <code class="function">json_object_agg_strict</code>, <code class="function">jsonb_object_agg_strict</code>,
447 <code class="function">json_object_agg_unique</code>, <code class="function">jsonb_object_agg_unique</code>,
448 <code class="function">json_object_agg_unique_strict</code>,
449 <code class="function">jsonb_object_agg_unique_strict</code>,
450 <code class="function">string_agg</code>,
451 and <code class="function">xmlagg</code>, as well as similar user-defined
452 aggregate functions, produce meaningfully different result values
453 depending on the order of the input values. This ordering is
454 unspecified by default, but can be controlled by writing an
455 <code class="literal">ORDER BY</code> clause within the aggregate call, as shown in
456 <a class="xref" href="sql-expressions.html#SYNTAX-AGGREGATES" title="4.2.7. Aggregate Expressions">Section 4.2.7</a>.
457 Alternatively, supplying the input values from a sorted subquery
458 will usually work. For example:
460 </p><pre class="screen">
461 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
464 Beware that this approach can fail if the outer query level contains
465 additional processing, such as a join, because that might cause the
466 subquery's output to be reordered before the aggregate is computed.
467 </p><div class="note"><h3 class="title">Note</h3><a id="id-1.5.8.27.9.1" class="indexterm"></a><a id="id-1.5.8.27.9.2" class="indexterm"></a><p>
468 The boolean aggregates <code class="function">bool_and</code> and
469 <code class="function">bool_or</code> correspond to the standard SQL aggregates
470 <code class="function">every</code> and <code class="function">any</code> or
471 <code class="function">some</code>.
472 <span class="productname">PostgreSQL</span>
473 supports <code class="function">every</code>, but not <code class="function">any</code>
474 or <code class="function">some</code>, because there is an ambiguity built into
476 </p><pre class="programlisting">
477 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
479 Here <code class="function">ANY</code> can be considered either as introducing
480 a subquery, or as being an aggregate function, if the subquery
481 returns one row with a Boolean value.
482 Thus the standard name cannot be given to these aggregates.
483 </p></div><div class="note"><h3 class="title">Note</h3><p>
484 Users accustomed to working with other SQL database management
485 systems might be disappointed by the performance of the
486 <code class="function">count</code> aggregate when it is applied to the
487 entire table. A query like:
488 </p><pre class="programlisting">
489 SELECT count(*) FROM sometable;
491 will require effort proportional to the size of the table:
492 <span class="productname">PostgreSQL</span> will need to scan either the
493 entire table or the entirety of an index that includes all rows in
496 <a class="xref" href="functions-aggregate.html#FUNCTIONS-AGGREGATE-STATISTICS-TABLE" title="Table 9.63. Aggregate Functions for Statistics">Table 9.63</a> shows
497 aggregate functions typically used in statistical analysis.
498 (These are separated out merely to avoid cluttering the listing
499 of more-commonly-used aggregates.) Functions shown as
500 accepting <em class="replaceable"><code>numeric_type</code></em> are available for all
501 the types <code class="type">smallint</code>, <code class="type">integer</code>,
502 <code class="type">bigint</code>, <code class="type">numeric</code>, <code class="type">real</code>,
503 and <code class="type">double precision</code>.
504 Where the description mentions
505 <em class="parameter"><code>N</code></em>, it means the
506 number of input rows for which all the input expressions are non-null.
507 In all cases, null is returned if the computation is meaningless,
508 for example when <em class="parameter"><code>N</code></em> is zero.
509 </p><a id="id-1.5.8.27.12" class="indexterm"></a><a id="id-1.5.8.27.13" class="indexterm"></a><div class="table" id="FUNCTIONS-AGGREGATE-STATISTICS-TABLE"><p class="title"><strong>Table 9.63. Aggregate Functions for Statistics</strong></p><div class="table-contents"><table class="table" summary="Aggregate Functions for Statistics" border="1"><colgroup><col class="col1" /><col class="col2" /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
514 </p></th><th>Partial Mode</th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
515 <a id="id-1.5.8.27.14.2.4.1.1.1.1" class="indexterm"></a>
516 <a id="id-1.5.8.27.14.2.4.1.1.1.2" class="indexterm"></a>
517 <code class="function">corr</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
518 → <code class="returnvalue">double precision</code>
521 Computes the correlation coefficient.
522 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
523 <a id="id-1.5.8.27.14.2.4.2.1.1.1" class="indexterm"></a>
524 <a id="id-1.5.8.27.14.2.4.2.1.1.2" class="indexterm"></a>
525 <code class="function">covar_pop</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
526 → <code class="returnvalue">double precision</code>
529 Computes the population covariance.
530 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
531 <a id="id-1.5.8.27.14.2.4.3.1.1.1" class="indexterm"></a>
532 <a id="id-1.5.8.27.14.2.4.3.1.1.2" class="indexterm"></a>
533 <code class="function">covar_samp</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
534 → <code class="returnvalue">double precision</code>
537 Computes the sample covariance.
538 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
539 <a id="id-1.5.8.27.14.2.4.4.1.1.1" class="indexterm"></a>
540 <code class="function">regr_avgx</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
541 → <code class="returnvalue">double precision</code>
544 Computes the average of the independent variable,
545 <code class="literal">sum(<em class="parameter"><code>X</code></em>)/<em class="parameter"><code>N</code></em></code>.
546 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
547 <a id="id-1.5.8.27.14.2.4.5.1.1.1" class="indexterm"></a>
548 <code class="function">regr_avgy</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
549 → <code class="returnvalue">double precision</code>
552 Computes the average of the dependent variable,
553 <code class="literal">sum(<em class="parameter"><code>Y</code></em>)/<em class="parameter"><code>N</code></em></code>.
554 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
555 <a id="id-1.5.8.27.14.2.4.6.1.1.1" class="indexterm"></a>
556 <code class="function">regr_count</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
557 → <code class="returnvalue">bigint</code>
560 Computes the number of rows in which both inputs are non-null.
561 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
562 <a id="id-1.5.8.27.14.2.4.7.1.1.1" class="indexterm"></a>
563 <a id="id-1.5.8.27.14.2.4.7.1.1.2" class="indexterm"></a>
564 <code class="function">regr_intercept</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
565 → <code class="returnvalue">double precision</code>
568 Computes the y-intercept of the least-squares-fit linear equation
570 (<em class="parameter"><code>X</code></em>, <em class="parameter"><code>Y</code></em>) pairs.
571 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
572 <a id="id-1.5.8.27.14.2.4.8.1.1.1" class="indexterm"></a>
573 <code class="function">regr_r2</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
574 → <code class="returnvalue">double precision</code>
577 Computes the square of the correlation coefficient.
578 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
579 <a id="id-1.5.8.27.14.2.4.9.1.1.1" class="indexterm"></a>
580 <a id="id-1.5.8.27.14.2.4.9.1.1.2" class="indexterm"></a>
581 <code class="function">regr_slope</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
582 → <code class="returnvalue">double precision</code>
585 Computes the slope of the least-squares-fit linear equation determined
586 by the (<em class="parameter"><code>X</code></em>, <em class="parameter"><code>Y</code></em>)
588 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
589 <a id="id-1.5.8.27.14.2.4.10.1.1.1" class="indexterm"></a>
590 <code class="function">regr_sxx</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
591 → <code class="returnvalue">double precision</code>
594 Computes the <span class="quote">“<span class="quote">sum of squares</span>”</span> of the independent
596 <code class="literal">sum(<em class="parameter"><code>X</code></em>^2) - sum(<em class="parameter"><code>X</code></em>)^2/<em class="parameter"><code>N</code></em></code>.
597 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
598 <a id="id-1.5.8.27.14.2.4.11.1.1.1" class="indexterm"></a>
599 <code class="function">regr_sxy</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
600 → <code class="returnvalue">double precision</code>
603 Computes the <span class="quote">“<span class="quote">sum of products</span>”</span> of independent times
605 <code class="literal">sum(<em class="parameter"><code>X</code></em>*<em class="parameter"><code>Y</code></em>) - sum(<em class="parameter"><code>X</code></em>) * sum(<em class="parameter"><code>Y</code></em>)/<em class="parameter"><code>N</code></em></code>.
606 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
607 <a id="id-1.5.8.27.14.2.4.12.1.1.1" class="indexterm"></a>
608 <code class="function">regr_syy</code> ( <em class="parameter"><code>Y</code></em> <code class="type">double precision</code>, <em class="parameter"><code>X</code></em> <code class="type">double precision</code> )
609 → <code class="returnvalue">double precision</code>
612 Computes the <span class="quote">“<span class="quote">sum of squares</span>”</span> of the dependent
614 <code class="literal">sum(<em class="parameter"><code>Y</code></em>^2) - sum(<em class="parameter"><code>Y</code></em>)^2/<em class="parameter"><code>N</code></em></code>.
615 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
616 <a id="id-1.5.8.27.14.2.4.13.1.1.1" class="indexterm"></a>
617 <a id="id-1.5.8.27.14.2.4.13.1.1.2" class="indexterm"></a>
618 <code class="function">stddev</code> ( <em class="replaceable"><code>numeric_type</code></em> )
619 → <code class="returnvalue"></code> <code class="type">double precision</code>
620 for <code class="type">real</code> or <code class="type">double precision</code>,
621 otherwise <code class="type">numeric</code>
624 This is a historical alias for <code class="function">stddev_samp</code>.
625 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
626 <a id="id-1.5.8.27.14.2.4.14.1.1.1" class="indexterm"></a>
627 <a id="id-1.5.8.27.14.2.4.14.1.1.2" class="indexterm"></a>
628 <code class="function">stddev_pop</code> ( <em class="replaceable"><code>numeric_type</code></em> )
629 → <code class="returnvalue"></code> <code class="type">double precision</code>
630 for <code class="type">real</code> or <code class="type">double precision</code>,
631 otherwise <code class="type">numeric</code>
634 Computes the population standard deviation of the input values.
635 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
636 <a id="id-1.5.8.27.14.2.4.15.1.1.1" class="indexterm"></a>
637 <a id="id-1.5.8.27.14.2.4.15.1.1.2" class="indexterm"></a>
638 <code class="function">stddev_samp</code> ( <em class="replaceable"><code>numeric_type</code></em> )
639 → <code class="returnvalue"></code> <code class="type">double precision</code>
640 for <code class="type">real</code> or <code class="type">double precision</code>,
641 otherwise <code class="type">numeric</code>
644 Computes the sample standard deviation of the input values.
645 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
646 <a id="id-1.5.8.27.14.2.4.16.1.1.1" class="indexterm"></a>
647 <code class="function">variance</code> ( <em class="replaceable"><code>numeric_type</code></em> )
648 → <code class="returnvalue"></code> <code class="type">double precision</code>
649 for <code class="type">real</code> or <code class="type">double precision</code>,
650 otherwise <code class="type">numeric</code>
653 This is a historical alias for <code class="function">var_samp</code>.
654 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
655 <a id="id-1.5.8.27.14.2.4.17.1.1.1" class="indexterm"></a>
656 <a id="id-1.5.8.27.14.2.4.17.1.1.2" class="indexterm"></a>
657 <code class="function">var_pop</code> ( <em class="replaceable"><code>numeric_type</code></em> )
658 → <code class="returnvalue"></code> <code class="type">double precision</code>
659 for <code class="type">real</code> or <code class="type">double precision</code>,
660 otherwise <code class="type">numeric</code>
663 Computes the population variance of the input values (square of the
664 population standard deviation).
665 </p></td><td>Yes</td></tr><tr><td class="func_table_entry"><p class="func_signature">
666 <a id="id-1.5.8.27.14.2.4.18.1.1.1" class="indexterm"></a>
667 <a id="id-1.5.8.27.14.2.4.18.1.1.2" class="indexterm"></a>
668 <code class="function">var_samp</code> ( <em class="replaceable"><code>numeric_type</code></em> )
669 → <code class="returnvalue"></code> <code class="type">double precision</code>
670 for <code class="type">real</code> or <code class="type">double precision</code>,
671 otherwise <code class="type">numeric</code>
674 Computes the sample variance of the input values (square of the sample
676 </p></td><td>Yes</td></tr></tbody></table></div></div><br class="table-break" /><p>
677 <a class="xref" href="functions-aggregate.html#FUNCTIONS-ORDEREDSET-TABLE" title="Table 9.64. Ordered-Set Aggregate Functions">Table 9.64</a> shows some
678 aggregate functions that use the <em class="firstterm">ordered-set aggregate</em>
679 syntax. These functions are sometimes referred to as <span class="quote">“<span class="quote">inverse
680 distribution</span>”</span> functions. Their aggregated input is introduced by
681 <code class="literal">ORDER BY</code>, and they may also take a <em class="firstterm">direct
682 argument</em> that is not aggregated, but is computed only once.
683 All these functions ignore null values in their aggregated input.
684 For those that take a <em class="parameter"><code>fraction</code></em> parameter, the
685 fraction value must be between 0 and 1; an error is thrown if not.
686 However, a null <em class="parameter"><code>fraction</code></em> value simply produces a
688 </p><a id="id-1.5.8.27.16" class="indexterm"></a><a id="id-1.5.8.27.17" class="indexterm"></a><div class="table" id="FUNCTIONS-ORDEREDSET-TABLE"><p class="title"><strong>Table 9.64. Ordered-Set Aggregate Functions</strong></p><div class="table-contents"><table class="table" summary="Ordered-Set Aggregate Functions" border="1"><colgroup><col class="col1" /><col class="col2" /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
693 </p></th><th>Partial Mode</th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
694 <a id="id-1.5.8.27.18.2.4.1.1.1.1" class="indexterm"></a>
695 <code class="function">mode</code> () <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <code class="type">anyelement</code> )
696 → <code class="returnvalue">anyelement</code>
699 Computes the <em class="firstterm">mode</em>, the most frequent
700 value of the aggregated argument (arbitrarily choosing the first one
701 if there are multiple equally-frequent values). The aggregated
702 argument must be of a sortable type.
703 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
704 <a id="id-1.5.8.27.18.2.4.2.1.1.1" class="indexterm"></a>
705 <code class="function">percentile_cont</code> ( <em class="parameter"><code>fraction</code></em> <code class="type">double precision</code> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <code class="type">double precision</code> )
706 → <code class="returnvalue">double precision</code>
708 <p class="func_signature">
709 <code class="function">percentile_cont</code> ( <em class="parameter"><code>fraction</code></em> <code class="type">double precision</code> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <code class="type">interval</code> )
710 → <code class="returnvalue">interval</code>
713 Computes the <em class="firstterm">continuous percentile</em>, a value
714 corresponding to the specified <em class="parameter"><code>fraction</code></em>
715 within the ordered set of aggregated argument values. This will
716 interpolate between adjacent input items if needed.
717 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
718 <code class="function">percentile_cont</code> ( <em class="parameter"><code>fractions</code></em> <code class="type">double precision[]</code> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <code class="type">double precision</code> )
719 → <code class="returnvalue">double precision[]</code>
721 <p class="func_signature">
722 <code class="function">percentile_cont</code> ( <em class="parameter"><code>fractions</code></em> <code class="type">double precision[]</code> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <code class="type">interval</code> )
723 → <code class="returnvalue">interval[]</code>
726 Computes multiple continuous percentiles. The result is an array of
727 the same dimensions as the <em class="parameter"><code>fractions</code></em>
728 parameter, with each non-null element replaced by the (possibly
729 interpolated) value corresponding to that percentile.
730 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
731 <a id="id-1.5.8.27.18.2.4.4.1.1.1" class="indexterm"></a>
732 <code class="function">percentile_disc</code> ( <em class="parameter"><code>fraction</code></em> <code class="type">double precision</code> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <code class="type">anyelement</code> )
733 → <code class="returnvalue">anyelement</code>
736 Computes the <em class="firstterm">discrete percentile</em>, the first
737 value within the ordered set of aggregated argument values whose
738 position in the ordering equals or exceeds the
739 specified <em class="parameter"><code>fraction</code></em>. The aggregated
740 argument must be of a sortable type.
741 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
742 <code class="function">percentile_disc</code> ( <em class="parameter"><code>fractions</code></em> <code class="type">double precision[]</code> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <code class="type">anyelement</code> )
743 → <code class="returnvalue">anyarray</code>
746 Computes multiple discrete percentiles. The result is an array of the
747 same dimensions as the <em class="parameter"><code>fractions</code></em> parameter,
748 with each non-null element replaced by the input value corresponding
750 The aggregated argument must be of a sortable type.
751 </p></td><td>No</td></tr></tbody></table></div></div><br class="table-break" /><a id="id-1.5.8.27.19" class="indexterm"></a><p>
752 Each of the <span class="quote">“<span class="quote">hypothetical-set</span>”</span> aggregates listed in
753 <a class="xref" href="functions-aggregate.html#FUNCTIONS-HYPOTHETICAL-TABLE" title="Table 9.65. Hypothetical-Set Aggregate Functions">Table 9.65</a> is associated with a
754 window function of the same name defined in
755 <a class="xref" href="functions-window.html" title="9.22. Window Functions">Section 9.22</a>. In each case, the aggregate's result
756 is the value that the associated window function would have
757 returned for the <span class="quote">“<span class="quote">hypothetical</span>”</span> row constructed from
758 <em class="replaceable"><code>args</code></em>, if such a row had been added to the sorted
759 group of rows represented by the <em class="replaceable"><code>sorted_args</code></em>.
760 For each of these functions, the list of direct arguments
761 given in <em class="replaceable"><code>args</code></em> must match the number and types of
762 the aggregated arguments given in <em class="replaceable"><code>sorted_args</code></em>.
763 Unlike most built-in aggregates, these aggregates are not strict, that is
764 they do not drop input rows containing nulls. Null values sort according
765 to the rule specified in the <code class="literal">ORDER BY</code> clause.
766 </p><div class="table" id="FUNCTIONS-HYPOTHETICAL-TABLE"><p class="title"><strong>Table 9.65. Hypothetical-Set Aggregate Functions</strong></p><div class="table-contents"><table class="table" summary="Hypothetical-Set Aggregate Functions" border="1"><colgroup><col class="col1" /><col class="col2" /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
771 </p></th><th>Partial Mode</th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
772 <a id="id-1.5.8.27.21.2.4.1.1.1.1" class="indexterm"></a>
773 <code class="function">rank</code> ( <em class="replaceable"><code>args</code></em> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <em class="replaceable"><code>sorted_args</code></em> )
774 → <code class="returnvalue">bigint</code>
777 Computes the rank of the hypothetical row, with gaps; that is, the row
778 number of the first row in its peer group.
779 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
780 <a id="id-1.5.8.27.21.2.4.2.1.1.1" class="indexterm"></a>
781 <code class="function">dense_rank</code> ( <em class="replaceable"><code>args</code></em> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <em class="replaceable"><code>sorted_args</code></em> )
782 → <code class="returnvalue">bigint</code>
785 Computes the rank of the hypothetical row, without gaps; this function
786 effectively counts peer groups.
787 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
788 <a id="id-1.5.8.27.21.2.4.3.1.1.1" class="indexterm"></a>
789 <code class="function">percent_rank</code> ( <em class="replaceable"><code>args</code></em> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <em class="replaceable"><code>sorted_args</code></em> )
790 → <code class="returnvalue">double precision</code>
793 Computes the relative rank of the hypothetical row, that is
794 (<code class="function">rank</code> - 1) / (total rows - 1).
795 The value thus ranges from 0 to 1 inclusive.
796 </p></td><td>No</td></tr><tr><td class="func_table_entry"><p class="func_signature">
797 <a id="id-1.5.8.27.21.2.4.4.1.1.1" class="indexterm"></a>
798 <code class="function">cume_dist</code> ( <em class="replaceable"><code>args</code></em> ) <code class="literal">WITHIN GROUP</code> ( <code class="literal">ORDER BY</code> <em class="replaceable"><code>sorted_args</code></em> )
799 → <code class="returnvalue">double precision</code>
802 Computes the cumulative distribution, that is (number of rows
803 preceding or peers with hypothetical row) / (total rows). The value
804 thus ranges from 1/<em class="parameter"><code>N</code></em> to 1.
805 </p></td><td>No</td></tr></tbody></table></div></div><br class="table-break" /><div class="table" id="FUNCTIONS-GROUPING-TABLE"><p class="title"><strong>Table 9.66. Grouping Operations</strong></p><div class="table-contents"><table class="table" summary="Grouping Operations" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
810 </p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
811 <a id="id-1.5.8.27.22.2.2.1.1.1.1" class="indexterm"></a>
812 <code class="function">GROUPING</code> ( <em class="replaceable"><code>group_by_expression(s)</code></em> )
813 → <code class="returnvalue">integer</code>
816 Returns a bit mask indicating which <code class="literal">GROUP BY</code>
817 expressions are not included in the current grouping set.
818 Bits are assigned with the rightmost argument corresponding to the
819 least-significant bit; each bit is 0 if the corresponding expression
820 is included in the grouping criteria of the grouping set generating
821 the current result row, and 1 if it is not included.
822 </p></td></tr></tbody></table></div></div><br class="table-break" /><p>
823 The grouping operations shown in
824 <a class="xref" href="functions-aggregate.html#FUNCTIONS-GROUPING-TABLE" title="Table 9.66. Grouping Operations">Table 9.66</a> are used in conjunction with
825 grouping sets (see <a class="xref" href="queries-table-expressions.html#QUERIES-GROUPING-SETS" title="7.2.4. GROUPING SETS, CUBE, and ROLLUP">Section 7.2.4</a>) to distinguish
826 result rows. The arguments to the <code class="literal">GROUPING</code> function
827 are not actually evaluated, but they must exactly match expressions given
828 in the <code class="literal">GROUP BY</code> clause of the associated query level.
830 </p><pre class="screen">
831 <code class="prompt">=></code> <strong class="userinput"><code>SELECT * FROM items_sold;</code></strong>
833 -------+-------+-------
840 <code class="prompt">=></code> <strong class="userinput"><code>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);</code></strong>
841 make | model | grouping | sum
842 -------+-------+----------+-----
852 Here, the <code class="literal">grouping</code> value <code class="literal">0</code> in the
853 first four rows shows that those have been grouped normally, over both the
854 grouping columns. The value <code class="literal">1</code> indicates
855 that <code class="literal">model</code> was not grouped by in the next-to-last two
856 rows, and the value <code class="literal">3</code> indicates that
857 neither <code class="literal">make</code> nor <code class="literal">model</code> was grouped
858 by in the last row (which therefore is an aggregate over all the input
860 </p></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="functions-range.html" title="9.20. Range/Multirange Functions and Operators">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="functions-window.html" title="9.22. Window Functions">Next</a></td></tr><tr><td width="40%" align="left" valign="top">9.20. Range/Multirange Functions and Operators </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"> 9.22. Window Functions</td></tr></table></div></body></html>