Unverified 提交 47e0deb3 authored 作者: Evgenij Ryazanov's avatar Evgenij Ryazanov 提交者: GitHub

Merge pull request #1461 from katzyn/window

Add WINDOW clause support
...@@ -8,6 +8,7 @@ SELECT [ TOP term [ PERCENT ] [ WITH TIES ] ] ...@@ -8,6 +8,7 @@ SELECT [ TOP term [ PERCENT ] [ WITH TIES ] ]
selectExpression [,...] selectExpression [,...]
FROM tableExpression [,...] [ WHERE expression ] FROM tableExpression [,...] [ WHERE expression ]
[ GROUP BY expression [,...] ] [ HAVING expression ] [ GROUP BY expression [,...] ] [ HAVING expression ]
[ WINDOW { { windowName AS windowSpecification } [,...] } ]
[ { UNION [ ALL ] | MINUS | EXCEPT | INTERSECT } select ] [ { UNION [ ALL ] | MINUS | EXCEPT | INTERSECT } select ]
[ ORDER BY order [,...] ] [ ORDER BY order [,...] ]
[ LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] ] [ LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] ]
...@@ -2533,17 +2534,27 @@ The column list of the resulting table is C1, C2, and so on. ...@@ -2533,17 +2534,27 @@ The column list of the resulting table is C1, C2, and so on.
SELECT * FROM (VALUES(1, 'Hello'), (2, 'World')) AS V; SELECT * FROM (VALUES(1, 'Hello'), (2, 'World')) AS V;
" "
"Other Grammar","Window specification"," "Other Grammar","Window name or specification","
([PARTITION BY expression [,...]] [ORDER BY order [,...]] windowName | windowSpecification
[windowFrame])
"," ","
A window specification for a window function or aggregate. A window name or inline specification for a window function or aggregate.
Window functions are currently experimental in H2 and should be used with caution. Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries. They also may require a lot of memory for large queries.
"," ","
() W1
(ORDER BY ID) (ORDER BY ID)
"
"Other Grammar","Window specification","
([existingWindowName]
[PARTITION BY expression [,...]] [ORDER BY order [,...]]
[windowFrame])
","
A window specification for a window, window function or aggregate.
","
()
(W1 ORDER BY ID)
(PARTITION BY CATEGORY) (PARTITION BY CATEGORY)
(PARTITION BY CATEGORY ORDER BY NAME, ID) (PARTITION BY CATEGORY ORDER BY NAME, ID)
(ORDER BY Y RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES) (ORDER BY Y RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES)
...@@ -3303,7 +3314,7 @@ INTERVAL MINUTE TO SECOND ...@@ -3303,7 +3314,7 @@ INTERVAL MINUTE TO SECOND
"Functions (Aggregate)","AVG"," "Functions (Aggregate)","AVG","
AVG ( [ DISTINCT ] { numeric } ) AVG ( [ DISTINCT ] { numeric } )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The average (mean) value. The average (mean) value.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3315,7 +3326,7 @@ AVG(X) ...@@ -3315,7 +3326,7 @@ AVG(X)
"Functions (Aggregate)","BIT_AND"," "Functions (Aggregate)","BIT_AND","
BIT_AND(expression) BIT_AND(expression)
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The bitwise AND of all non-null values. The bitwise AND of all non-null values.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3326,7 +3337,7 @@ BIT_AND(ID) ...@@ -3326,7 +3337,7 @@ BIT_AND(ID)
"Functions (Aggregate)","BIT_OR"," "Functions (Aggregate)","BIT_OR","
BIT_OR(expression) BIT_OR(expression)
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The bitwise OR of all non-null values. The bitwise OR of all non-null values.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3337,7 +3348,7 @@ BIT_OR(ID) ...@@ -3337,7 +3348,7 @@ BIT_OR(ID)
"Functions (Aggregate)","BOOL_AND"," "Functions (Aggregate)","BOOL_AND","
BOOL_AND(boolean) BOOL_AND(boolean)
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
Returns true if all expressions are true. Returns true if all expressions are true.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3348,7 +3359,7 @@ BOOL_AND(ID>10) ...@@ -3348,7 +3359,7 @@ BOOL_AND(ID>10)
"Functions (Aggregate)","BOOL_OR"," "Functions (Aggregate)","BOOL_OR","
BOOL_OR(boolean) BOOL_OR(boolean)
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
Returns true if any expression is true. Returns true if any expression is true.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3359,7 +3370,7 @@ BOOL_OR(NAME LIKE 'W%') ...@@ -3359,7 +3370,7 @@ BOOL_OR(NAME LIKE 'W%')
"Functions (Aggregate)","COUNT"," "Functions (Aggregate)","COUNT","
COUNT( { * | { [ DISTINCT ] expression } } ) COUNT( { * | { [ DISTINCT ] expression } } )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The count of all row, or of the non-null values. The count of all row, or of the non-null values.
This method returns a long. This method returns a long.
...@@ -3373,7 +3384,7 @@ COUNT(*) ...@@ -3373,7 +3384,7 @@ COUNT(*)
GROUP_CONCAT ( [ DISTINCT ] string GROUP_CONCAT ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ] [ ORDER BY { expression [ ASC | DESC ] } [,...] ]
[ SEPARATOR expression ] ) [ SEPARATOR expression ] )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
Concatenates strings with a separator. Concatenates strings with a separator.
The default separator is a ',' (without space). The default separator is a ',' (without space).
...@@ -3387,7 +3398,7 @@ GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ') ...@@ -3387,7 +3398,7 @@ GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ')
"Functions (Aggregate)","ARRAY_AGG"," "Functions (Aggregate)","ARRAY_AGG","
ARRAY_AGG ( [ DISTINCT ] string ARRAY_AGG ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ] ) [ ORDER BY { expression [ ASC | DESC ] } [,...] ] )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
Aggregate the value into an array. Aggregate the value into an array.
This method returns an array. This method returns an array.
...@@ -3399,7 +3410,7 @@ ARRAY_AGG(NAME ORDER BY ID) ...@@ -3399,7 +3410,7 @@ ARRAY_AGG(NAME ORDER BY ID)
"Functions (Aggregate)","MAX"," "Functions (Aggregate)","MAX","
MAX(value) MAX(value)
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The highest value. The highest value.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3411,7 +3422,7 @@ MAX(NAME) ...@@ -3411,7 +3422,7 @@ MAX(NAME)
"Functions (Aggregate)","MIN"," "Functions (Aggregate)","MIN","
MIN(value) MIN(value)
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The lowest value. The lowest value.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3423,7 +3434,7 @@ MIN(NAME) ...@@ -3423,7 +3434,7 @@ MIN(NAME)
"Functions (Aggregate)","SUM"," "Functions (Aggregate)","SUM","
SUM( [ DISTINCT ] { numeric } ) SUM( [ DISTINCT ] { numeric } )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The sum of all values. The sum of all values.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3436,7 +3447,7 @@ SUM(X) ...@@ -3436,7 +3447,7 @@ SUM(X)
"Functions (Aggregate)","SELECTIVITY"," "Functions (Aggregate)","SELECTIVITY","
SELECTIVITY(value) SELECTIVITY(value)
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
Estimates the selectivity (0-100) of a value. Estimates the selectivity (0-100) of a value.
The value is defined as (100 * distinctCount / rowCount). The value is defined as (100 * distinctCount / rowCount).
...@@ -3449,7 +3460,7 @@ SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000 ...@@ -3449,7 +3460,7 @@ SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000
"Functions (Aggregate)","STDDEV_POP"," "Functions (Aggregate)","STDDEV_POP","
STDDEV_POP( [ DISTINCT ] numeric ) STDDEV_POP( [ DISTINCT ] numeric )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The population standard deviation. The population standard deviation.
This method returns a double. This method returns a double.
...@@ -3461,7 +3472,7 @@ STDDEV_POP(X) ...@@ -3461,7 +3472,7 @@ STDDEV_POP(X)
"Functions (Aggregate)","STDDEV_SAMP"," "Functions (Aggregate)","STDDEV_SAMP","
STDDEV_SAMP( [ DISTINCT ] numeric ) STDDEV_SAMP( [ DISTINCT ] numeric )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The sample standard deviation. The sample standard deviation.
This method returns a double. This method returns a double.
...@@ -3473,7 +3484,7 @@ STDDEV(X) ...@@ -3473,7 +3484,7 @@ STDDEV(X)
"Functions (Aggregate)","VAR_POP"," "Functions (Aggregate)","VAR_POP","
VAR_POP( [ DISTINCT ] numeric ) VAR_POP( [ DISTINCT ] numeric )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The population variance (square of the population standard deviation). The population variance (square of the population standard deviation).
This method returns a double. This method returns a double.
...@@ -3485,7 +3496,7 @@ VAR_POP(X) ...@@ -3485,7 +3496,7 @@ VAR_POP(X)
"Functions (Aggregate)","VAR_SAMP"," "Functions (Aggregate)","VAR_SAMP","
VAR_SAMP( [ DISTINCT ] numeric ) VAR_SAMP( [ DISTINCT ] numeric )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The sample variance (square of the sample standard deviation). The sample variance (square of the sample standard deviation).
This method returns a double. This method returns a double.
...@@ -3497,7 +3508,7 @@ VAR_SAMP(X) ...@@ -3497,7 +3508,7 @@ VAR_SAMP(X)
"Functions (Aggregate)","MEDIAN"," "Functions (Aggregate)","MEDIAN","
MEDIAN( [ DISTINCT ] value ) MEDIAN( [ DISTINCT ] value )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
The value separating the higher half of a values from the lower half. The value separating the higher half of a values from the lower half.
Returns the middle value or an interpolated value between two middle values if number of values is even. Returns the middle value or an interpolated value between two middle values if number of values is even.
...@@ -3512,7 +3523,7 @@ MEDIAN(X) ...@@ -3512,7 +3523,7 @@ MEDIAN(X)
"Functions (Aggregate)","MODE"," "Functions (Aggregate)","MODE","
{ MODE( value ) [ ORDER BY expression [ ASC | DESC ] ] } { MODE( value ) [ ORDER BY expression [ ASC | DESC ] ] }
| { MODE() WITHIN GROUP(ORDER BY expression [ ASC | DESC ]) } | { MODE() WITHIN GROUP(ORDER BY expression [ ASC | DESC ]) }
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
Returns the value that occurs with the greatest frequency. Returns the value that occurs with the greatest frequency.
If there are multiple values with the same frequency only one value will be returned. If there are multiple values with the same frequency only one value will be returned.
...@@ -3532,7 +3543,7 @@ MODE() WITHIN GROUP(ORDER BY X) ...@@ -3532,7 +3543,7 @@ MODE() WITHIN GROUP(ORDER BY X)
"Functions (Aggregate)","ENVELOPE"," "Functions (Aggregate)","ENVELOPE","
ENVELOPE( value ) ENVELOPE( value )
[FILTER (WHERE expression)] [OVER windowSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
"," ","
Returns the minimum bounding box that encloses all specified GEOMETRY values. Returns the minimum bounding box that encloses all specified GEOMETRY values.
Only 2D coordinate plane is supported. Only 2D coordinate plane is supported.
...@@ -5105,7 +5116,7 @@ H2VERSION() ...@@ -5105,7 +5116,7 @@ H2VERSION()
" "
"Functions (Window)","ROW_NUMBER"," "Functions (Window)","ROW_NUMBER","
ROW_NUMBER() OVER windowSpecification ROW_NUMBER() OVER windowNameOrSpecification
"," ","
Returns the number of the current row starting with 1. Returns the number of the current row starting with 1.
...@@ -5118,7 +5129,7 @@ SELECT ROW_NUMBER() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST; ...@@ -5118,7 +5129,7 @@ SELECT ROW_NUMBER() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
" "
"Functions (Window)","RANK"," "Functions (Window)","RANK","
RANK() OVER windowSpecification RANK() OVER windowNameOrSpecification
"," ","
Returns the rank of the current row. Returns the rank of the current row.
The rank of a row is the number of rows that precede this row plus 1. The rank of a row is the number of rows that precede this row plus 1.
...@@ -5133,7 +5144,7 @@ SELECT RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST; ...@@ -5133,7 +5144,7 @@ SELECT RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
" "
"Functions (Window)","DENSE_RANK"," "Functions (Window)","DENSE_RANK","
DENSE_RANK() OVER windowSpecification DENSE_RANK() OVER windowNameOrSpecification
"," ","
Returns the dense rank of the current row. Returns the dense rank of the current row.
The rank of a row is the number of groups of rows with the same values in ORDER BY columns that precede group with this row plus 1. The rank of a row is the number of groups of rows with the same values in ORDER BY columns that precede group with this row plus 1.
...@@ -5148,7 +5159,7 @@ SELECT DENSE_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST; ...@@ -5148,7 +5159,7 @@ SELECT DENSE_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
" "
"Functions (Window)","PERCENT_RANK"," "Functions (Window)","PERCENT_RANK","
PERCENT_RANK() OVER windowSpecification PERCENT_RANK() OVER windowNameOrSpecification
"," ","
Returns the relative rank of the current row. Returns the relative rank of the current row.
The relative rank is calculated as (RANK - 1) / (NR - 1), The relative rank is calculated as (RANK - 1) / (NR - 1),
...@@ -5162,7 +5173,7 @@ SELECT PERCENT_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST; ...@@ -5162,7 +5173,7 @@ SELECT PERCENT_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
" "
"Functions (Window)","CUME_DIST"," "Functions (Window)","CUME_DIST","
CUME_DIST() OVER windowSpecification CUME_DIST() OVER windowNameOrSpecification
"," ","
Returns the relative rank of the current row. Returns the relative rank of the current row.
The relative rank is calculated as NP / NR The relative rank is calculated as NP / NR
...@@ -5177,7 +5188,7 @@ SELECT CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST; ...@@ -5177,7 +5188,7 @@ SELECT CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
" "
"Functions (Window)","NTILE"," "Functions (Window)","NTILE","
NTILE(int) OVER windowSpecification NTILE(int) OVER windowNameOrSpecification
"," ","
Distributes the rows into a specified number of groups. Distributes the rows into a specified number of groups.
Number of groups should be a positive integer value. Number of groups should be a positive integer value.
...@@ -5194,7 +5205,7 @@ SELECT NTILE(5) OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST; ...@@ -5194,7 +5205,7 @@ SELECT NTILE(5) OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"Functions (Window)","LEAD"," "Functions (Window)","LEAD","
LEAD(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS] LEAD(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
OVER windowSpecification OVER windowNameOrSpecification
"," ","
Returns the value in a next row with specified offset relative to the current row. Returns the value in a next row with specified offset relative to the current row.
Offset must be non-negative. Offset must be non-negative.
...@@ -5214,7 +5225,7 @@ SELECT LEAD(X, 2, 0) IGNORE NULLS OVER ( ...@@ -5214,7 +5225,7 @@ SELECT LEAD(X, 2, 0) IGNORE NULLS OVER (
"Functions (Window)","LAG"," "Functions (Window)","LAG","
LAG(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS] LAG(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
OVER windowSpecification OVER windowNameOrSpecification
"," ","
Returns the value in a previous row with specified offset relative to the current row. Returns the value in a previous row with specified offset relative to the current row.
Offset must be non-negative. Offset must be non-negative.
...@@ -5233,7 +5244,8 @@ SELECT LAG(X, 2, 0) IGNORE NULLS OVER ( ...@@ -5233,7 +5244,8 @@ SELECT LAG(X, 2, 0) IGNORE NULLS OVER (
" "
"Functions (Window)","FIRST_VALUE"," "Functions (Window)","FIRST_VALUE","
FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS] OVER windowSpecification FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
"," ","
Returns the first value in a window. Returns the first value in a window.
If IGNORE NULLS is specified null values are skipped and the function returns first non-null value, if any. If IGNORE NULLS is specified null values are skipped and the function returns first non-null value, if any.
...@@ -5246,7 +5258,8 @@ SELECT FIRST_VALUE(X) IGNORE NULLS OVER (PARTITION BY CATEGORY ORDER BY ID), * F ...@@ -5246,7 +5258,8 @@ SELECT FIRST_VALUE(X) IGNORE NULLS OVER (PARTITION BY CATEGORY ORDER BY ID), * F
" "
"Functions (Window)","LAST_VALUE"," "Functions (Window)","LAST_VALUE","
LAST_VALUE(value) [{RESPECT|IGNORE} NULLS] OVER windowSpecification LAST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
"," ","
Returns the last value in a window. Returns the last value in a window.
If IGNORE NULLS is specified null values are skipped and the function returns last non-null value before them, if any; If IGNORE NULLS is specified null values are skipped and the function returns last non-null value before them, if any;
...@@ -5265,7 +5278,7 @@ SELECT LAST_VALUE(X) IGNORE NULLS OVER ( ...@@ -5265,7 +5278,7 @@ SELECT LAST_VALUE(X) IGNORE NULLS OVER (
"Functions (Window)","NTH_VALUE"," "Functions (Window)","NTH_VALUE","
NTH_VALUE(value, nInt) [FROM {FIRST|LAST}] [{RESPECT|IGNORE} NULLS] NTH_VALUE(value, nInt) [FROM {FIRST|LAST}] [{RESPECT|IGNORE} NULLS]
OVER windowSpecification OVER windowNameOrSpecification
"," ","
Returns the value in a row with a specified relative number in a window. Returns the value in a row with a specified relative number in a window.
Relative row number must be positive. Relative row number must be positive.
......
...@@ -488,7 +488,7 @@ ALL, CHECK, CONSTRAINT, CROSS, CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP, DI ...@@ -488,7 +488,7 @@ ALL, CHECK, CONSTRAINT, CROSS, CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP, DI
EXISTS, FALSE, FETCH, FOR, FOREIGN, FROM, FULL, GROUP, HAVING, INNER, INTERSECT, INTERSECTS, EXISTS, FALSE, FETCH, FOR, FOREIGN, FROM, FULL, GROUP, HAVING, INNER, INTERSECT, INTERSECTS,
IS, JOIN, LIKE, LIMIT, LOCALTIME, LOCALTIMESTAMP, MINUS, NATURAL, NOT, NULL, OFFSET, ON, ORDER, IS, JOIN, LIKE, LIMIT, LOCALTIME, LOCALTIMESTAMP, MINUS, NATURAL, NOT, NULL, OFFSET, ON, ORDER,
PRIMARY, ROWNUM, SELECT, SYSDATE, SYSTIME, SYSTIMESTAMP, TODAY, TOP, TRUE, UNION, UNIQUE, WHERE, PRIMARY, ROWNUM, SELECT, SYSDATE, SYSTIME, SYSTIMESTAMP, TODAY, TOP, TRUE, UNION, UNIQUE, WHERE,
WITH WINDOW, WITH
</code> </code>
</p><p> </p><p>
Certain words of this list are keywords because they are functions that can be used without '()' for compatibility, Certain words of this list are keywords because they are functions that can be used without '()' for compatibility,
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=Cannot change the setting {0} when the database is already open 90133=Cannot change the setting {0} when the database is already open
90134=Access to the class {0} is denied 90134=Access to the class {0} is denied
90135=The database is open in exclusive mode; can not open additional connections 90135=The database is open in exclusive mode; can not open additional connections
90136=Unsupported outer join condition: {0} 90136=Window not found: {0}
90137=Can only assign to a variable, not to: {0} 90137=Can only assign to a variable, not to: {0}
90138=Invalid database name: {0} 90138=Invalid database name: {0}
90139=The public static Java method was not found: {0} 90139=The public static Java method was not found: {0}
......
...@@ -1926,6 +1926,16 @@ public class ErrorCode { ...@@ -1926,6 +1926,16 @@ public class ErrorCode {
*/ */
public static final int DATABASE_IS_IN_EXCLUSIVE_MODE = 90135; public static final int DATABASE_IS_IN_EXCLUSIVE_MODE = 90135;
/**
* The error with code <code>90136</code> is thrown when
* trying to reference a window that does not exist.
* Example:
* <pre>
* SELECT LEAD(X) OVER W FROM TEST;
* </pre>
*/
public static final int WINDOW_NOT_FOUND_1 = 90136;
/** /**
* The error with code <code>90137</code> is thrown when * The error with code <code>90137</code> is thrown when
* trying to assign a value to something that is not a variable. * trying to assign a value to something that is not a variable.
...@@ -2009,7 +2019,7 @@ public class ErrorCode { ...@@ -2009,7 +2019,7 @@ public class ErrorCode {
public static final int AUTHENTICATOR_NOT_AVAILABLE = 90144; public static final int AUTHENTICATOR_NOT_AVAILABLE = 90144;
// next are 90136, 90145 // next is 90145
private ErrorCode() { private ErrorCode() {
// utility class // utility class
......
...@@ -44,6 +44,7 @@ import static org.h2.util.ParserUtil.TRUE; ...@@ -44,6 +44,7 @@ import static org.h2.util.ParserUtil.TRUE;
import static org.h2.util.ParserUtil.UNION; import static org.h2.util.ParserUtil.UNION;
import static org.h2.util.ParserUtil.UNIQUE; import static org.h2.util.ParserUtil.UNIQUE;
import static org.h2.util.ParserUtil.WHERE; import static org.h2.util.ParserUtil.WHERE;
import static org.h2.util.ParserUtil.WINDOW;
import static org.h2.util.ParserUtil.WITH; import static org.h2.util.ParserUtil.WITH;
import java.math.BigDecimal; import java.math.BigDecimal;
...@@ -482,6 +483,8 @@ public class Parser { ...@@ -482,6 +483,8 @@ public class Parser {
"UNIQUE", "UNIQUE",
// WHERE // WHERE
"WHERE", "WHERE",
// WINDOW
"WINDOW",
// WITH // WITH
"WITH", "WITH",
// PARAMETER // PARAMETER
...@@ -2628,6 +2631,17 @@ public class Parser { ...@@ -2628,6 +2631,17 @@ public class Parser {
Expression condition = readExpression(); Expression condition = readExpression();
command.setHaving(condition); command.setHaving(condition);
} }
if (readIf(WINDOW)) {
do {
int index = parseIndex;
String name = readAliasIdentifier();
read("AS");
Window w = readWindowSpecification();
if (!currentSelect.addWindow(name, w)) {
throw DbException.getSyntaxError(sqlCommand, index, "unique identifier");
}
} while (readIf(COMMA));
}
command.setParameterList(parameters); command.setParameterList(parameters);
currentSelect = oldSelect; currentSelect = oldSelect;
setSQL(command, "SELECT", start); setSQL(command, "SELECT", start);
...@@ -3049,7 +3063,7 @@ public class Parser { ...@@ -3049,7 +3063,7 @@ public class Parser {
} }
Window over = null; Window over = null;
if (readIf("OVER")) { if (readIf("OVER")) {
over = readWindowSpecification(); over = readWindowNameOrSpecification();
aggregate.setOverCondition(over); aggregate.setOverCondition(over);
currentSelect.setWindowQuery(); currentSelect.setWindowQuery();
} else if (!isAggregate) { } else if (!isAggregate) {
...@@ -3059,8 +3073,24 @@ public class Parser { ...@@ -3059,8 +3073,24 @@ public class Parser {
} }
} }
private Window readWindowNameOrSpecification() {
return isToken(OPEN_PAREN) ? readWindowSpecification() : new Window(readAliasIdentifier(), null, null, null);
}
private Window readWindowSpecification() { private Window readWindowSpecification() {
read(OPEN_PAREN); read(OPEN_PAREN);
String parent = null;
if (currentTokenType == IDENTIFIER) {
String token = currentToken;
if (currentTokenQuoted || ( //
!equalsToken(token, "PARTITION") //
&& !equalsToken(token, "ROWS") //
&& !equalsToken(token, "RANGE") //
&& !equalsToken(token, "GROUPS"))) {
parent = token;
read();
}
}
ArrayList<Expression> partitionBy = null; ArrayList<Expression> partitionBy = null;
if (readIf("PARTITION")) { if (readIf("PARTITION")) {
read("BY"); read("BY");
...@@ -3077,7 +3107,7 @@ public class Parser { ...@@ -3077,7 +3107,7 @@ public class Parser {
} }
WindowFrame frame = readWindowFrame(); WindowFrame frame = readWindowFrame();
read(CLOSE_PAREN); read(CLOSE_PAREN);
return new Window(partitionBy, orderBy, frame); return new Window(parent, partitionBy, orderBy, frame);
} }
private WindowFrame readWindowFrame() { private WindowFrame readWindowFrame() {
......
...@@ -8,6 +8,7 @@ package org.h2.command.dml; ...@@ -8,6 +8,7 @@ package org.h2.command.dml;
import java.util.ArrayList; import java.util.ArrayList;
import java.util.Arrays; import java.util.Arrays;
import java.util.BitSet; import java.util.BitSet;
import java.util.HashMap;
import java.util.HashSet; import java.util.HashSet;
import org.h2.api.ErrorCode; import org.h2.api.ErrorCode;
import org.h2.api.Trigger; import org.h2.api.Trigger;
...@@ -25,6 +26,7 @@ import org.h2.expression.ExpressionVisitor; ...@@ -25,6 +26,7 @@ import org.h2.expression.ExpressionVisitor;
import org.h2.expression.Parameter; import org.h2.expression.Parameter;
import org.h2.expression.Wildcard; import org.h2.expression.Wildcard;
import org.h2.expression.aggregate.Aggregate; import org.h2.expression.aggregate.Aggregate;
import org.h2.expression.aggregate.Window;
import org.h2.index.Cursor; import org.h2.index.Cursor;
import org.h2.index.Index; import org.h2.index.Index;
import org.h2.index.IndexType; import org.h2.index.IndexType;
...@@ -116,6 +118,8 @@ public class Select extends Query { ...@@ -116,6 +118,8 @@ public class Select extends Query {
private boolean isGroupWindowStage2; private boolean isGroupWindowStage2;
private HashMap<String, Window> windows;
public Select(Session session) { public Select(Session session) {
super(session); super(session);
} }
...@@ -214,6 +218,30 @@ public class Select extends Query { ...@@ -214,6 +218,30 @@ public class Select extends Query {
return distinct || distinctExpressions != null; return distinct || distinctExpressions != null;
} }
/**
* Adds a named window definition.
*
* @param name name
* @param window window definition
* @return true if a new definition was added, false if old definition was replaced
*/
public boolean addWindow(String name, Window window) {
if (windows == null) {
windows = new HashMap<>();
}
return windows.put(name, window) == null;
}
/**
* Returns a window with specified name, or null.
*
* @param name name of the window
* @return the window with specified name, or null
*/
public Window getWindow(String name) {
return windows != null ? windows.get(name) : null;
}
/** /**
* Add a condition to the list of conditions. * Add a condition to the list of conditions.
* *
......
...@@ -7,9 +7,11 @@ package org.h2.expression.aggregate; ...@@ -7,9 +7,11 @@ package org.h2.expression.aggregate;
import java.util.ArrayList; import java.util.ArrayList;
import org.h2.api.ErrorCode;
import org.h2.command.dml.SelectOrderBy; import org.h2.command.dml.SelectOrderBy;
import org.h2.engine.Session; import org.h2.engine.Session;
import org.h2.expression.Expression; import org.h2.expression.Expression;
import org.h2.message.DbException;
import org.h2.result.SortOrder; import org.h2.result.SortOrder;
import org.h2.table.ColumnResolver; import org.h2.table.ColumnResolver;
import org.h2.table.TableFilter; import org.h2.table.TableFilter;
...@@ -22,11 +24,13 @@ import org.h2.value.ValueArray; ...@@ -22,11 +24,13 @@ import org.h2.value.ValueArray;
*/ */
public final class Window { public final class Window {
private final ArrayList<Expression> partitionBy; private ArrayList<Expression> partitionBy;
private final ArrayList<SelectOrderBy> orderBy; private ArrayList<SelectOrderBy> orderBy;
private final WindowFrame frame; private WindowFrame frame;
private String parent;
/** /**
* @param builder * @param builder
...@@ -54,6 +58,8 @@ public final class Window { ...@@ -54,6 +58,8 @@ public final class Window {
/** /**
* Creates a new instance of window clause. * Creates a new instance of window clause.
* *
* @param parent
* name of the parent window
* @param partitionBy * @param partitionBy
* PARTITION BY clause, or null * PARTITION BY clause, or null
* @param orderBy * @param orderBy
...@@ -61,7 +67,9 @@ public final class Window { ...@@ -61,7 +67,9 @@ public final class Window {
* @param frame * @param frame
* window frame clause * window frame clause
*/ */
public Window(ArrayList<Expression> partitionBy, ArrayList<SelectOrderBy> orderBy, WindowFrame frame) { public Window(String parent, ArrayList<Expression> partitionBy, ArrayList<SelectOrderBy> orderBy,
WindowFrame frame) {
this.parent = parent;
this.partitionBy = partitionBy; this.partitionBy = partitionBy;
this.orderBy = orderBy; this.orderBy = orderBy;
this.frame = frame; this.frame = frame;
...@@ -77,6 +85,7 @@ public final class Window { ...@@ -77,6 +85,7 @@ public final class Window {
* @see Expression#mapColumns(ColumnResolver, int) * @see Expression#mapColumns(ColumnResolver, int)
*/ */
public void mapColumns(ColumnResolver resolver, int level) { public void mapColumns(ColumnResolver resolver, int level) {
resolveWindows(resolver);
if (partitionBy != null) { if (partitionBy != null) {
for (Expression e : partitionBy) { for (Expression e : partitionBy) {
e.mapColumns(resolver, level); e.mapColumns(resolver, level);
...@@ -89,6 +98,26 @@ public final class Window { ...@@ -89,6 +98,26 @@ public final class Window {
} }
} }
private void resolveWindows(ColumnResolver resolver) {
if (parent != null) {
Window p = resolver.getSelect().getWindow(parent);
if (p == null) {
throw DbException.get(ErrorCode.WINDOW_NOT_FOUND_1, parent);
}
p.resolveWindows(resolver);
if (partitionBy == null) {
partitionBy = p.partitionBy;
}
if (orderBy == null) {
orderBy = p.orderBy;
}
if (frame == null) {
frame = p.frame;
}
parent = null;
}
}
/** /**
* Try to optimize the window conditions. * Try to optimize the window conditions.
* *
......
...@@ -1549,7 +1549,7 @@ public class JdbcDatabaseMetaData extends TraceObject implements ...@@ -1549,7 +1549,7 @@ public class JdbcDatabaseMetaData extends TraceObject implements
* HAVING, INNER, INTERSECT, INTERSECTS, IS, JOIN, LIKE, LIMIT, LOCALTIME, * HAVING, INNER, INTERSECT, INTERSECTS, IS, JOIN, LIKE, LIMIT, LOCALTIME,
* LOCALTIMESTAMP, MINUS, NATURAL, NOT, NULL, OFFSET, ON, ORDER, PRIMARY, ROWNUM, * LOCALTIMESTAMP, MINUS, NATURAL, NOT, NULL, OFFSET, ON, ORDER, PRIMARY, ROWNUM,
* SELECT, SYSDATE, SYSTIME, SYSTIMESTAMP, TODAY, TOP, TRUE, UNION, UNIQUE, WHERE, * SELECT, SYSDATE, SYSTIME, SYSTIMESTAMP, TODAY, TOP, TRUE, UNION, UNIQUE, WHERE,
* WITH * WINDOW, WITH
* </pre> * </pre>
* *
* @return a list of additional the keywords * @return a list of additional the keywords
......
...@@ -562,6 +562,7 @@ public class DbException extends RuntimeException { ...@@ -562,6 +562,7 @@ public class DbException extends RuntimeException {
case CANNOT_MIX_INDEXED_AND_UNINDEXED_PARAMS: case CANNOT_MIX_INDEXED_AND_UNINDEXED_PARAMS:
case TRANSACTION_NOT_FOUND_1: case TRANSACTION_NOT_FOUND_1:
case AGGREGATE_NOT_FOUND_1: case AGGREGATE_NOT_FOUND_1:
case WINDOW_NOT_FOUND_1:
case CAN_ONLY_ASSIGN_TO_VARIABLE_1: case CAN_ONLY_ASSIGN_TO_VARIABLE_1:
case PUBLIC_STATIC_JAVA_METHOD_NOT_FOUND_1: case PUBLIC_STATIC_JAVA_METHOD_NOT_FOUND_1:
case JAVA_OBJECT_SERIALIZER_CHANGE_WITH_DATA_TABLE: case JAVA_OBJECT_SERIALIZER_CHANGE_WITH_DATA_TABLE:
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=Nelze změnit nastavení {0}, pokud je již databáze otevřena 90133=Nelze změnit nastavení {0}, pokud je již databáze otevřena
90134=Přístup ke třídě {0} byl odepřen 90134=Přístup ke třídě {0} byl odepřen
90135=Databáze je spuštěna ve vyhrazeném režimu; nelze otevřít další spojení 90135=Databáze je spuštěna ve vyhrazeném režimu; nelze otevřít další spojení
90136=Nepodporovaná podmínka vnějšího spojení: {0} 90136=#Window not found: {0}
90137=Lze přiřadit pouze proměnné, nikoli: {0} 90137=Lze přiřadit pouze proměnné, nikoli: {0}
90138=Neplatný název databáze: {0} 90138=Neplatný název databáze: {0}
90139=Nenalezena veřejná statická Java metoda: {0} 90139=Nenalezena veřejná statická Java metoda: {0}
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=Kann das Setting {0} nicht ändern wenn die Datenbank bereits geöffnet ist 90133=Kann das Setting {0} nicht ändern wenn die Datenbank bereits geöffnet ist
90134=Der Zugriff auf die Klasse {0} ist nicht erlaubt 90134=Der Zugriff auf die Klasse {0} ist nicht erlaubt
90135=Die Datenbank befindet sich im Exclusiv Modus; es können keine zusätzlichen Verbindungen geöffnet werden 90135=Die Datenbank befindet sich im Exclusiv Modus; es können keine zusätzlichen Verbindungen geöffnet werden
90136=Diese Outer Join Bedingung wird nicht unterstützt: {0} 90136=#Window not found: {0}
90137=Werte können nur einer Variablen zugewiesen werden, nicht an: {0} 90137=Werte können nur einer Variablen zugewiesen werden, nicht an: {0}
90138=Ungültiger Datenbank Name: {0} 90138=Ungültiger Datenbank Name: {0}
90139=Die (public static) Java Funktion wurde nicht gefunden: {0} 90139=Die (public static) Java Funktion wurde nicht gefunden: {0}
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=Cannot change the setting {0} when the database is already open 90133=Cannot change the setting {0} when the database is already open
90134=Access to the class {0} is denied 90134=Access to the class {0} is denied
90135=The database is open in exclusive mode; can not open additional connections 90135=The database is open in exclusive mode; can not open additional connections
90136=Unsupported outer join condition: {0} 90136=Window not found: {0}
90137=Can only assign to a variable, not to: {0} 90137=Can only assign to a variable, not to: {0}
90138=Invalid database name: {0} 90138=Invalid database name: {0}
90139=The public static Java method was not found: {0} 90139=The public static Java method was not found: {0}
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=No puede cambiar el setting {0} cuando la base de datos esta abierta 90133=No puede cambiar el setting {0} cuando la base de datos esta abierta
90134=Acceso denegado a la clase {0} 90134=Acceso denegado a la clase {0}
90135=La base de datos esta abierta en modo EXCLUSIVO; no puede abrir conexiones adicionales 90135=La base de datos esta abierta en modo EXCLUSIVO; no puede abrir conexiones adicionales
90136=Condición No soportada en Outer join : {0} 90136=#Window not found: {0}
90137=Solo puede asignarse a una variable, no a: {0} 90137=Solo puede asignarse a una variable, no a: {0}
90138=Nombre de base de datos Invalido: {0} 90138=Nombre de base de datos Invalido: {0}
90139=El metodo Java (publico y estatico) : {0} no fue encontrado 90139=El metodo Java (publico y estatico) : {0} no fue encontrado
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=Impossible de changer le paramétrage {0} lorsque la base de données est déjà ouverte 90133=Impossible de changer le paramétrage {0} lorsque la base de données est déjà ouverte
90134=L''accès à la classe {0} est interdit 90134=L''accès à la classe {0} est interdit
90135=La base de données est ouverte en mode exclusif; impossible d''ouvrir des connexions additionnelles 90135=La base de données est ouverte en mode exclusif; impossible d''ouvrir des connexions additionnelles
90136=Condition de jointure extérieure non prise en charge: {0} 90136=#Window not found: {0}
90137=Peut seulement être assigné à une variable, pas à: {0} 90137=Peut seulement être assigné à une variable, pas à: {0}
90138=Nom de la base de données invalide: {0} 90138=Nom de la base de données invalide: {0}
90139=La méthode Java public static n''a pas été trouvée: {0} 90139=La méthode Java public static n''a pas été trouvée: {0}
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=データベースオープン中には、設定 {0} を変更できません 90133=データベースオープン中には、設定 {0} を変更できません
90134=クラス {0} へのアクセスが拒否されました 90134=クラス {0} へのアクセスが拒否されました
90135=データベースは排他モードでオープンされています; 接続を追加することはできません 90135=データベースは排他モードでオープンされています; 接続を追加することはできません
90136=未サポートの外部結合条件: {0} 90136=#Window not found: {0}
90137=割り当ては変数にのみ可能です。{0} にはできません 90137=割り当ては変数にのみ可能です。{0} にはできません
90138=不正なデータベース名: {0} 90138=不正なデータベース名: {0}
90139=public staticであるJavaメソッドが見つかりません: {0} 90139=public staticであるJavaメソッドが見つかりません: {0}
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=Nie można zmienić ustawienia {0} gdy baza danych jest otwarta 90133=Nie można zmienić ustawienia {0} gdy baza danych jest otwarta
90134=Dostęp do klasy {0} jest zabroniony 90134=Dostęp do klasy {0} jest zabroniony
90135=Baza danych jest otwarta w trybie wyłączności, nie można otworzyć dodatkowych połączeń 90135=Baza danych jest otwarta w trybie wyłączności, nie można otworzyć dodatkowych połączeń
90136=Nieobsługiwany warunek złączenia zewnętrznego: {0} 90136=#Window not found: {0}
90137=Można przypisywać tylko do zmiennych, nie do: {0} 90137=Można przypisywać tylko do zmiennych, nie do: {0}
90138=Nieprawidłowa nazwa bazy danych: {0} 90138=Nieprawidłowa nazwa bazy danych: {0}
90139=Publiczna, statyczna metoda Java nie znaleziona: {0} 90139=Publiczna, statyczna metoda Java nie znaleziona: {0}
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=#Cannot change the setting {0} when the database is already open 90133=#Cannot change the setting {0} when the database is already open
90134=#Access to the class {0} is denied 90134=#Access to the class {0} is denied
90135=#The database is open in exclusive mode; can not open additional connections 90135=#The database is open in exclusive mode; can not open additional connections
90136=#Unsupported outer join condition: {0} 90136=#Window not found: {0}
90137=#Can only assign to a variable, not to: {0} 90137=#Can only assign to a variable, not to: {0}
90138=#Invalid database name: {0} 90138=#Invalid database name: {0}
90139=#The public static Java method was not found: {0} 90139=#The public static Java method was not found: {0}
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=Невозможно изменить опцию {0}, когда база данных уже открыта 90133=Невозможно изменить опцию {0}, когда база данных уже открыта
90134=Доступ к классу {0} запрещен 90134=Доступ к классу {0} запрещен
90135=База данных открыта в эксклюзивном режиме, открыть дополнительные соединения невозможно 90135=База данных открыта в эксклюзивном режиме, открыть дополнительные соединения невозможно
90136=Данное условие не поддерживается в OUTER JOIN : {0} 90136=Окно не найдено: {0}
90137=Присваивать значения возможно только переменным, но не: {0} 90137=Присваивать значения возможно только переменным, но не: {0}
90138=Недопустимое имя базы данных: {0} 90138=Недопустимое имя базы данных: {0}
90139=public static Java метод не найден: {0} 90139=public static Java метод не найден: {0}
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=Nemôžem zmeniť nastavenie {0} keď už je databáza otvorená 90133=Nemôžem zmeniť nastavenie {0} keď už je databáza otvorená
90134=Prístup k triede {0} odoprený 90134=Prístup k triede {0} odoprený
90135=Databáza je otvorená vo výhradnom (exclusive) móde; nemôžem na ňu otvoriť ďalšie pripojenia 90135=Databáza je otvorená vo výhradnom (exclusive) móde; nemôžem na ňu otvoriť ďalšie pripojenia
90136=Nepodporovaná "outer join" podmienka: {0} 90136=#Window not found: {0}
90137=Môžete priradiť len do premennej, nie do: {0} 90137=Môžete priradiť len do premennej, nie do: {0}
90138=Nesprávne meno databázy: {0} 90138=Nesprávne meno databázy: {0}
90139=Verejná statická Java metóda nebola nájdená: {0} 90139=Verejná statická Java metóda nebola nájdená: {0}
......
...@@ -166,7 +166,7 @@ ...@@ -166,7 +166,7 @@
90133=数据库有已启动的时候不允许更改设置{0} 90133=数据库有已启动的时候不允许更改设置{0}
90134=访问 {0}类时被拒绝 90134=访问 {0}类时被拒绝
90135=数据库运行在独占模式(exclusive mode); 不能打开额外的连接 90135=数据库运行在独占模式(exclusive mode); 不能打开额外的连接
90136=不支持的外连接条件: {0} 90136=#Window not found: {0}
90137=只能赋值到一个变量,而不是: {0} 90137=只能赋值到一个变量,而不是: {0}
90138=无效数据库名称: {0} 90138=无效数据库名称: {0}
90139=找不到公用Java静态方法: {0} 90139=找不到公用Java静态方法: {0}
......
...@@ -207,10 +207,15 @@ public class ParserUtil { ...@@ -207,10 +207,15 @@ public class ParserUtil {
*/ */
public static final int WHERE = UNIQUE + 1; public static final int WHERE = UNIQUE + 1;
/**
* The token "WINDOW".
*/
public static final int WINDOW = WHERE + 1;
/** /**
* The token "WITH". * The token "WITH".
*/ */
public static final int WITH = WHERE + 1; public static final int WITH = WINDOW + 1;
private static final int UPPER_OR_OTHER_LETTER = private static final int UPPER_OR_OTHER_LETTER =
1 << Character.UPPERCASE_LETTER 1 << Character.UPPERCASE_LETTER
...@@ -426,10 +431,12 @@ public class ParserUtil { ...@@ -426,10 +431,12 @@ public class ParserUtil {
} }
return IDENTIFIER; return IDENTIFIER;
case 'W': case 'W':
if ("WITH".equals(s)) { if ("WHERE".equals(s)) {
return WITH;
} else if ("WHERE".equals(s)) {
return WHERE; return WHERE;
} else if ("WINDOW".equals(s)) {
return WINDOW;
} else if ("WITH".equals(s)) {
return WITH;
} }
return IDENTIFIER; return IDENTIFIER;
default: default:
......
...@@ -110,6 +110,7 @@ public class TestScript extends TestDb { ...@@ -110,6 +110,7 @@ public class TestScript extends TestDb {
testScript("altertable-fk.sql"); testScript("altertable-fk.sql");
testScript("default-and-on_update.sql"); testScript("default-and-on_update.sql");
testScript("query-optimisations.sql"); testScript("query-optimisations.sql");
testScript("window.sql");
String decimal2; String decimal2;
if (SysProperties.BIG_DECIMAL_IS_DECIMAL) { if (SysProperties.BIG_DECIMAL_IS_DECIMAL) {
decimal2 = "decimal_decimal"; decimal2 = "decimal_decimal";
......
-- Copyright 2004-2018 H2 Group. Multiple-Licensed under the MPL 2.0,
-- and the EPL 1.0 (http://h2database.com/html/license.html).
-- Initial Developer: H2 Group
--
CREATE TABLE TEST(ID INT, R INT, CATEGORY INT);
> ok
INSERT INTO TEST VALUES
(1, 4, 1),
(2, 3, 1),
(3, 2, 2),
(4, 1, 2);
> update count: 4
SELECT *, ROW_NUMBER() OVER W FROM TEST;
> exception WINDOW_NOT_FOUND_1
SELECT * FROM TEST WINDOW W AS W1, W1 AS ();
> exception SYNTAX_ERROR_2
SELECT *, ROW_NUMBER() OVER W1, ROW_NUMBER() OVER W2 FROM TEST
WINDOW W1 AS (W2 ORDER BY ID), W2 AS (PARTITION BY CATEGORY ORDER BY ID DESC);
> ID R CATEGORY ROW_NUMBER() OVER (PARTITION BY CATEGORY ORDER BY ID) ROW_NUMBER() OVER (PARTITION BY CATEGORY ORDER BY ID DESC)
> -- - -------- ----------------------------------------------------- ----------------------------------------------------------
> 1 4 1 1 2
> 2 3 1 2 1
> 3 2 2 1 2
> 4 1 2 2 1
> rows (ordered): 4
SELECT *, LAST_VALUE(ID) OVER W FROM TEST
WINDOW W AS (PARTITION BY CATEGORY ORDER BY ID RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING EXCLUDE CURRENT ROW);
> ID R CATEGORY LAST_VALUE(ID) OVER (PARTITION BY CATEGORY ORDER BY ID RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING EXCLUDE CURRENT ROW)
> -- - -------- -------------------------------------------------------------------------------------------------------------------------------------
> 1 4 1 2
> 2 3 1 1
> 3 2 2 4
> 4 1 2 3
> rows (ordered): 4
DROP TABLE TEST;
> ok
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论