1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-30 11:03:19 +03:00

Implement the FILTER clause for aggregate function calls.

This is SQL-standard with a few extensions, namely support for
subqueries and outer references in clause expressions.

catversion bump due to change in Aggref and WindowFunc.

David Fetter, reviewed by Dean Rasheed.
This commit is contained in:
Noah Misch
2013-07-16 20:15:36 -04:00
parent 7a8e9f298e
commit b560ec1b0d
35 changed files with 403 additions and 51 deletions

View File

@ -1554,6 +1554,10 @@ sqrt(2)
<secondary>invocation</secondary>
</indexterm>
<indexterm zone="syntax-aggregates">
<primary>filter</primary>
</indexterm>
<para>
An <firstterm>aggregate expression</firstterm> represents the
application of an aggregate function across the rows selected by a
@ -1562,19 +1566,19 @@ sqrt(2)
syntax of an aggregate expression is one of the following:
<synopsis>
<replaceable>aggregate_name</replaceable> (<replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] )
<replaceable>aggregate_name</replaceable> (ALL <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] )
<replaceable>aggregate_name</replaceable> (DISTINCT <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] )
<replaceable>aggregate_name</replaceable> ( * )
<replaceable>aggregate_name</replaceable> (<replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
<replaceable>aggregate_name</replaceable> (ALL <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
<replaceable>aggregate_name</replaceable> (DISTINCT <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
<replaceable>aggregate_name</replaceable> ( * ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
</synopsis>
where <replaceable>aggregate_name</replaceable> is a previously
defined aggregate (possibly qualified with a schema name),
defined aggregate (possibly qualified with a schema name) and
<replaceable>expression</replaceable> is
any value expression that does not itself contain an aggregate
expression or a window function call, and
<replaceable>order_by_clause</replaceable> is a optional
<literal>ORDER BY</> clause as described below.
expression or a window function call. The optional
<replaceable>order_by_clause</replaceable> and
<replaceable>filter_clause</replaceable> are described below.
</para>
<para>
@ -1606,6 +1610,23 @@ sqrt(2)
distinct non-null values of <literal>f1</literal>.
</para>
<para>
If <literal>FILTER</literal> is specified, then only the input
rows for which the <replaceable>filter_clause</replaceable>
evaluates to true are fed to the aggregate function; other rows
are discarded. For example:
<programlisting>
SELECT
count(*) AS unfiltered,
count(*) FILTER (WHERE i < 5) AS filtered
FROM generate_series(1,10) AS s(i);
unfiltered | filtered
------------+----------
10 | 4
(1 row)
</programlisting>
</para>
<para>
Ordinarily, the input rows are fed to the aggregate function in an
unspecified order. In many cases this does not matter; for example,
@ -1709,10 +1730,10 @@ SELECT string_agg(a ORDER BY a, ',') FROM table; -- incorrect
The syntax of a window function call is one of the following:
<synopsis>
<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) OVER ( <replaceable class="parameter">window_definition</replaceable> )
<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) OVER <replaceable>window_name</replaceable>
<replaceable>function_name</replaceable> ( * ) OVER ( <replaceable class="parameter">window_definition</replaceable> )
<replaceable>function_name</replaceable> ( * ) OVER <replaceable>window_name</replaceable>
<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER ( <replaceable class="parameter">window_definition</replaceable> )
<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER <replaceable>window_name</replaceable>
<replaceable>function_name</replaceable> ( * ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER ( <replaceable class="parameter">window_definition</replaceable> )
<replaceable>function_name</replaceable> ( * ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER <replaceable>window_name</replaceable>
</synopsis>
where <replaceable class="parameter">window_definition</replaceable>
has the syntax
@ -1836,7 +1857,8 @@ UNBOUNDED FOLLOWING
The built-in window functions are described in <xref
linkend="functions-window-table">. Other window functions can be added by
the user. Also, any built-in or user-defined aggregate function can be
used as a window function.
used as a window function. Only aggregate window functions accept
a <literal>FILTER</literal> clause.
</para>
<para>