From 0a459cec96d3856f476c2db298c6b52f592894e8 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Wed, 7 Feb 2018 00:06:50 -0500 Subject: Support all SQL:2011 options for window frame clauses. This patch adds the ability to use "RANGE offset PRECEDING/FOLLOWING" frame boundaries in window functions. We'd punted on that back in the original patch to add window functions, because it was not clear how to do it in a reasonably data-type-extensible fashion. That problem is resolved here by adding the ability for btree operator classes to provide an "in_range" support function that defines how to add or subtract the RANGE offset value. Factoring it this way also allows the operator class to avoid overflow problems near the ends of the datatype's range, if it wishes to expend effort on that. (In the committed patch, the integer opclasses handle that issue, but it did not seem worth the trouble to avoid overflow failures for datetime types.) The patch includes in_range support for the integer_ops opfamily (int2/int4/int8) as well as the standard datetime types. Support for other numeric types has been requested, but that seems like suitable material for a follow-on patch. In addition, the patch adds GROUPS mode which counts the offset in ORDER-BY peer groups rather than rows, and it adds the frame_exclusion options specified by SQL:2011. As far as I can see, we are now fully up to spec on window framing options. Existing behaviors remain unchanged, except that I changed the errcode for a couple of existing error reports to meet the SQL spec's expectation that negative "offset" values should be reported as SQLSTATE 22013. Internally and in relevant parts of the documentation, we now consistently use the terminology "offset PRECEDING/FOLLOWING" rather than "value PRECEDING/FOLLOWING", since the term "value" is confusingly vague. Oliver Ford, reviewed and whacked around some by me Discussion: https://postgr.es/m/CAGMVOdu9sivPAxbNN0X+q19Sfv9edEPv=HibOJhB14TJv_RCQg@mail.gmail.com --- doc/src/sgml/btree.sgml | 181 ++++++++++++++++++++++++++++++++++++++++++- doc/src/sgml/func.sgml | 5 +- doc/src/sgml/ref/select.sgml | 123 +++++++++++++++++++---------- doc/src/sgml/syntax.sgml | 144 ++++++++++++++++++++++++++-------- doc/src/sgml/xindex.sgml | 60 ++++++++++++-- 5 files changed, 432 insertions(+), 81 deletions(-) (limited to 'doc/src/sgml') diff --git a/doc/src/sgml/btree.sgml b/doc/src/sgml/btree.sgml index 9f39edc742d..10abf90189e 100644 --- a/doc/src/sgml/btree.sgml +++ b/doc/src/sgml/btree.sgml @@ -207,7 +207,7 @@ As shown in , btree defines - one required and one optional support function. + one required and two optional support functions. @@ -252,6 +252,185 @@ src/include/utils/sortsupport.h. + + in_range support functions + + + + support functions + in_range + + + + Optionally, a btree operator family may + provide in_range support function(s), registered + under support function number 3. These are not used during btree index + operations; rather, they extend the semantics of the operator family so + that it can support window clauses containing + the RANGE offset + PRECEDING + and RANGE offset + FOLLOWING frame bound types (see + ). Fundamentally, the extra + information provided is how to add or subtract + an offset value in a way that is compatible + with the family's data ordering. + + + + An in_range function must have the signature + +in_range(val type1, base type1, offset type2, sub bool, less bool) +returns bool + + val and base must be + of the same type, which is one of the types supported by the operator + family (i.e., a type for which it provides an ordering). + However, offset could be of a different type, + which might be one otherwise unsupported by the family. An example is + that the built-in time_ops family provides + an in_range function that + has offset of type interval. + A family can provide in_range functions for any of + its supported types and one or more offset + types. Each in_range function should be entered + in pg_amproc + with amproclefttype equal to type1 + and amprocrighttype equal to type2. + + + + The essential semantics of an in_range function + depend on the two boolean flag parameters. It should add or + subtract base + and offset, then + compare val to the result, as follows: + + + + if !sub and + !less, + return val >= + (base + + offset) + + + + + if !sub + and less, + return val <= + (base + + offset) + + + + + if sub + and !less, + return val >= + (base - + offset) + + + + + if sub and less, + return val <= + (base - + offset) + + + + Before doing so, the function should check the sign + of offset: if it is less than zero, raise + error ERRCODE_INVALID_PRECEDING_FOLLOWING_SIZE (22013) + with error text like invalid preceding or following size in window + function. (This is required by the SQL standard, although + nonstandard operator families might perhaps choose to ignore this + restriction, since there seems to be little semantic necessity for it.) + This requirement is delegated to the in_range + function so that the core code needn't understand what less than + zero means for a particular data type. + + + + An additional expectation is that in_range functions + should, if practical, avoid throwing an error + if base + + offset + or base - + offset would overflow. + The correct comparison result can be determined even if that value would + be out of the data type's range. Note that if the data type includes + concepts such as infinity or NaN, extra care + may be needed to ensure that in_range's results agree + with the normal sort order of the operator family. + + + + The results of the in_range function must be + consistent with the sort ordering imposed by the operator family. + To be precise, given any fixed values of offset + and sub, then: + + + + If in_range with less = + true is true for some val1 + and base, it must be true for + every val2 <= + val1 with the + same base. + + + + + If in_range with less = + true is false for some val1 + and base, it must be false for + every val2 >= + val1 with the + same base. + + + + + If in_range with less = + true is true for some val + and base1, it must be true for + every base2 >= + base1 with the + same val. + + + + + If in_range with less = + true is false for some val + and base1, it must be false for + every base2 <= + base1 with the + same val. + + + + Analogous statements with inverted conditions hold + when less = false. + + + + If the type being ordered (type1) is collatable, + the appropriate collation OID will be passed to + the in_range function, using the standard + PG_GET_COLLATION() mechanism. + + + + in_range functions need not handle NULL inputs, and + typically will be marked strict. + + diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 487c7ff7507..640ff09a7b9 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -14729,8 +14729,9 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab; partition through the last peer of the current row. This is likely to give unhelpful results for last_value and sometimes also nth_value. You can redefine the frame by - adding a suitable frame specification (RANGE or - ROWS) to the OVER clause. + adding a suitable frame specification (RANGE, + ROWS or GROUPS) to + the OVER clause. See for more information about frame specifications. diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml index 8a3e86b6db6..b5d3d3a071e 100644 --- a/doc/src/sgml/ref/select.sgml +++ b/doc/src/sgml/ref/select.sgml @@ -859,19 +859,28 @@ WINDOW window_name AS ( frame_clause can be one of -{ RANGE | ROWS } frame_start -{ RANGE | ROWS } BETWEEN frame_start AND frame_end +{ RANGE | ROWS | GROUPS } frame_start [ frame_exclusion ] +{ RANGE | ROWS | GROUPS } BETWEEN frame_start AND frame_end [ frame_exclusion ] - where frame_start and frame_end can be - one of + where frame_start + and frame_end can be one of UNBOUNDED PRECEDING -value PRECEDING +offset PRECEDING CURRENT ROW -value FOLLOWING +offset FOLLOWING UNBOUNDED FOLLOWING + + + and frame_exclusion can be one of + + +EXCLUDE CURRENT ROW +EXCLUDE GROUP +EXCLUDE TIES +EXCLUDE NO OTHERS If frame_end is omitted it defaults to CURRENT @@ -879,8 +888,10 @@ UNBOUNDED FOLLOWING frame_start cannot be UNBOUNDED FOLLOWING, frame_end cannot be UNBOUNDED PRECEDING, and the frame_end choice cannot appear earlier in the - above list than the frame_start choice — for example - RANGE BETWEEN CURRENT ROW AND value + above list of frame_start + and frame_end options than + the frame_start choice does — for example + RANGE BETWEEN CURRENT ROW AND offset PRECEDING is not allowed. @@ -888,33 +899,72 @@ UNBOUNDED FOLLOWING The default framing option is RANGE UNBOUNDED PRECEDING, which is the same as RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW; it sets the frame to be all rows from the partition start - up through the current row's last peer (a row that ORDER - BY considers equivalent to the current row, or all rows if there - is no ORDER BY). + up through the current row's last peer (a row + that the window's ORDER BY clause considers + equivalent to the current row), or all rows if there + is no ORDER BY. In general, UNBOUNDED PRECEDING means that the frame starts with the first row of the partition, and similarly UNBOUNDED FOLLOWING means that the frame ends with the last - row of the partition (regardless of RANGE or ROWS - mode). In ROWS mode, CURRENT ROW - means that the frame starts or ends with the current row; but in - RANGE mode it means that the frame starts or ends with - the current row's first or last peer in the ORDER BY ordering. - The value PRECEDING and - value FOLLOWING cases are currently only - allowed in ROWS mode. They indicate that the frame starts - or ends with the row that many rows before or after the current row. - value must be an integer expression not - containing any variables, aggregate functions, or window functions. - The value must not be null or negative; but it can be zero, which - selects the current row itself. - - - - Beware that the ROWS options can produce unpredictable + row of the partition, regardless + of RANGE, ROWS + or GROUPS mode. + In ROWS mode, CURRENT ROW means + that the frame starts or ends with the current row; but + in RANGE or GROUPS mode it means + that the frame starts or ends with the current row's first or last peer + in the ORDER BY ordering. + The offset PRECEDING and + offset FOLLOWING options + vary in meaning depending on the frame mode. + In ROWS mode, the offset + is an integer indicating that the frame starts or ends that many rows + before or after the current row. + In GROUPS mode, the offset + is an integer indicating that the frame starts or ends that many peer + groups before or after the current row's peer group, where + a peer group is a group of rows that are + equivalent according to ORDER BY. + In RANGE mode, use of + an offset option requires that there be + exactly one ORDER BY column in the window definition. + Then the frame contains those rows whose ordering column value is no + more than offset less than + (for PRECEDING) or more than + (for FOLLOWING) the current row's ordering column + value. In these cases the data type of + the offset expression depends on the data + type of the ordering column. For numeric ordering columns it is + typically of the same type as the ordering column, but for datetime + ordering columns it is an interval. + In all these cases, the value of the offset + must be non-null and non-negative. Also, while + the offset does not have to be a simple + constant, it cannot contain variables, aggregate functions, or window + functions. + + + + The frame_exclusion option allows rows around + the current row to be excluded from the frame, even if they would be + included according to the frame start and frame end options. + EXCLUDE CURRENT ROW excludes the current row from the + frame. + EXCLUDE GROUP excludes the current row and its + ordering peers from the frame. + EXCLUDE TIES excludes any peers of the current + row from the frame, but not the current row itself. + EXCLUDE NO OTHERS simply specifies explicitly the + default behavior of not excluding the current row or its peers. + + + + Beware that the ROWS mode can produce unpredictable results if the ORDER BY ordering does not order the rows - uniquely. The RANGE options are designed to ensure that - rows that are peers in the ORDER BY ordering are treated - alike; all peer rows will be in the same frame. + uniquely. The RANGE and GROUPS + modes are designed to ensure that rows that are peers in + the ORDER BY ordering are treated alike: all rows of + a given peer group will be in the frame or excluded from it. @@ -1981,17 +2031,6 @@ SELECT distributors.* WHERE distributors.name = 'Westward'; - - <literal>WINDOW</literal> Clause Restrictions - - - The SQL standard provides additional options for the window - frame_clause. - PostgreSQL currently supports only the - options listed above. - - - <literal>LIMIT</literal> and <literal>OFFSET</literal> diff --git a/doc/src/sgml/syntax.sgml b/doc/src/sgml/syntax.sgml index a938a21334b..f9905fb447b 100644 --- a/doc/src/sgml/syntax.sgml +++ b/doc/src/sgml/syntax.sgml @@ -1802,20 +1802,27 @@ FROM generate_series(1,10) AS s(i); [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ] [ frame_clause ] - and the optional frame_clause + The optional frame_clause can be one of -{ RANGE | ROWS } frame_start -{ RANGE | ROWS } BETWEEN frame_start AND frame_end +{ RANGE | ROWS | GROUPS } frame_start [ frame_exclusion ] +{ RANGE | ROWS | GROUPS } BETWEEN frame_start AND frame_end [ frame_exclusion ] - where frame_start and frame_end can be - one of + where frame_start + and frame_end can be one of UNBOUNDED PRECEDING -value PRECEDING +offset PRECEDING CURRENT ROW -value FOLLOWING +offset FOLLOWING UNBOUNDED FOLLOWING + + and frame_exclusion can be one of + +EXCLUDE CURRENT ROW +EXCLUDE GROUP +EXCLUDE TIES +EXCLUDE NO OTHERS @@ -1856,11 +1863,14 @@ UNBOUNDED FOLLOWING The frame_clause specifies the set of rows constituting the window frame, which is a subset of the current partition, for those window functions that act on - the frame instead of the whole partition. The frame can be specified in - either RANGE or ROWS mode; in either case, it - runs from the frame_start to the - frame_end. If frame_end is omitted, - it defaults to CURRENT ROW. + the frame instead of the whole partition. The set of rows in the frame + can vary depending on which row is the current row. The frame can be + specified in RANGE, ROWS + or GROUPS mode; in each case, it runs from + the frame_start to + the frame_end. + If frame_end is omitted, the end defaults + to CURRENT ROW. @@ -1871,24 +1881,91 @@ UNBOUNDED FOLLOWING - In RANGE mode, a frame_start of - CURRENT ROW means the frame starts with the current row's - first peer row (a row that ORDER BY considers - equivalent to the current row), while a frame_end of - CURRENT ROW means the frame ends with the last equivalent - ORDER BY peer. In ROWS mode, CURRENT ROW simply means - the current row. + In RANGE or GROUPS mode, + a frame_start of + CURRENT ROW means the frame starts with the current + row's first peer row (a row that the + window's ORDER BY clause sorts as equivalent to the + current row), while a frame_end of + CURRENT ROW means the frame ends with the current + row's last peer row. + In ROWS mode, CURRENT ROW simply + means the current row. - The value PRECEDING and - value FOLLOWING cases are currently only - allowed in ROWS mode. They indicate that the frame starts - or ends the specified number of rows before or after the current row. - value must be an integer expression not + In the offset PRECEDING + and offset FOLLOWING frame + options, the offset must be an expression not containing any variables, aggregate functions, or window functions. - The value must not be null or negative; but it can be zero, which - just selects the current row. + The meaning of the offset depends on the + frame mode: + + + + In ROWS mode, + the offset must yield a non-null, + non-negative integer, and the option means that the frame starts or + ends the specified number of rows before or after the current row. + + + + + In GROUPS mode, + the offset again must yield a non-null, + non-negative integer, and the option means that the frame starts or + ends the specified number of peer groups + before or after the current row's peer group, where a peer group is a + set of rows that are equivalent in the ORDER BY + ordering. (If there is no ORDER BY, the whole + partition is one peer group.) + + + + + In RANGE mode, these options require that + the ORDER BY clause specify exactly one column. + The offset specifies the maximum + difference between the value of that column in the current row and + its value in preceding or following rows of the frame. The data type + of the offset expression varies depending + on the data type of the ordering column. For numeric ordering + columns it is typically of the same type as the ordering column, + but for datetime ordering columns it is an interval. + For example, if the ordering column is of type date + or timestamp, one could write RANGE BETWEEN + '1 day' PRECEDING AND '10 days' FOLLOWING. + The offset is still required to be + non-null and non-negative, though the meaning + of non-negative depends on its data type. + + + + In any case, the distance to the end of the frame is limited by the + distance to the end of the partition, so that for rows near the partition + ends the frame might contain fewer rows than elsewhere. + + + + Notice that in both ROWS and GROUPS + mode, 0 PRECEDING and 0 FOLLOWING + are equivalent to CURRENT ROW. This normally holds + in RANGE mode as well, for an appropriate + data-type-specific meaning of zero. + + + + The frame_exclusion option allows rows around + the current row to be excluded from the frame, even if they would be + included according to the frame start and frame end options. + EXCLUDE CURRENT ROW excludes the current row from the + frame. + EXCLUDE GROUP excludes the current row and its + ordering peers from the frame. + EXCLUDE TIES excludes any peers of the current + row from the frame, but not the current row itself. + EXCLUDE NO OTHERS simply specifies explicitly the + default behavior of not excluding the current row or its peers. @@ -1896,9 +1973,9 @@ UNBOUNDED FOLLOWING which is the same as RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW. With ORDER BY, this sets the frame to be all rows from the partition start up through the current row's last - ORDER BY peer. Without ORDER BY, all rows of the partition are - included in the window frame, since all rows become peers of the current - row. + ORDER BY peer. Without ORDER BY, + this means all rows of the partition are included in the window frame, + since all rows become peers of the current row. @@ -1906,9 +1983,14 @@ UNBOUNDED FOLLOWING frame_start cannot be UNBOUNDED FOLLOWING, frame_end cannot be UNBOUNDED PRECEDING, and the frame_end choice cannot appear earlier in the - above list than the frame_start choice — for example - RANGE BETWEEN CURRENT ROW AND value + above list of frame_start + and frame_end options than + the frame_start choice does — for example + RANGE BETWEEN CURRENT ROW AND offset PRECEDING is not allowed. + But, for example, ROWS BETWEEN 7 PRECEDING AND 8 + PRECEDING is allowed, even though it would never select any + rows. diff --git a/doc/src/sgml/xindex.sgml b/doc/src/sgml/xindex.sgml index e40131473fe..9f5c0c3fb2c 100644 --- a/doc/src/sgml/xindex.sgml +++ b/doc/src/sgml/xindex.sgml @@ -401,7 +401,8 @@ - B-trees require a single support function, and allow a second one to be + B-trees require a comparison support function, + and allow two additional support functions to be supplied at the operator class author's option, as shown in . The requirements for these support functions are explained further in @@ -433,6 +434,13 @@ 2 + + + Compare a test value to a base value plus/minus an offset, and return + true or false according to the comparison result (optional) + + 3 + @@ -971,7 +979,8 @@ DEFAULT FOR TYPE int8 USING btree FAMILY integer_ops AS OPERATOR 4 >= , OPERATOR 5 > , FUNCTION 1 btint8cmp(int8, int8) , - FUNCTION 2 btint8sortsupport(internal) ; + FUNCTION 2 btint8sortsupport(internal) , + FUNCTION 3 in_range(int8, int8, int8, boolean, boolean) ; CREATE OPERATOR CLASS int4_ops DEFAULT FOR TYPE int4 USING btree FAMILY integer_ops AS @@ -982,7 +991,8 @@ DEFAULT FOR TYPE int4 USING btree FAMILY integer_ops AS OPERATOR 4 >= , OPERATOR 5 > , FUNCTION 1 btint4cmp(int4, int4) , - FUNCTION 2 btint4sortsupport(internal) ; + FUNCTION 2 btint4sortsupport(internal) , + FUNCTION 3 in_range(int4, int4, int4, boolean, boolean) ; CREATE OPERATOR CLASS int2_ops DEFAULT FOR TYPE int2 USING btree FAMILY integer_ops AS @@ -993,7 +1003,8 @@ DEFAULT FOR TYPE int2 USING btree FAMILY integer_ops AS OPERATOR 4 >= , OPERATOR 5 > , FUNCTION 1 btint2cmp(int2, int2) , - FUNCTION 2 btint2sortsupport(internal) ; + FUNCTION 2 btint2sortsupport(internal) , + FUNCTION 3 in_range(int2, int2, int2, boolean, boolean) ; ALTER OPERATOR FAMILY integer_ops USING btree ADD -- cross-type comparisons int8 vs int2 @@ -1042,7 +1053,13 @@ ALTER OPERATOR FAMILY integer_ops USING btree ADD OPERATOR 3 = (int2, int4) , OPERATOR 4 >= (int2, int4) , OPERATOR 5 > (int2, int4) , - FUNCTION 1 btint24cmp(int2, int4) ; + FUNCTION 1 btint24cmp(int2, int4) , + + -- cross-type in_range functions + FUNCTION 3 in_range(int4, int4, int8, boolean, boolean) , + FUNCTION 3 in_range(int4, int4, int2, boolean, boolean) , + FUNCTION 3 in_range(int2, int2, int8, boolean, boolean) , + FUNCTION 3 in_range(int2, int2, int4, boolean, boolean) ; ]]> @@ -1180,6 +1197,39 @@ SELECT * FROM mytable ORDER BY somecol USING ~<~; then array equality is supported, but not ordering comparisons. + + Another SQL feature that requires even more data-type-specific knowledge + is the RANGE offset + PRECEDING/FOLLOWING framing option + for window functions (see ). + For a query such as + +SELECT sum(x) OVER (ORDER BY x RANGE BETWEEN 5 PRECEDING AND 10 FOLLOWING) + FROM mytable; + + it is not sufficient to know how to order by x; + the database must also understand how to subtract 5 or + add 10 to the current row's value of x + to identify the bounds of the current window frame. Comparing the + resulting bounds to other rows' values of x is + possible using the comparison operators provided by the B-tree operator + class that defines the ORDER BY ordering — but + addition and subtraction operators are not part of the operator class, so + which ones should be used? Hard-wiring that choice would be undesirable, + because different sort orders (different B-tree operator classes) might + need different behavior. Therefore, a B-tree operator class can specify + an in_range support function that encapsulates the + addition and subtraction behaviors that make sense for its sort order. + It can even provide more than one in_range support function, in case + there is more than one data type that makes sense to use as the offset + in RANGE clauses. + If the B-tree operator class associated with the window's ORDER + BY clause does not have a matching in_range support function, + the RANGE offset + PRECEDING/FOLLOWING + option is not supported. + + Another important point is that an equality operator that appears in a hash operator family is a candidate for hash joins, -- cgit v1.2.3