提交 d129b3c9 authored 作者: Evgenij Ryazanov's avatar Evgenij Ryazanov

Add LEAD() and LAG() window functions

上级 4f23bb18
......@@ -5176,6 +5176,46 @@ SELECT CUME_DIST() OVER (ORDER BY ID), * FROM TEST;
SELECT CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"
"Functions (Window)","LEAD","
LEAD(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
OVER windowSpecification
","
Returns the value in a next row with specified offset relative to the current row.
Offset must be non-negative.
If IGNORE NULLS is specified rows with null values in selected expression are skipped.
If number of considered rows is less than specified relative number this function returns NULL
or the specified default value, if any.
If offset is 0 the value from the current row is returned unconditionally.
Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT LEAD(X) OVER (ORDER BY ID), * FROM TEST;
SELECT LEAD(X, 2, 0) IGNORE NULLS OVER (
PARTITION BY CATEGORY ORDER BY ID
), * FROM TEST;
"
"Functions (Window)","LAG","
LAG(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
OVER windowSpecification
","
Returns the value in a previous row with specified offset relative to the current row.
Offset must be non-negative.
If IGNORE NULLS is specified rows with null values in selected expression are skipped.
If number of considered rows is less than specified relative number this function returns NULL
or the specified default value, if any.
If offset is 0 the value from the current row is returned unconditionally.
Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT LAG(X) OVER (ORDER BY ID), * FROM TEST;
SELECT LAG(X, 2, 0) IGNORE NULLS OVER (
PARTITION BY CATEGORY ORDER BY ID
), * FROM TEST;
"
"Functions (Window)","FIRST_VALUE","
FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS] OVER windowSpecification
","
......
......@@ -181,7 +181,7 @@ import org.h2.expression.aggregate.WindowFrameBoundType;
import org.h2.expression.aggregate.WindowFrameExclusion;
import org.h2.expression.aggregate.WindowFrameUnits;
import org.h2.expression.aggregate.WindowFunction;
import org.h2.expression.aggregate.WindowFunction.WindowFunctionType;
import org.h2.expression.aggregate.WindowFunctionType;
import org.h2.index.Index;
import org.h2.message.DbException;
import org.h2.result.SortOrder;
......@@ -3376,15 +3376,34 @@ public class Parser {
if (currentSelect == null) {
throw getSyntaxError();
}
int numArgs = WindowFunction.getArgumentCount(type);
int numArgs = WindowFunction.getMinArgumentCount(type);
Expression[] args = null;
if (numArgs > 0) {
args = new Expression[numArgs];
for (int i = 0; i < numArgs; i++) {
if (i > 0) {
read(COMMA);
// There is no functions with numArgs == 0 && numArgsMax > 0
int numArgsMax = WindowFunction.getMaxArgumentCount(type);
args = new Expression[numArgsMax];
if (numArgs == numArgsMax) {
for (int i = 0; i < numArgs; i++) {
if (i > 0) {
read(COMMA);
}
args[i] = readExpression();
}
} else {
int i = 0;
while (i < numArgsMax) {
if (i > 0 && !readIf(COMMA)) {
break;
}
args[i] = readExpression();
i++;
}
if (i < numArgs) {
throw getSyntaxError();
}
if (i != numArgsMax) {
args = Arrays.copyOf(args, i);
}
args[i] = readExpression();
}
}
read(CLOSE_PAREN);
......@@ -3393,6 +3412,8 @@ public class Parser {
readFromFirstOrLast(function);
}
switch (type) {
case LEAD:
case LAG:
case FIRST_VALUE:
case LAST_VALUE:
case NTH_VALUE:
......
/*
* 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
*/
package org.h2.expression.aggregate;
/**
* A type of a window function.
*/
public enum WindowFunctionType {
/**
* The type for ROW_NUMBER() window function.
*/
ROW_NUMBER,
/**
* The type for RANK() window function.
*/
RANK,
/**
* The type for DENSE_RANK() window function.
*/
DENSE_RANK,
/**
* The type for PERCENT_RANK() window function.
*/
PERCENT_RANK,
/**
* The type for CUME_DIST() window function.
*/
CUME_DIST,
/**
* The type for LEAD() window function.
*/
LEAD,
/**
* The type for LAG() window function.
*/
LAG,
/**
* The type for FIRST_VALUE() window function.
*/
FIRST_VALUE,
/**
* The type for LAST_VALUE() window function.
*/
LAST_VALUE,
/**
* The type for NTH_VALUE() window function.
*/
NTH_VALUE,
;
/**
* Returns the type of window function with the specified name, or null.
*
* @param name
* name of a window function
* @return the type of window function, or null.
*/
public static WindowFunctionType get(String name) {
switch (name) {
case "ROW_NUMBER":
return ROW_NUMBER;
case "RANK":
return RANK;
case "DENSE_RANK":
return DENSE_RANK;
case "PERCENT_RANK":
return PERCENT_RANK;
case "CUME_DIST":
return CUME_DIST;
case "LEAD":
return LEAD;
case "LAG":
return LAG;
case "FIRST_VALUE":
return FIRST_VALUE;
case "LAST_VALUE":
return LAST_VALUE;
case "NTH_VALUE":
return NTH_VALUE;
default:
return null;
}
}
}
\ No newline at end of file
......@@ -179,7 +179,7 @@ public class TestScript extends TestDb {
"parsedatetime", "quarter", "second", "truncate", "week", "year", "date_trunc" }) {
testScript("functions/timeanddate/" + s + ".sql");
}
for (String s : new String[] { "row_number", "nth_value" }) {
for (String s : new String[] { "lead", "row_number", "nth_value" }) {
testScript("functions/window/" + s + ".sql");
}
......
......@@ -394,14 +394,14 @@ CREATE TABLE TEST (ID INT, VALUE INT);
> ok
INSERT INTO TEST VALUES
(1, 1),
(2, 1),
(3, 2),
(4, 2),
(5, 3),
(6, 3),
(7, 4),
(8, 4);
(1, 1),
(2, 1),
(3, 2),
(4, 2),
(5, 3),
(6, 3),
(7, 4),
(8, 4);
> update count: 8
SELECT *, ARRAY_AGG(ID) OVER (ORDER BY VALUE RANGE BETWEEN 2 PRECEDING AND 1 PRECEDING) FROM TEST;
......
-- 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 PRIMARY KEY, VALUE INT);
> ok
INSERT INTO TEST VALUES
(1, NULL),
(2, 12),
(3, NULL),
(4, 13),
(5, NULL),
(6, 21),
(7, 22),
(8, 33),
(9, NULL);
> update count: 9
SELECT *,
LEAD(VALUE) OVER (ORDER BY ID) LD,
LEAD(VALUE) RESPECT NULLS OVER (ORDER BY ID) LD_N,
LEAD(VALUE) IGNORE NULLS OVER (ORDER BY ID) LD_NN,
LAG(VALUE) OVER (ORDER BY ID) LG,
LAG(VALUE) RESPECT NULLS OVER (ORDER BY ID) LG_N,
LAG(VALUE) IGNORE NULLS OVER (ORDER BY ID) LG_NN
FROM TEST;
> ID VALUE LD LD_N LD_NN LG LG_N LG_NN
> -- ----- ---- ---- ----- ---- ---- -----
> 1 null 12 12 12 null null null
> 2 12 null null 13 null null null
> 3 null 13 13 13 12 12 12
> 4 13 null null 21 null null 12
> 5 null 21 21 21 13 13 13
> 6 21 22 22 22 null null 13
> 7 22 33 33 33 21 21 21
> 8 33 null null null 22 22 22
> 9 null null null null 33 33 33
> rows (ordered): 9
SELECT *,
LEAD(VALUE, 1) OVER (ORDER BY ID) LD,
LEAD(VALUE, 1) RESPECT NULLS OVER (ORDER BY ID) LD_N,
LEAD(VALUE, 1) IGNORE NULLS OVER (ORDER BY ID) LD_NN,
LAG(VALUE, 1) OVER (ORDER BY ID) LG,
LAG(VALUE, 1) RESPECT NULLS OVER (ORDER BY ID) LG_N,
LAG(VALUE, 1) IGNORE NULLS OVER (ORDER BY ID) LG_NN
FROM TEST;
> ID VALUE LD LD_N LD_NN LG LG_N LG_NN
> -- ----- ---- ---- ----- ---- ---- -----
> 1 null 12 12 12 null null null
> 2 12 null null 13 null null null
> 3 null 13 13 13 12 12 12
> 4 13 null null 21 null null 12
> 5 null 21 21 21 13 13 13
> 6 21 22 22 22 null null 13
> 7 22 33 33 33 21 21 21
> 8 33 null null null 22 22 22
> 9 null null null null 33 33 33
> rows (ordered): 9
SELECT *,
LEAD(VALUE, 0) OVER (ORDER BY ID) LD,
LEAD(VALUE, 0) RESPECT NULLS OVER (ORDER BY ID) LD_N,
LEAD(VALUE, 0) IGNORE NULLS OVER (ORDER BY ID) LD_NN,
LAG(VALUE, 0) OVER (ORDER BY ID) LG,
LAG(VALUE, 0) RESPECT NULLS OVER (ORDER BY ID) LG_N,
LAG(VALUE, 0) IGNORE NULLS OVER (ORDER BY ID) LG_NN
FROM TEST;
> ID VALUE LD LD_N LD_NN LG LG_N LG_NN
> -- ----- ---- ---- ----- ---- ---- -----
> 1 null null null null null null null
> 2 12 12 12 12 12 12 12
> 3 null null null null null null null
> 4 13 13 13 13 13 13 13
> 5 null null null null null null null
> 6 21 21 21 21 21 21 21
> 7 22 22 22 22 22 22 22
> 8 33 33 33 33 33 33 33
> 9 null null null null null null null
> rows (ordered): 9
SELECT *,
LEAD(VALUE, 2) OVER (ORDER BY ID) LD,
LEAD(VALUE, 2) RESPECT NULLS OVER (ORDER BY ID) LD_N,
LEAD(VALUE, 2) IGNORE NULLS OVER (ORDER BY ID) LD_NN,
LAG(VALUE, 2) OVER (ORDER BY ID) LG,
LAG(VALUE, 2) RESPECT NULLS OVER (ORDER BY ID) LG_N,
LAG(VALUE, 2) IGNORE NULLS OVER (ORDER BY ID) LG_NN
FROM TEST;
> ID VALUE LD LD_N LD_NN LG LG_N LG_NN
> -- ----- ---- ---- ----- ---- ---- -----
> 1 null null null 13 null null null
> 2 12 13 13 21 null null null
> 3 null null null 21 null null null
> 4 13 21 21 22 12 12 null
> 5 null 22 22 22 null null 12
> 6 21 33 33 33 13 13 12
> 7 22 null null null null null 13
> 8 33 null null null 21 21 21
> 9 null null null null 22 22 22
> rows (ordered): 9
SELECT *,
LEAD(VALUE, 2, 1111.0) OVER (ORDER BY ID) LD,
LEAD(VALUE, 2, 1111.0) RESPECT NULLS OVER (ORDER BY ID) LD_N,
LEAD(VALUE, 2, 1111.0) IGNORE NULLS OVER (ORDER BY ID) LD_NN,
LAG(VALUE, 2, 1111.0) OVER (ORDER BY ID) LG,
LAG(VALUE, 2, 1111.0) RESPECT NULLS OVER (ORDER BY ID) LG_N,
LAG(VALUE, 2, 1111.0) IGNORE NULLS OVER (ORDER BY ID) LG_NN
FROM TEST;
> ID VALUE LD LD_N LD_NN LG LG_N LG_NN
> -- ----- ---- ---- ----- ---- ---- -----
> 1 null null null 13 1111 1111 1111
> 2 12 13 13 21 1111 1111 1111
> 3 null null null 21 null null 1111
> 4 13 21 21 22 12 12 1111
> 5 null 22 22 22 null null 12
> 6 21 33 33 33 13 13 12
> 7 22 null null 1111 null null 13
> 8 33 1111 1111 1111 21 21 21
> 9 null 1111 1111 1111 22 22 22
> rows (ordered): 9
SELECT LEAD(VALUE, -1) OVER (ORDER BY ID) FROM TEST;
> exception INVALID_VALUE_2
SELECT LAG(VALUE, -1) OVER (ORDER BY ID) FROM TEST;
> exception INVALID_VALUE_2
DROP TABLE TEST;
> ok
......@@ -796,4 +796,4 @@ interior envelopes multilinestring multipoint packed exterior normalization awkw
xym normalizes coord setz xyzm geometrycollection multipolygon mixup rings polygons rejection finite
pointzm pointz pointm dimensionality redefine forum measures
mpg casted pzm mls constrained subtypes complains
ranks rno dro rko precede cume reopens preceding unbounded rightly itr
ranks rno dro rko precede cume reopens preceding unbounded rightly itr lag maximal
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论