Commit 8e8854da authored by Tom Lane's avatar Tom Lane

Add some basic support for window frame clauses to the window-functions

patch.  This includes the ability to force the frame to cover the whole
partition, and the ability to make the frame end exactly on the current row
rather than its last ORDER BY peer.  Supporting any more of the full SQL
frame-clause syntax will require nontrivial hacking on the window aggregate
code, so it'll have to wait for 8.5 or beyond.
parent 0fb9be7a
<!-- $PostgreSQL: pgsql/doc/src/sgml/advanced.sgml,v 1.55 2008/12/28 18:53:53 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/advanced.sgml,v 1.56 2008/12/31 00:08:32 tgl Exp $ -->
<chapter id="tutorial-advanced">
<title>Advanced Features</title>
......@@ -429,27 +429,27 @@ SELECT depname, empno, salary, rank() OVER (PARTITION BY depname ORDER BY salary
<para>
We already saw that <literal>ORDER BY</> can be omitted if the ordering
of rows is not important. It is also possible to omit <literal>PARTITION
BY</>, in which case the window function is computed over all rows of the
virtual table; that is, there is one partition containing all the rows.
BY</>, in which case there is just one partition containing all the rows.
</para>
<para>
There is another important concept associated with window functions:
for each row, there is a set of rows within its partition called its
<firstterm>window frame</>. When <literal>ORDER BY</> is omitted the
frame is always the same as the partition. If <literal>ORDER BY</> is
supplied, the frame consists of all rows from the start of the partition
up to the current row, plus any following rows that are equal to the
current row according to the <literal>ORDER BY</> clause.
<firstterm>window frame</>. Many (but not all) window functions act only
on the rows of the window frame, rather than of the whole partition.
By default, if <literal>ORDER BY</> is supplied then the frame consists of
all rows from the start of the partition up through the current row, plus
any following rows that are equal to the current row according to the
<literal>ORDER BY</> clause. When <literal>ORDER BY</> is omitted the
default frame consists of all rows in the partition.
<footnote>
<para>
The SQL standard includes options to define the window frame in
other ways, but this definition is the only one currently supported
by <productname>PostgreSQL</productname>.
There are options to define the window frame in other ways, but
this tutorial does not cover them. See
<xref linkend="syntax-window-functions"> for details.
</para>
</footnote>
Many window functions act only on the rows of the window frame, rather
than of the whole partition. Here is an example using <function>sum</>:
Here is an example using <function>sum</>:
</para>
<programlisting>
......@@ -550,6 +550,13 @@ SELECT sum(salary) OVER w, avg(salary) OVER w
WINDOW w AS (PARTITION BY depname ORDER BY salary DESC);
</programlisting>
</para>
<para>
More details about window functions can be found in
<xref linkend="syntax-window-functions">,
<xref linkend="queries-window">, and the
<xref linkend="sql-select" endterm="sql-select-title"> reference page.
</para>
</sect1>
......
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.464 2008/12/28 18:53:53 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.465 2008/12/31 00:08:33 tgl Exp $ -->
<chapter id="functions">
<title>Functions and Operators</title>
......@@ -10160,9 +10160,8 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
<para>
<firstterm>Window functions</firstterm> provide the ability to perform
calculations across sets of rows that are related to the current query
row. For information about this feature see
<xref linkend="tutorial-window"> and
<xref linkend="syntax-window-functions">.
row. See <xref linkend="tutorial-window"> for an introduction to this
feature.
</para>
<para>
......@@ -10392,18 +10391,23 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
<para>
Note that <function>first_value</>, <function>last_value</>, and
<function>nth_value</> consider only the rows within the <quote>window
frame</>, that is the rows from the start of the partition through the
last peer of the current row. This is particularly likely to give
unintuitive results for <function>last_value</>.
frame</>, which by default contains the rows from the start of the
partition through the last peer of the current row. This is
likely to give unhelpful results for <function>nth_value</> and
particularly <function>last_value</>. You can redefine the frame as
being the whole partition by adding <literal>ROWS BETWEEN UNBOUNDED
PRECEDING AND UNBOUNDED FOLLOWING</> to the <literal>OVER</> clause.
See <xref linkend="syntax-window-functions"> for more information.
</para>
<para>
When an aggregate function is used as a window function, it aggregates
over the rows within the current row's window frame. To obtain
aggregation over the whole partition, be sure to omit <literal>ORDER BY</>
from the window definition. An aggregate used with <literal>ORDER BY</>
produces a <quote>running sum</> type of behavior, which may or may not
be what's wanted.
aggregation over the whole partition, omit <literal>ORDER BY</> or use
<literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
An aggregate used with <literal>ORDER BY</> and the default window frame
definition produces a <quote>running sum</> type of behavior, which may or
may not be what's wanted.
</para>
<note>
......@@ -10416,7 +10420,9 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
same as the standard's default, namely <literal>RESPECT NULLS</>.
Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
option for <function>nth_value</> is not implemented: only the
default <literal>FROM FIRST</> behavior is supported.
default <literal>FROM FIRST</> behavior is supported. (You can achieve
the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
ordering.)
</para>
</note>
......
<!-- $PostgreSQL: pgsql/doc/src/sgml/queries.sgml,v 1.51 2008/12/28 18:53:54 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/queries.sgml,v 1.52 2008/12/31 00:08:35 tgl Exp $ -->
<chapter id="queries">
<title>Queries</title>
......@@ -993,7 +993,7 @@ SELECT product_id, p.name, (sum(s.units) * (p.price - p.cost)) AS profit
</para>
<para>
Currently, use of window functions always forces sorting, and so the
Currently, window functions always require presorted data, and so the
query output will be ordered according to one or another of the window
functions' <literal>PARTITION BY</>/<literal>ORDER BY</> clauses.
It is not recommendable to rely on this, however. Use an explicit
......
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/select.sgml,v 1.114 2008/12/29 18:23:53 tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/ref/select.sgml,v 1.115 2008/12/31 00:08:35 tgl Exp $
PostgreSQL documentation
-->
......@@ -583,7 +583,21 @@ WINDOW <replaceable class="parameter">window_name</replaceable> AS ( <replaceabl
[ <replaceable class="parameter">existing_window_name</replaceable> ]
[ PARTITION BY <replaceable class="parameter">expression</replaceable> [, ...] ]
[ ORDER BY <replaceable class="parameter">expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [ NULLS { FIRST | LAST } ] [, ...] ]
[ <replaceable class="parameter">framing_clause</replaceable> ]
</synopsis>
</para>
<para>
If an <replaceable class="parameter">existing_window_name</replaceable>
is specified it must refer to an earlier entry in the <literal>WINDOW</>
list; the new window copies its partitioning clause from that entry,
as well as its ordering clause if any. In this case the new window cannot
specify its own <literal>PARTITION BY</> clause, and it can specify
<literal>ORDER BY</> only if the copied window does not have one.
The framing clause is never copied from the existing window.
</para>
<para>
The elements of the <literal>PARTITION BY</> list are interpreted in
the same fashion as elements of a
<xref linkend="sql-groupby" endterm="sql-groupby-title">, and
......@@ -597,12 +611,29 @@ WINDOW <replaceable class="parameter">window_name</replaceable> AS ( <replaceabl
</para>
<para>
If an <replaceable class="parameter">existing_window_name</replaceable>
is specified it must refer to an earlier entry in the <literal>WINDOW</>
list; the new window copies its partitioning clause from that entry,
as well as its ordering clause if any. In this case the new window cannot
specify its own <literal>PARTITION BY</> clause, and it can specify
<literal>ORDER BY</> only if the copied window does not have one.
The optional <replaceable class="parameter">framing_clause</> defines
the <firstterm>window frame</> for window functions that depend on the
frame (not all do). It can be one of
<synopsis>
RANGE UNBOUNDED PRECEDING
RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
ROWS UNBOUNDED PRECEDING
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
</synopsis>
The first two are equivalent and are also the default: they set the
frame to be all rows from the partition start up through the current row's
last peer in the <literal>ORDER BY</> ordering (which means all rows if
there is no <literal>ORDER BY</>). The options
<literal>RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</> and
<literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>
are also equivalent: they always select all rows in the partition.
Lastly, <literal>ROWS UNBOUNDED PRECEDING</> or its verbose equivalent
<literal>ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW</> select
all rows up through the current row (regardless of duplicates).
Beware that this option can produce implementation-dependent results
if the <literal>ORDER BY</> ordering does not order the rows uniquely.
</para>
<para>
......@@ -623,8 +654,9 @@ WINDOW <replaceable class="parameter">window_name</replaceable> AS ( <replaceabl
<para>
Window functions are described in detail in
<xref linkend="tutorial-window"> and
<xref linkend="syntax-window-functions">.
<xref linkend="tutorial-window">,
<xref linkend="syntax-window-functions">, and
<xref linkend="queries-window">.
</para>
</refsect2>
......@@ -1453,12 +1485,10 @@ SELECT distributors.* WHERE distributors.name = 'Westward';
<title><literal>WINDOW</literal> Clause Restrictions</title>
<para>
The SQL standard provides for an optional <quote>framing clause</>,
introduced by the key word <literal>RANGE</> or <literal>ROWS</>,
in window definitions. <productname>PostgreSQL</productname> does
not yet implement framing clauses, and always follows the
default framing behavior, which is equivalent to the framing clause
<literal>RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW</>.
The SQL standard provides additional options for the window
<replaceable class="parameter">framing_clause</>.
<productname>PostgreSQL</productname> currently supports only the
options listed above.
</para>
</refsect2>
......
<!-- $PostgreSQL: pgsql/doc/src/sgml/syntax.sgml,v 1.127 2008/12/28 18:53:54 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/syntax.sgml,v 1.128 2008/12/31 00:08:35 tgl Exp $ -->
<chapter id="sql-syntax">
<title>SQL Syntax</title>
......@@ -1591,6 +1591,17 @@ sqrt(2)
[ <replaceable class="parameter">window_name</replaceable> ]
[ PARTITION BY <replaceable class="parameter">expression</replaceable> [, ...] ]
[ ORDER BY <replaceable class="parameter">expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [ NULLS { FIRST | LAST } ] [, ...] ]
[ <replaceable class="parameter">framing_clause</replaceable> ]
</synopsis>
and the optional <replaceable class="parameter">framing_clause</replaceable>
can be one of
<synopsis>
RANGE UNBOUNDED PRECEDING
RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
ROWS UNBOUNDED PRECEDING
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
</synopsis>
Here, <replaceable>expression</replaceable> represents any value
......@@ -1603,19 +1614,33 @@ sqrt(2)
Named window specifications are usually referenced with just
<literal>OVER</> <replaceable>window_name</replaceable>, but it is
also possible to write a window name inside the parentheses and then
optionally override its ordering clause with <literal>ORDER BY</>.
optionally override its ordering clause and/or framing clause.
This latter syntax follows the same rules as modifying an existing
window name within the <literal>WINDOW</literal> clause; see the
<xref linkend="sql-select" endterm="sql-select-title"> reference
page for details.
</para>
<para>
The default framing option is <literal>RANGE UNBOUNDED PRECEDING</>,
which is the same as <literal>RANGE BETWEEN UNBOUNDED PRECEDING AND
CURRENT ROW</>; it selects rows up through the current row's last
peer in the <literal>ORDER BY</> ordering (which means all rows if
there is no <literal>ORDER BY</>). The options
<literal>RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</> and
<literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>
are also equivalent: they always select all rows in the partition.
Lastly, <literal>ROWS UNBOUNDED PRECEDING</> or its verbose equivalent
<literal>ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW</> select
all rows up through the current row (regardless of duplicates).
Beware that this option can produce implementation-dependent results
if the <literal>ORDER BY</> ordering does not order the rows uniquely.
</para>
<para>
The built-in window functions are described in <xref
linkend="functions-window-table">. Also, any built-in or
user-defined aggregate function can be used as a window function.
Currently, there is no provision for user-defined window functions
other than aggregates.
</para>
<para>
......
This diff is collapsed.
......@@ -15,7 +15,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.417 2008/12/28 18:53:55 tgl Exp $
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.418 2008/12/31 00:08:35 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -678,6 +678,7 @@ _copyWindowAgg(WindowAgg *from)
CopyPlanFields((Plan *) from, (Plan *) newnode);
COPY_SCALAR_FIELD(winref);
COPY_SCALAR_FIELD(partNumCols);
if (from->partNumCols > 0)
{
......@@ -690,6 +691,7 @@ _copyWindowAgg(WindowAgg *from)
COPY_POINTER_FIELD(ordColIdx, from->ordNumCols * sizeof(AttrNumber));
COPY_POINTER_FIELD(ordOperators, from->ordNumCols * sizeof(Oid));
}
COPY_SCALAR_FIELD(frameOptions);
return newnode;
}
......@@ -1783,6 +1785,7 @@ _copyWindowClause(WindowClause *from)
COPY_STRING_FIELD(refname);
COPY_NODE_FIELD(partitionClause);
COPY_NODE_FIELD(orderClause);
COPY_SCALAR_FIELD(frameOptions);
COPY_SCALAR_FIELD(winref);
COPY_SCALAR_FIELD(copiedOrder);
......@@ -2010,6 +2013,7 @@ _copyWindowDef(WindowDef *from)
COPY_STRING_FIELD(refname);
COPY_NODE_FIELD(partitionClause);
COPY_NODE_FIELD(orderClause);
COPY_SCALAR_FIELD(frameOptions);
COPY_LOCATION_FIELD(location);
return newnode;
......
......@@ -22,7 +22,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.342 2008/12/28 18:53:56 tgl Exp $
* $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.343 2008/12/31 00:08:35 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -2005,6 +2005,7 @@ _equalWindowDef(WindowDef *a, WindowDef *b)
COMPARE_STRING_FIELD(refname);
COMPARE_NODE_FIELD(partitionClause);
COMPARE_NODE_FIELD(orderClause);
COMPARE_SCALAR_FIELD(frameOptions);
COMPARE_LOCATION_FIELD(location);
return true;
......@@ -2143,6 +2144,7 @@ _equalWindowClause(WindowClause *a, WindowClause *b)
COMPARE_STRING_FIELD(refname);
COMPARE_NODE_FIELD(partitionClause);
COMPARE_NODE_FIELD(orderClause);
COMPARE_SCALAR_FIELD(frameOptions);
COMPARE_SCALAR_FIELD(winref);
COMPARE_SCALAR_FIELD(copiedOrder);
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/outfuncs.c,v 1.347 2008/12/28 18:53:56 tgl Exp $
* $PostgreSQL: pgsql/src/backend/nodes/outfuncs.c,v 1.348 2008/12/31 00:08:36 tgl Exp $
*
* NOTES
* Every node type that can appear in stored rules' parsetrees *must*
......@@ -575,6 +575,7 @@ _outWindowAgg(StringInfo str, WindowAgg *node)
_outPlanInfo(str, (Plan *) node);
WRITE_UINT_FIELD(winref);
WRITE_INT_FIELD(partNumCols);
appendStringInfo(str, " :partColIdx");
......@@ -594,6 +595,8 @@ _outWindowAgg(StringInfo str, WindowAgg *node)
appendStringInfo(str, " :ordOperations");
for (i = 0; i < node->ordNumCols; i++)
appendStringInfo(str, " %u", node->ordOperators[i]);
WRITE_INT_FIELD(frameOptions);
}
static void
......@@ -1953,6 +1956,7 @@ _outWindowClause(StringInfo str, WindowClause *node)
WRITE_STRING_FIELD(refname);
WRITE_NODE_FIELD(partitionClause);
WRITE_NODE_FIELD(orderClause);
WRITE_INT_FIELD(frameOptions);
WRITE_UINT_FIELD(winref);
WRITE_BOOL_FIELD(copiedOrder);
}
......@@ -2242,6 +2246,7 @@ _outWindowDef(StringInfo str, WindowDef *node)
WRITE_STRING_FIELD(refname);
WRITE_NODE_FIELD(partitionClause);
WRITE_NODE_FIELD(orderClause);
WRITE_INT_FIELD(frameOptions);
WRITE_LOCATION_FIELD(location);
}
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/readfuncs.c,v 1.218 2008/12/28 18:53:56 tgl Exp $
* $PostgreSQL: pgsql/src/backend/nodes/readfuncs.c,v 1.219 2008/12/31 00:08:36 tgl Exp $
*
* NOTES
* Path and Plan nodes do not have any readfuncs support, because we
......@@ -231,6 +231,7 @@ _readWindowClause(void)
READ_STRING_FIELD(refname);
READ_NODE_FIELD(partitionClause);
READ_NODE_FIELD(orderClause);
READ_INT_FIELD(frameOptions);
READ_UINT_FIELD(winref);
READ_BOOL_FIELD(copiedOrder);
......
......@@ -10,7 +10,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/optimizer/plan/createplan.c,v 1.253 2008/12/28 18:53:56 tgl Exp $
* $PostgreSQL: pgsql/src/backend/optimizer/plan/createplan.c,v 1.254 2008/12/31 00:08:36 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -3261,22 +3261,25 @@ make_agg(PlannerInfo *root, List *tlist, List *qual,
}
WindowAgg *
make_windowagg(PlannerInfo *root, List *tlist, int numWindowFuncs,
make_windowagg(PlannerInfo *root, List *tlist,
int numWindowFuncs, Index winref,
int partNumCols, AttrNumber *partColIdx, Oid *partOperators,
int ordNumCols, AttrNumber *ordColIdx, Oid *ordOperators,
Plan *lefttree)
int frameOptions, Plan *lefttree)
{
WindowAgg *node = makeNode(WindowAgg);
Plan *plan = &node->plan;
Path windowagg_path; /* dummy for result of cost_windowagg */
QualCost qual_cost;
node->winref = winref;
node->partNumCols = partNumCols;
node->partColIdx = partColIdx;
node->partOperators = partOperators;
node->ordNumCols = ordNumCols;
node->ordColIdx = ordColIdx;
node->ordOperators = ordOperators;
node->frameOptions = frameOptions;
copy_plan_costsize(plan, lefttree); /* only care about copying size */
cost_windowagg(&windowagg_path, root,
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/optimizer/plan/planner.c,v 1.248 2008/12/28 18:53:56 tgl Exp $
* $PostgreSQL: pgsql/src/backend/optimizer/plan/planner.c,v 1.249 2008/12/31 00:08:36 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -1398,12 +1398,14 @@ grouping_planner(PlannerInfo *root, double tuple_fraction)
make_windowagg(root,
(List *) copyObject(window_tlist),
list_length(wflists->windowFuncs[wc->winref]),
wc->winref,
partNumCols,
partColIdx,
partOperators,
ordNumCols,
ordColIdx,
ordOperators,
wc->frameOptions,
result_plan);
}
}
......@@ -2412,6 +2414,7 @@ select_active_windows(PlannerInfo *root, WindowFuncLists *wflists)
WindowClause *wc2 = (WindowClause *) lfirst(lc);
next = lnext(lc);
/* framing options are NOT to be compared here! */
if (equal(wc->partitionClause, wc2->partitionClause) &&
equal(wc->orderClause, wc2->orderClause))
{
......
......@@ -11,7 +11,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.648 2008/12/28 18:53:58 tgl Exp $
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.649 2008/12/31 00:08:36 tgl Exp $
*
* HISTORY
* AUTHOR DATE MAJOR EVENT
......@@ -406,6 +406,7 @@ static TypeName *TableFuncTypeName(List *columns);
%type <list> window_clause window_definition_list opt_partition_clause
%type <windef> window_definition over_clause window_specification
%type <str> opt_existing_window_name
%type <ival> opt_frame_clause frame_extent frame_bound
/*
......@@ -439,7 +440,7 @@ static TypeName *TableFuncTypeName(List *columns);
EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EXCEPT
EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXTERNAL EXTRACT
FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOR FORCE FOREIGN FORWARD
FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD
FREEZE FROM FULL FUNCTION
GLOBAL GRANT GRANTED GREATEST GROUP_P
......@@ -469,14 +470,14 @@ static TypeName *TableFuncTypeName(List *columns);
ORDER OUT_P OUTER_P OVER OVERLAPS OVERLAY OWNED OWNER
PARSER PARTIAL PARTITION PASSWORD PLACING PLANS POSITION
PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
PRIOR PRIVILEGES PROCEDURAL PROCEDURE
QUOTE
READ REAL REASSIGN RECHECK RECURSIVE REFERENCES REINDEX RELATIVE_P RELEASE
RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURNING RETURNS
REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE
RANGE READ REAL REASSIGN RECHECK RECURSIVE REFERENCES REINDEX
RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART
RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE
SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE
SERIALIZABLE SERVER SESSION SESSION_USER SET SETOF SHARE
......@@ -488,7 +489,7 @@ static TypeName *TableFuncTypeName(List *columns);
TO TRAILING TRANSACTION TREAT TRIGGER TRIM TRUE_P
TRUNCATE TRUSTED TYPE_P
UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN UNLISTEN UNTIL
UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN UNLISTEN UNTIL
UPDATE USER USING
VACUUM VALID VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
......@@ -533,10 +534,12 @@ static TypeName *TableFuncTypeName(List *columns);
* between POSTFIXOP and Op. We can safely assign the same priority to
* various unreserved keywords as needed to resolve ambiguities (this can't
* have any bad effects since obviously the keywords will still behave the
* same as if they weren't keywords). We need to do this for PARTITION
* to support opt_existing_window_name.
* same as if they weren't keywords). We need to do this for PARTITION,
* RANGE, ROWS to support opt_existing_window_name; and for RANGE, ROWS
* so that they can follow a_expr without creating
* postfix-operator problems.
*/
%nonassoc IDENT PARTITION
%nonassoc IDENT PARTITION RANGE ROWS
%left Op OPERATOR /* multi-character ops and user-defined operators */
%nonassoc NOTNULL
%nonassoc ISNULL
......@@ -9235,10 +9238,11 @@ over_clause: OVER window_specification
| OVER ColId
{
WindowDef *n = makeNode(WindowDef);
n->name = NULL;
n->refname = $2;
n->name = $2;
n->refname = NULL;
n->partitionClause = NIL;
n->orderClause = NIL;
n->frameOptions = FRAMEOPTION_DEFAULTS;
n->location = @2;
$$ = n;
}
......@@ -9247,13 +9251,14 @@ over_clause: OVER window_specification
;
window_specification: '(' opt_existing_window_name opt_partition_clause
opt_sort_clause ')'
opt_sort_clause opt_frame_clause ')'
{
WindowDef *n = makeNode(WindowDef);
n->name = NULL;
n->refname = $2;
n->partitionClause = $3;
n->orderClause = $4;
n->frameOptions = $5;
n->location = @1;
$$ = n;
}
......@@ -9268,7 +9273,6 @@ window_specification: '(' opt_existing_window_name opt_partition_clause
* that the shift/reduce conflict is resolved in favor of reducing the rule.
* These keywords are thus precluded from being an existing_window_name but
* are not reserved for any other purpose.
* (RANGE/ROWS are not an issue as of 8.4 for lack of frame_clause support.)
*/
opt_existing_window_name: ColId { $$ = $1; }
| /*EMPTY*/ %prec Op { $$ = NULL; }
......@@ -9278,6 +9282,83 @@ opt_partition_clause: PARTITION BY expr_list { $$ = $3; }
| /*EMPTY*/ { $$ = NIL; }
;
/*
* This is only a subset of the full SQL:2008 frame_clause grammar.
* We don't support <expression> PRECEDING, <expression> FOLLOWING,
* nor <window frame exclusion> yet.
*/
opt_frame_clause:
RANGE frame_extent
{
$$ = FRAMEOPTION_NONDEFAULT | FRAMEOPTION_RANGE | $2;
}
| ROWS frame_extent
{
$$ = FRAMEOPTION_NONDEFAULT | FRAMEOPTION_ROWS | $2;
}
| /*EMPTY*/
{ $$ = FRAMEOPTION_DEFAULTS; }
;
frame_extent: frame_bound
{
/* reject invalid cases */
if ($1 & FRAMEOPTION_START_UNBOUNDED_FOLLOWING)
ereport(ERROR,
(errcode(ERRCODE_WINDOWING_ERROR),
errmsg("frame start cannot be UNBOUNDED FOLLOWING"),
scanner_errposition(@1)));
if ($1 & FRAMEOPTION_START_CURRENT_ROW)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("frame start at CURRENT ROW is not implemented"),
scanner_errposition(@1)));
$$ = $1 | FRAMEOPTION_END_CURRENT_ROW;
}
| BETWEEN frame_bound AND frame_bound
{
/* reject invalid cases */
if ($2 & FRAMEOPTION_START_UNBOUNDED_FOLLOWING)
ereport(ERROR,
(errcode(ERRCODE_WINDOWING_ERROR),
errmsg("frame start cannot be UNBOUNDED FOLLOWING"),
scanner_errposition(@2)));
if ($2 & FRAMEOPTION_START_CURRENT_ROW)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("frame start at CURRENT ROW is not implemented"),
scanner_errposition(@2)));
if ($4 & FRAMEOPTION_START_UNBOUNDED_PRECEDING)
ereport(ERROR,
(errcode(ERRCODE_WINDOWING_ERROR),
errmsg("frame end cannot be UNBOUNDED PRECEDING"),
scanner_errposition(@4)));
/* shift converts START_ options to END_ options */
$$ = FRAMEOPTION_BETWEEN | $2 | ($4 << 1);
}
;
/*
* This is used for both frame start and frame end, with output set up on
* the assumption it's frame start; the frame_extent productions must reject
* invalid cases.
*/
frame_bound:
UNBOUNDED PRECEDING
{
$$ = FRAMEOPTION_START_UNBOUNDED_PRECEDING;
}
| UNBOUNDED FOLLOWING
{
$$ = FRAMEOPTION_START_UNBOUNDED_FOLLOWING;
}
| CURRENT_P ROW
{
$$ = FRAMEOPTION_START_CURRENT_ROW;
}
;
/*
* Supporting nonterminals for expressions.
*/
......@@ -10012,6 +10093,7 @@ unreserved_keyword:
| EXTERNAL
| FAMILY
| FIRST_P
| FOLLOWING
| FORCE
| FORWARD
| FUNCTION
......@@ -10086,6 +10168,7 @@ unreserved_keyword:
| PARTITION
| PASSWORD
| PLANS
| PRECEDING
| PREPARE
| PREPARED
| PRESERVE
......@@ -10094,6 +10177,7 @@ unreserved_keyword:
| PROCEDURAL
| PROCEDURE
| QUOTE
| RANGE
| READ
| REASSIGN
| RECHECK
......@@ -10151,6 +10235,7 @@ unreserved_keyword:
| TRUNCATE
| TRUSTED
| TYPE_P
| UNBOUNDED
| UNCOMMITTED
| UNENCRYPTED
| UNKNOWN
......
......@@ -11,7 +11,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/parser/keywords.c,v 1.207 2008/12/28 18:53:58 tgl Exp $
* $PostgreSQL: pgsql/src/backend/parser/keywords.c,v 1.208 2008/12/31 00:08:37 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -172,6 +172,7 @@ const ScanKeyword ScanKeywords[] = {
{"fetch", FETCH, RESERVED_KEYWORD},
{"first", FIRST_P, UNRESERVED_KEYWORD},
{"float", FLOAT_P, COL_NAME_KEYWORD},
{"following", FOLLOWING, UNRESERVED_KEYWORD},
{"for", FOR, RESERVED_KEYWORD},
{"force", FORCE, UNRESERVED_KEYWORD},
{"foreign", FOREIGN, RESERVED_KEYWORD},
......@@ -299,6 +300,7 @@ const ScanKeyword ScanKeywords[] = {
{"placing", PLACING, RESERVED_KEYWORD},
{"plans", PLANS, UNRESERVED_KEYWORD},
{"position", POSITION, COL_NAME_KEYWORD},
{"preceding", PRECEDING, UNRESERVED_KEYWORD},
{"precision", PRECISION, COL_NAME_KEYWORD},
{"prepare", PREPARE, UNRESERVED_KEYWORD},
{"prepared", PREPARED, UNRESERVED_KEYWORD},
......@@ -309,6 +311,7 @@ const ScanKeyword ScanKeywords[] = {
{"procedural", PROCEDURAL, UNRESERVED_KEYWORD},
{"procedure", PROCEDURE, UNRESERVED_KEYWORD},
{"quote", QUOTE, UNRESERVED_KEYWORD},
{"range", RANGE, UNRESERVED_KEYWORD},
{"read", READ, UNRESERVED_KEYWORD},
{"real", REAL, COL_NAME_KEYWORD},
{"reassign", REASSIGN, UNRESERVED_KEYWORD},
......@@ -388,6 +391,7 @@ const ScanKeyword ScanKeywords[] = {
{"truncate", TRUNCATE, UNRESERVED_KEYWORD},
{"trusted", TRUSTED, UNRESERVED_KEYWORD},
{"type", TYPE_P, UNRESERVED_KEYWORD},
{"unbounded", UNBOUNDED, UNRESERVED_KEYWORD},
{"uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD},
{"unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD},
{"union", UNION, RESERVED_KEYWORD},
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/parser/parse_agg.c,v 1.85 2008/12/28 18:53:58 tgl Exp $
* $PostgreSQL: pgsql/src/backend/parser/parse_agg.c,v 1.86 2008/12/31 00:08:37 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -123,25 +123,27 @@ transformWindowFuncCall(ParseState *pstate, WindowFunc *wfunc,
locate_windowfunc((Node *) wfunc->args))));
/*
* If the OVER clause just specifies a reference name, find that
* If the OVER clause just specifies a window name, find that
* WINDOW clause (which had better be present). Otherwise, try to
* match all the properties of the OVER clause, and make a new entry
* in the p_windowdefs list if no luck.
*/
Assert(!windef->name);
if (windef->refname &&
windef->partitionClause == NIL &&
windef->orderClause == NIL)
if (windef->name)
{
Index winref = 0;
ListCell *lc;
Assert(windef->refname == NULL &&
windef->partitionClause == NIL &&
windef->orderClause == NIL &&
windef->frameOptions == FRAMEOPTION_DEFAULTS);
foreach(lc, pstate->p_windowdefs)
{
WindowDef *refwin = (WindowDef *) lfirst(lc);
winref++;
if (refwin->name && strcmp(refwin->name, windef->refname) == 0)
if (refwin->name && strcmp(refwin->name, windef->name) == 0)
{
wfunc->winref = winref;
break;
......@@ -150,7 +152,7 @@ transformWindowFuncCall(ParseState *pstate, WindowFunc *wfunc,
if (lc == NULL) /* didn't find it? */
ereport(ERROR,
(errcode(ERRCODE_UNDEFINED_OBJECT),
errmsg("window \"%s\" does not exist", windef->refname),
errmsg("window \"%s\" does not exist", windef->name),
parser_errposition(pstate, windef->location)));
}
else
......@@ -164,14 +166,15 @@ transformWindowFuncCall(ParseState *pstate, WindowFunc *wfunc,
winref++;
if (refwin->refname && windef->refname &&
strcmp(refwin->name, windef->refname) == 0)
strcmp(refwin->refname, windef->refname) == 0)
/* matched on refname */ ;
else if (!refwin->refname && !windef->refname)
/* matched, no refname */ ;
else
continue;
if (equal(refwin->partitionClause, windef->partitionClause) &&
equal(refwin->orderClause, windef->orderClause))
equal(refwin->orderClause, windef->orderClause) &&
refwin->frameOptions == windef->frameOptions)
{
/* found a duplicate window specification */
wfunc->winref = winref;
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/parser/parse_clause.c,v 1.182 2008/12/28 18:53:58 tgl Exp $
* $PostgreSQL: pgsql/src/backend/parser/parse_clause.c,v 1.183 2008/12/31 00:08:37 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -1554,7 +1554,7 @@ transformWindowDefinitions(ParseState *pstate,
* Per spec, a windowdef that references a previous one copies the
* previous partition clause (and mustn't specify its own). It can
* specify its own ordering clause. but only if the previous one
* had none.
* had none. It always specifies its own framing clause.
*/
if (refwc)
{
......@@ -1592,6 +1592,7 @@ transformWindowDefinitions(ParseState *pstate,
wc->orderClause = orderClause;
wc->copiedOrder = false;
}
wc->frameOptions = windef->frameOptions;
wc->winref = winref;
result = lappend(result, wc);
......
......@@ -9,7 +9,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/utils/adt/ruleutils.c,v 1.291 2008/12/28 18:53:59 tgl Exp $
* $PostgreSQL: pgsql/src/backend/utils/adt/ruleutils.c,v 1.292 2008/12/31 00:08:37 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -2903,7 +2903,7 @@ get_rule_windowspec(WindowClause *wc, List *targetList,
appendStringInfoString(buf, quote_identifier(wc->refname));
needspace = true;
}
/* partitions are always inherited, so only print if no refname */
/* partition clauses are always inherited, so only print if no refname */
if (wc->partitionClause && !wc->refname)
{
if (needspace)
......@@ -2921,6 +2921,7 @@ get_rule_windowspec(WindowClause *wc, List *targetList,
}
needspace = true;
}
/* print ordering clause only if not inherited */
if (wc->orderClause && !wc->copiedOrder)
{
if (needspace)
......@@ -2929,6 +2930,38 @@ get_rule_windowspec(WindowClause *wc, List *targetList,
get_rule_orderby(wc->orderClause, targetList, false, context);
needspace = true;
}
/* framing clause is never inherited, so print unless it's default */
if (wc->frameOptions & FRAMEOPTION_NONDEFAULT)
{
if (needspace)
appendStringInfoChar(buf, ' ');
if (wc->frameOptions & FRAMEOPTION_RANGE)
appendStringInfoString(buf, "RANGE ");
else if (wc->frameOptions & FRAMEOPTION_ROWS)
appendStringInfoString(buf, "ROWS ");
else
Assert(false);
if (wc->frameOptions & FRAMEOPTION_BETWEEN)
appendStringInfoString(buf, "BETWEEN ");
if (wc->frameOptions & FRAMEOPTION_START_UNBOUNDED_PRECEDING)
appendStringInfoString(buf, "UNBOUNDED PRECEDING ");
else if (wc->frameOptions & FRAMEOPTION_START_CURRENT_ROW)
appendStringInfoString(buf, "CURRENT ROW ");
else
Assert(false);
if (wc->frameOptions & FRAMEOPTION_BETWEEN)
{
appendStringInfoString(buf, "AND ");
if (wc->frameOptions & FRAMEOPTION_END_UNBOUNDED_FOLLOWING)
appendStringInfoString(buf, "UNBOUNDED FOLLOWING ");
else if (wc->frameOptions & FRAMEOPTION_END_CURRENT_ROW)
appendStringInfoString(buf, "CURRENT ROW ");
else
Assert(false);
}
/* we will now have a trailing space; remove it */
buf->len--;
}
appendStringInfoChar(buf, ')');
}
......
......@@ -37,7 +37,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.514 2008/12/28 18:53:59 tgl Exp $
* $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.515 2008/12/31 00:08:38 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 200812281
#define CATALOG_VERSION_NO 200812301
#endif
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/nodes/execnodes.h,v 1.197 2008/12/28 18:54:00 tgl Exp $
* $PostgreSQL: pgsql/src/include/nodes/execnodes.h,v 1.198 2008/12/31 00:08:38 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -1533,12 +1533,14 @@ typedef struct WindowAggState
* have been spooled into tuplestore */
bool more_partitions; /* true if there's more partitions after
* this one */
bool frametail_valid; /* true if frametailpos is known up to date
* for current row */
TupleTableSlot *first_part_slot; /* first tuple of current or next
* partition */
/* temporary slots for tuples fetched back from tuplestore */
TupleTableSlot *first_peer_slot;
TupleTableSlot *agg_row_slot;
TupleTableSlot *temp_slot_1;
TupleTableSlot *temp_slot_2;
} WindowAggState;
......
......@@ -13,7 +13,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.385 2008/12/28 18:54:00 tgl Exp $
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.386 2008/12/31 00:08:38 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -382,17 +382,46 @@ typedef struct SortBy
/*
* WindowDef - raw representation of WINDOW and OVER clauses
*
* For entries in a WINDOW list, "name" is the window name being defined.
* For OVER clauses, we use "name" for the "OVER window" syntax, or "refname"
* for the "OVER (window)" syntax, which is subtly different --- the latter
* implies overriding the window frame clause.
*/
typedef struct WindowDef
{
NodeTag type;
char *name; /* window name (NULL in an OVER clause) */
char *name; /* window's own name */
char *refname; /* referenced window name, if any */
List *partitionClause; /* PARTITION BY expression list */
List *orderClause; /* ORDER BY (list of SortBy) */
int frameOptions; /* frame_clause options, see below */
int location; /* parse location, or -1 if none/unknown */
} WindowDef;
/*
* frameOptions is an OR of these bits. The NONDEFAULT and BETWEEN bits are
* used so that ruleutils.c can tell which properties were specified and
* which were defaulted; the correct behavioral bits must be set either way.
* The START_foo and END_foo options must come in pairs of adjacent bits for
* the convenience of gram.y, even though some of them are useless/invalid.
* We will need more bits (and fields) to cover the full SQL:2008 option set.
*/
#define FRAMEOPTION_NONDEFAULT 0x00001 /* any specified? */
#define FRAMEOPTION_RANGE 0x00002 /* RANGE behavior */
#define FRAMEOPTION_ROWS 0x00004 /* ROWS behavior */
#define FRAMEOPTION_BETWEEN 0x00008 /* BETWEEN given? */
#define FRAMEOPTION_START_UNBOUNDED_PRECEDING 0x00010 /* start is U. P. */
#define FRAMEOPTION_END_UNBOUNDED_PRECEDING 0x00020 /* (disallowed) */
#define FRAMEOPTION_START_UNBOUNDED_FOLLOWING 0x00040 /* (disallowed) */
#define FRAMEOPTION_END_UNBOUNDED_FOLLOWING 0x00080 /* end is U. F. */
#define FRAMEOPTION_START_CURRENT_ROW 0x00100 /* start is C. R. */
#define FRAMEOPTION_END_CURRENT_ROW 0x00200 /* end is C. R. */
#define FRAMEOPTION_DEFAULTS \
(FRAMEOPTION_RANGE | FRAMEOPTION_START_UNBOUNDED_PRECEDING | \
FRAMEOPTION_END_CURRENT_ROW)
/*
* RangeSubselect - subquery appearing in a FROM clause
*/
......@@ -744,8 +773,8 @@ typedef struct SortGroupClause
* winref is an ID number referenced by WindowFunc nodes; it must be unique
* among the members of a Query's windowClause list.
* When refname isn't null, the partitionClause is always copied from there;
* the orderClause might or might not be copied. (We don't implement
* framing clauses yet, but if we did, they are never copied, per spec.)
* the orderClause might or might not be copied (see copiedOrder); the framing
* options are never copied, per spec.
*/
typedef struct WindowClause
{
......@@ -754,6 +783,7 @@ typedef struct WindowClause
char *refname; /* referenced window name, if any */
List *partitionClause; /* PARTITION BY list */
List *orderClause; /* ORDER BY list */
int frameOptions; /* frame_clause options, see WindowDef */
Index winref; /* ID referenced by window functions */
bool copiedOrder; /* did we copy orderClause from refname? */
} WindowClause;
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/nodes/plannodes.h,v 1.106 2008/12/28 18:54:00 tgl Exp $
* $PostgreSQL: pgsql/src/include/nodes/plannodes.h,v 1.107 2008/12/31 00:08:38 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -543,12 +543,14 @@ typedef struct Agg
typedef struct WindowAgg
{
Plan plan;
Index winref; /* ID referenced by window functions */
int partNumCols; /* number of columns in partition clause */
AttrNumber *partColIdx; /* their indexes in the target list */
Oid *partOperators; /* equality operators for partition columns */
int ordNumCols; /* number of columns in ordering clause */
AttrNumber *ordColIdx; /* their indexes in the target list */
Oid *ordOperators; /* equality operators for ordering columns */
int frameOptions; /* frame_clause options, see WindowDef */
} WindowAgg;
/* ----------------
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/optimizer/planmain.h,v 1.115 2008/12/28 18:54:01 tgl Exp $
* $PostgreSQL: pgsql/src/include/optimizer/planmain.h,v 1.116 2008/12/31 00:08:38 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -57,10 +57,10 @@ extern Agg *make_agg(PlannerInfo *root, List *tlist, List *qual,
long numGroups, int numAggs,
Plan *lefttree);
extern WindowAgg *make_windowagg(PlannerInfo *root, List *tlist,
int numWindowFuncs,
int numWindowFuncs, Index winref,
int partNumCols, AttrNumber *partColIdx, Oid *partOperators,
int ordNumCols, AttrNumber *ordColIdx, Oid *ordOperators,
Plan *lefttree);
int frameOptions, Plan *lefttree);
extern Group *make_group(PlannerInfo *root, List *tlist, List *qual,
int numGroupCols, AttrNumber *grpColIdx, Oid *grpOperators,
double numGroups,
......
......@@ -587,30 +587,153 @@ SELECT empno, depname, salary, bonus, depadj, MIN(bonus) OVER (ORDER BY empno),
11 | develop | 5200 | 500 | 200 | 500 | 200
(10 rows)
-- test non-default frame specifications
SELECT four, ten,
sum(ten) over (partition by four order by ten),
last_value(ten) over (partition by four order by ten)
FROM (select distinct ten, four from tenk1) ss;
four | ten | sum | last_value
------+-----+-----+------------
0 | 0 | 0 | 0
0 | 2 | 2 | 2
0 | 4 | 6 | 4
0 | 6 | 12 | 6
0 | 8 | 20 | 8
1 | 1 | 1 | 1
1 | 3 | 4 | 3
1 | 5 | 9 | 5
1 | 7 | 16 | 7
1 | 9 | 25 | 9
2 | 0 | 0 | 0
2 | 2 | 2 | 2
2 | 4 | 6 | 4
2 | 6 | 12 | 6
2 | 8 | 20 | 8
3 | 1 | 1 | 1
3 | 3 | 4 | 3
3 | 5 | 9 | 5
3 | 7 | 16 | 7
3 | 9 | 25 | 9
(20 rows)
SELECT four, ten,
sum(ten) over (partition by four order by ten range between unbounded preceding and current row),
last_value(ten) over (partition by four order by ten range between unbounded preceding and current row)
FROM (select distinct ten, four from tenk1) ss;
four | ten | sum | last_value
------+-----+-----+------------
0 | 0 | 0 | 0
0 | 2 | 2 | 2
0 | 4 | 6 | 4
0 | 6 | 12 | 6
0 | 8 | 20 | 8
1 | 1 | 1 | 1
1 | 3 | 4 | 3
1 | 5 | 9 | 5
1 | 7 | 16 | 7
1 | 9 | 25 | 9
2 | 0 | 0 | 0
2 | 2 | 2 | 2
2 | 4 | 6 | 4
2 | 6 | 12 | 6
2 | 8 | 20 | 8
3 | 1 | 1 | 1
3 | 3 | 4 | 3
3 | 5 | 9 | 5
3 | 7 | 16 | 7
3 | 9 | 25 | 9
(20 rows)
SELECT four, ten,
sum(ten) over (partition by four order by ten range between unbounded preceding and unbounded following),
last_value(ten) over (partition by four order by ten range between unbounded preceding and unbounded following)
FROM (select distinct ten, four from tenk1) ss;
four | ten | sum | last_value
------+-----+-----+------------
0 | 0 | 20 | 8
0 | 2 | 20 | 8
0 | 4 | 20 | 8
0 | 6 | 20 | 8
0 | 8 | 20 | 8
1 | 1 | 25 | 9
1 | 3 | 25 | 9
1 | 5 | 25 | 9
1 | 7 | 25 | 9
1 | 9 | 25 | 9
2 | 0 | 20 | 8
2 | 2 | 20 | 8
2 | 4 | 20 | 8
2 | 6 | 20 | 8
2 | 8 | 20 | 8
3 | 1 | 25 | 9
3 | 3 | 25 | 9
3 | 5 | 25 | 9
3 | 7 | 25 | 9
3 | 9 | 25 | 9
(20 rows)
SELECT four, ten/4 as two,
sum(ten/4) over (partition by four order by ten/4 range between unbounded preceding and current row),
last_value(ten/4) over (partition by four order by ten/4 range between unbounded preceding and current row)
FROM (select distinct ten, four from tenk1) ss;
four | two | sum | last_value
------+-----+-----+------------
0 | 0 | 0 | 0
0 | 0 | 0 | 0
0 | 1 | 2 | 1
0 | 1 | 2 | 1
0 | 2 | 4 | 2
1 | 0 | 0 | 0
1 | 0 | 0 | 0
1 | 1 | 2 | 1
1 | 1 | 2 | 1
1 | 2 | 4 | 2
2 | 0 | 0 | 0
2 | 0 | 0 | 0
2 | 1 | 2 | 1
2 | 1 | 2 | 1
2 | 2 | 4 | 2
3 | 0 | 0 | 0
3 | 0 | 0 | 0
3 | 1 | 2 | 1
3 | 1 | 2 | 1
3 | 2 | 4 | 2
(20 rows)
SELECT four, ten/4 as two,
sum(ten/4) over (partition by four order by ten/4 rows between unbounded preceding and current row),
last_value(ten/4) over (partition by four order by ten/4 rows between unbounded preceding and current row)
FROM (select distinct ten, four from tenk1) ss;
four | two | sum | last_value
------+-----+-----+------------
0 | 0 | 0 | 0
0 | 0 | 0 | 0
0 | 1 | 1 | 1
0 | 1 | 2 | 1
0 | 2 | 4 | 2
1 | 0 | 0 | 0
1 | 0 | 0 | 0
1 | 1 | 1 | 1
1 | 1 | 2 | 1
1 | 2 | 4 | 2
2 | 0 | 0 | 0
2 | 0 | 0 | 0
2 | 1 | 1 | 1
2 | 1 | 2 | 1
2 | 2 | 4 | 2
3 | 0 | 0 | 0
3 | 0 | 0 | 0
3 | 1 | 1 | 1
3 | 1 | 2 | 1
3 | 2 | 4 | 2
(20 rows)
-- with UNION
SELECT count(*) OVER (PARTITION BY four) FROM (SELECT * FROM tenk1 UNION ALL SELECT * FROM tenk2)s LIMIT 0;
count
-------
(0 rows)
-- via a VIEW
CREATE TEMPORARY VIEW vsumsalary AS
SELECT SUM(salary) OVER (PARTITION BY depname) FROM empsalary;
SELECT * FROM vsumsalary;
sum
-------
25100
25100
25100
25100
25100
7400
7400
14600
14600
14600
(10 rows)
-- ordering by a non-integer constant is allowed
SELECT rank() OVER (ORDER BY length('abc'));
rank
......@@ -669,5 +792,4 @@ ERROR: argument of ntile must be greater than zero
SELECT nth_value(four, 0) OVER (ORDER BY ten), ten, four FROM tenk1;
ERROR: argument of nth_value must be greater than zero
-- cleanup
DROP VIEW vsumsalary;
DROP TABLE empsalary;
......@@ -135,14 +135,35 @@ SELECT empno, depname, salary, bonus, depadj, MIN(bonus) OVER (ORDER BY empno),
THEN 200 END AS depadj FROM empsalary
)s;
-- test non-default frame specifications
SELECT four, ten,
sum(ten) over (partition by four order by ten),
last_value(ten) over (partition by four order by ten)
FROM (select distinct ten, four from tenk1) ss;
SELECT four, ten,
sum(ten) over (partition by four order by ten range between unbounded preceding and current row),
last_value(ten) over (partition by four order by ten range between unbounded preceding and current row)
FROM (select distinct ten, four from tenk1) ss;
SELECT four, ten,
sum(ten) over (partition by four order by ten range between unbounded preceding and unbounded following),
last_value(ten) over (partition by four order by ten range between unbounded preceding and unbounded following)
FROM (select distinct ten, four from tenk1) ss;
SELECT four, ten/4 as two,
sum(ten/4) over (partition by four order by ten/4 range between unbounded preceding and current row),
last_value(ten/4) over (partition by four order by ten/4 range between unbounded preceding and current row)
FROM (select distinct ten, four from tenk1) ss;
SELECT four, ten/4 as two,
sum(ten/4) over (partition by four order by ten/4 rows between unbounded preceding and current row),
last_value(ten/4) over (partition by four order by ten/4 rows between unbounded preceding and current row)
FROM (select distinct ten, four from tenk1) ss;
-- with UNION
SELECT count(*) OVER (PARTITION BY four) FROM (SELECT * FROM tenk1 UNION ALL SELECT * FROM tenk2)s LIMIT 0;
-- via a VIEW
CREATE TEMPORARY VIEW vsumsalary AS
SELECT SUM(salary) OVER (PARTITION BY depname) FROM empsalary;
SELECT * FROM vsumsalary;
-- ordering by a non-integer constant is allowed
SELECT rank() OVER (ORDER BY length('abc'));
......@@ -175,5 +196,4 @@ SELECT ntile(0) OVER (ORDER BY ten), ten, four FROM tenk1;
SELECT nth_value(four, 0) OVER (ORDER BY ten), ten, four FROM tenk1;
-- cleanup
DROP VIEW vsumsalary;
DROP TABLE empsalary;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment