Skip to content

Commit 3293fa3

Browse files
author
Commitfest Bot
committed
[CF 5230] Add IGNORE NULLS to Window functions
This branch was automatically generated by a robot using patches from an email thread registered at: https://commitfest.postgresql.org/patch/5230 The branch will be overwritten each time a new patch version is posted to the thread, and also periodically to check for bitrot caused by changes on the master branch. Patch(es): https://www.postgresql.org/message-id/CAGMVOduuhBa5b9ZzsJ2EwQZKFJhtjx3j4xwmbvfNo8Oks63mZw@mail.gmail.com Author(s): Oliver Ford
2 parents fe29b2a + 7e8d366 commit 3293fa3

File tree

15 files changed

+773
-28
lines changed

15 files changed

+773
-28
lines changed

doc/src/sgml/func.sgml

Lines changed: 23 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -23533,7 +23533,7 @@ SELECT count(*) FROM sometable;
2353323533
</indexterm>
2353423534
<function>lag</function> ( <parameter>value</parameter> <type>anycompatible</type>
2353523535
<optional>, <parameter>offset</parameter> <type>integer</type>
23536-
<optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
23536+
<optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> ) <optional> <parameter>null treatment</parameter> </optional>
2353723537
<returnvalue>anycompatible</returnvalue>
2353823538
</para>
2353923539
<para>
@@ -23558,7 +23558,7 @@ SELECT count(*) FROM sometable;
2355823558
</indexterm>
2355923559
<function>lead</function> ( <parameter>value</parameter> <type>anycompatible</type>
2356023560
<optional>, <parameter>offset</parameter> <type>integer</type>
23561-
<optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
23561+
<optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> ) <optional> <parameter>null treatment</parameter> </optional>
2356223562
<returnvalue>anycompatible</returnvalue>
2356323563
</para>
2356423564
<para>
@@ -23581,7 +23581,7 @@ SELECT count(*) FROM sometable;
2358123581
<indexterm>
2358223582
<primary>first_value</primary>
2358323583
</indexterm>
23584-
<function>first_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
23584+
<function>first_value</function> ( <parameter>value</parameter> <type>anyelement</type> ) <optional> <parameter>null treatment</parameter> </optional>
2358523585
<returnvalue>anyelement</returnvalue>
2358623586
</para>
2358723587
<para>
@@ -23595,7 +23595,7 @@ SELECT count(*) FROM sometable;
2359523595
<indexterm>
2359623596
<primary>last_value</primary>
2359723597
</indexterm>
23598-
<function>last_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
23598+
<function>last_value</function> ( <parameter>value</parameter> <type>anyelement</type> ) <optional> <parameter>null treatment</parameter> </optional>
2359923599
<returnvalue>anyelement</returnvalue>
2360023600
</para>
2360123601
<para>
@@ -23609,7 +23609,7 @@ SELECT count(*) FROM sometable;
2360923609
<indexterm>
2361023610
<primary>nth_value</primary>
2361123611
</indexterm>
23612-
<function>nth_value</function> ( <parameter>value</parameter> <type>anyelement</type>, <parameter>n</parameter> <type>integer</type> )
23612+
<function>nth_value</function> ( <parameter>value</parameter> <type>anyelement</type>, <parameter>n</parameter> <type>integer</type> ) <optional> <parameter>null treatment</parameter> </optional>
2361323613
<returnvalue>anyelement</returnvalue>
2361423614
</para>
2361523615
<para>
@@ -23658,18 +23658,26 @@ SELECT count(*) FROM sometable;
2365823658
Other frame specifications can be used to obtain other effects.
2365923659
</para>
2366023660

23661+
<para>
23662+
The <literal>null treatment</literal> option must be one of:
23663+
<synopsis>
23664+
RESPECT NULLS
23665+
IGNORE NULLS
23666+
</synopsis>
23667+
If unspecified, the default is <literal>RESPECT NULLS</literal> which includes NULL
23668+
values in any result calculation. <literal>IGNORE NULLS</literal> ignores NULL values.
23669+
This option is only allowed for the following functions: <function>lag</function>,
23670+
<function>lead</function>, <function>first_value</function>, <function>last_value</function>,
23671+
<function>nth_value</function>.
23672+
</para>
23673+
2366123674
<note>
2366223675
<para>
23663-
The SQL standard defines a <literal>RESPECT NULLS</literal> or
23664-
<literal>IGNORE NULLS</literal> option for <function>lead</function>, <function>lag</function>,
23665-
<function>first_value</function>, <function>last_value</function>, and
23666-
<function>nth_value</function>. This is not implemented in
23667-
<productname>PostgreSQL</productname>: the behavior is always the
23668-
same as the standard's default, namely <literal>RESPECT NULLS</literal>.
23669-
Likewise, the standard's <literal>FROM FIRST</literal> or <literal>FROM LAST</literal>
23670-
option for <function>nth_value</function> is not implemented: only the
23671-
default <literal>FROM FIRST</literal> behavior is supported. (You can achieve
23672-
the result of <literal>FROM LAST</literal> by reversing the <literal>ORDER BY</literal>
23676+
The SQL standard defines a <literal>FROM FIRST</literal> or <literal>FROM LAST</literal>
23677+
option for <function>nth_value</function>. This is not implemented in
23678+
<productname>PostgreSQL</productname>: only the default <literal>FROM FIRST</literal>
23679+
behavior is supported. (You can achieve the result of <literal>FROM LAST</literal> by
23680+
reversing the <literal>ORDER BY</literal>
2367323681
ordering.)
2367423682
</para>
2367523683
</note>

doc/src/sgml/syntax.sgml

Lines changed: 6 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -1834,8 +1834,8 @@ FROM generate_series(1,10) AS s(i);
18341834
The syntax of a window function call is one of the following:
18351835

18361836
<synopsis>
1837-
<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>
1838-
<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> )
1837+
<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) <optional>null treatment</optional> [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER <replaceable>window_name</replaceable>
1838+
<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) <optional>null treatment</optional> [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER ( <replaceable class="parameter">window_definition</replaceable> )
18391839
<replaceable>function_name</replaceable> ( * ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER <replaceable>window_name</replaceable>
18401840
<replaceable>function_name</replaceable> ( * ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER ( <replaceable class="parameter">window_definition</replaceable> )
18411841
</synopsis>
@@ -1873,7 +1873,9 @@ EXCLUDE NO OTHERS
18731873

18741874
<para>
18751875
Here, <replaceable>expression</replaceable> represents any value
1876-
expression that does not itself contain window function calls.
1876+
expression that does not itself contain window function calls. Some
1877+
non-aggregate functions allow a <literal>null treatment</literal> clause,
1878+
described in <xref linkend="functions-window"/>.
18771879
</para>
18781880

18791881
<para>
@@ -2048,7 +2050,7 @@ EXCLUDE NO OTHERS
20482050

20492051
<para>
20502052
The built-in window functions are described in <xref
2051-
linkend="functions-window-table"/>. Other window functions can be added by
2053+
linkend="functions-window-table"/>. Other window functions can be added by
20522054
the user. Also, any built-in or user-defined general-purpose or
20532055
statistical aggregate can be used as a window function. (Ordered-set
20542056
and hypothetical-set aggregates cannot presently be used as window functions.)

src/backend/catalog/sql_features.txt

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -518,7 +518,7 @@ T612 Advanced OLAP operations YES
518518
T613 Sampling YES
519519
T614 NTILE function YES
520520
T615 LEAD and LAG functions YES
521-
T616 Null treatment option for LEAD and LAG functions NO
521+
T616 Null treatment option for LEAD and LAG functions YES
522522
T617 FIRST_VALUE and LAST_VALUE functions YES
523523
T618 NTH_VALUE function NO function exists, but some options missing
524524
T619 Nested window functions NO

0 commit comments

Comments
 (0)