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

Merge pull request #1457 from katzyn/window

Add NTILE(), LEAD() and LAG() window functions
...@@ -5176,6 +5176,62 @@ SELECT CUME_DIST() OVER (ORDER BY ID), * FROM TEST; ...@@ -5176,6 +5176,62 @@ SELECT CUME_DIST() OVER (ORDER BY ID), * FROM TEST;
SELECT CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST; SELECT CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
" "
"Functions (Window)","NTILE","
NTILE(int) OVER windowSpecification
","
Distributes the rows into a specified number of groups.
Number of groups should be a positive integer value.
NTILE returns the 1-based number of the group to which the current row belongs.
First groups will have more rows if number of rows is not divisible by number of groups.
For example, if 5 rows are distributed into 2 groups this function returns 1 for the first 3 row and 2 for the last 2 rows.
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 NTILE(10) OVER (ORDER BY ID), * FROM TEST;
SELECT NTILE(5) 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"," "Functions (Window)","FIRST_VALUE","
FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS] OVER windowSpecification FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS] OVER windowSpecification
"," ","
......
...@@ -181,7 +181,7 @@ import org.h2.expression.aggregate.WindowFrameBoundType; ...@@ -181,7 +181,7 @@ import org.h2.expression.aggregate.WindowFrameBoundType;
import org.h2.expression.aggregate.WindowFrameExclusion; import org.h2.expression.aggregate.WindowFrameExclusion;
import org.h2.expression.aggregate.WindowFrameUnits; import org.h2.expression.aggregate.WindowFrameUnits;
import org.h2.expression.aggregate.WindowFunction; 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.index.Index;
import org.h2.message.DbException; import org.h2.message.DbException;
import org.h2.result.SortOrder; import org.h2.result.SortOrder;
...@@ -3376,15 +3376,34 @@ public class Parser { ...@@ -3376,15 +3376,34 @@ public class Parser {
if (currentSelect == null) { if (currentSelect == null) {
throw getSyntaxError(); throw getSyntaxError();
} }
int numArgs = WindowFunction.getArgumentCount(type); int numArgs = WindowFunction.getMinArgumentCount(type);
Expression[] args = null; Expression[] args = null;
if (numArgs > 0) { if (numArgs > 0) {
args = new Expression[numArgs]; // There is no functions with numArgs == 0 && numArgsMax > 0
for (int i = 0; i < numArgs; i++) { int numArgsMax = WindowFunction.getMaxArgumentCount(type);
if (i > 0) { args = new Expression[numArgsMax];
read(COMMA); 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); read(CLOSE_PAREN);
...@@ -3393,6 +3412,8 @@ public class Parser { ...@@ -3393,6 +3412,8 @@ public class Parser {
readFromFirstOrLast(function); readFromFirstOrLast(function);
} }
switch (type) { switch (type) {
case LEAD:
case LAG:
case FIRST_VALUE: case FIRST_VALUE:
case LAST_VALUE: case LAST_VALUE:
case NTH_VALUE: case NTH_VALUE:
......
...@@ -25,105 +25,52 @@ import org.h2.value.ValueNull; ...@@ -25,105 +25,52 @@ import org.h2.value.ValueNull;
*/ */
public class WindowFunction extends AbstractAggregate { public class WindowFunction extends AbstractAggregate {
/** private final WindowFunctionType type;
* 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,
/** private final Expression[] args;
* The type for CUME_DIST() window function.
*/
CUME_DIST,
/** private boolean fromLast;
* The type for FIRST_VALUE() window function.
*/
FIRST_VALUE,
/** private boolean ignoreNulls;
* The type for LAST_VALUE() window function.
*/
LAST_VALUE,
/** /**
* The type for NTH_VALUE() window function. * Returns minimal number of arguments for the specified type.
*
* @param type
* the type of a window function
* @return minimal number of arguments
*/ */
NTH_VALUE, public static int getMinArgumentCount(WindowFunctionType type) {
switch (type) {
; case NTILE:
case LEAD:
/** case LAG:
* Returns the type of window function with the specified name, or null. case FIRST_VALUE:
* case LAST_VALUE:
* @param name return 1;
* name of a window function case NTH_VALUE:
* @return the type of window function, or null. return 2;
*/ default:
public static WindowFunctionType get(String name) { return 0;
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 "FIRST_VALUE":
return FIRST_VALUE;
case "LAST_VALUE":
return LAST_VALUE;
case "NTH_VALUE":
return NTH_VALUE;
default:
return null;
}
} }
} }
private final WindowFunctionType type;
private final Expression[] args;
private boolean fromLast;
private boolean ignoreNulls;
/** /**
* Returns number of arguments for the specified type. * Returns maximal number of arguments for the specified type.
* *
* @param type * @param type
* the type of a window function * the type of a window function
* @return number of arguments * @return maximal number of arguments
*/ */
public static int getArgumentCount(WindowFunctionType type) { public static int getMaxArgumentCount(WindowFunctionType type) {
switch (type) { switch (type) {
case NTILE:
case FIRST_VALUE: case FIRST_VALUE:
case LAST_VALUE: case LAST_VALUE:
return 1; return 1;
case LEAD:
case LAG:
return 3;
case NTH_VALUE: case NTH_VALUE:
return 2; return 2;
default: default:
...@@ -212,14 +159,15 @@ public class WindowFunction extends AbstractAggregate { ...@@ -212,14 +159,15 @@ public class WindowFunction extends AbstractAggregate {
@Override @Override
protected int getNumExpressions() { protected int getNumExpressions() {
return getArgumentCount(type); return args != null ? args.length : 0;
} }
@Override @Override
protected void rememberExpressions(Session session, Value[] array) { protected void rememberExpressions(Session session, Value[] array) {
int cnt = getNumExpressions(); if (args != null) {
for (int i = 0; i < cnt; i++) { for (int i = 0, cnt = args.length; i < cnt; i++) {
array[i] = args[i].getValue(session); array[i] = args[i].getValue(session);
}
} }
} }
...@@ -240,6 +188,13 @@ public class WindowFunction extends AbstractAggregate { ...@@ -240,6 +188,13 @@ public class WindowFunction extends AbstractAggregate {
case CUME_DIST: case CUME_DIST:
getCumeDist(session, result, ordered, rowIdColumn); getCumeDist(session, result, ordered, rowIdColumn);
return; return;
case NTILE:
getNtile(session, result, ordered, rowIdColumn);
return;
case LEAD:
case LAG:
getLeadLag(session, result, ordered, rowIdColumn);
return;
case FIRST_VALUE: case FIRST_VALUE:
case LAST_VALUE: case LAST_VALUE:
case NTH_VALUE: case NTH_VALUE:
...@@ -282,11 +237,6 @@ public class WindowFunction extends AbstractAggregate { ...@@ -282,11 +237,6 @@ public class WindowFunction extends AbstractAggregate {
} }
break; break;
} }
case CUME_DIST: {
int nm = number;
v = ValueDouble.get((double) nm / size);
break;
}
default: default:
throw DbException.throwInternalError("type=" + type); throw DbException.throwInternalError("type=" + type);
} }
...@@ -312,6 +262,93 @@ public class WindowFunction extends AbstractAggregate { ...@@ -312,6 +262,93 @@ public class WindowFunction extends AbstractAggregate {
} }
} }
private static void getNtile(Session session, HashMap<Integer, Value> result, ArrayList<Value[]> orderedData,
int last) {
int size = orderedData.size();
for (int i = 0; i < size; i++) {
Value[] array = orderedData.get(i);
int buckets = array[0].getInt();
if (buckets <= 0) {
throw DbException.getInvalidValueException("number of tiles", buckets);
}
int perTile = size / buckets;
int numLarger = size - perTile * buckets;
int largerGroup = numLarger * (perTile + 1);
int v;
if (i >= largerGroup) {
v = (i - largerGroup) / perTile + numLarger + 1;
} else {
v = i / (perTile + 1) + 1;
}
result.put(orderedData.get(i)[last].getInt(), ValueInt.get(v));
}
}
private void getLeadLag(Session session, HashMap<Integer, Value> result, ArrayList<Value[]> ordered,
int rowIdColumn) {
int size = ordered.size();
int numExpressions = getNumExpressions();
int dataType = args[0].getType();
for (int i = 0; i < size; i++) {
Value[] row = ordered.get(i);
int rowId = row[rowIdColumn].getInt();
int n;
if (numExpressions >= 2) {
n = row[1].getInt();
// 0 is valid here
if (n < 0) {
throw DbException.getInvalidValueException("nth row", n);
}
} else {
n = 1;
}
Value v = null;
if (n == 0) {
v = ordered.get(i)[0];
} else if (type == WindowFunctionType.LEAD) {
if (ignoreNulls) {
for (int j = i + 1; n > 0 && j < size; j++) {
v = ordered.get(j)[0];
if (v != ValueNull.INSTANCE) {
n--;
}
}
if (n > 0) {
v = null;
}
} else {
if (n <= size - i - 1) {
v = ordered.get(i + n)[0];
}
}
} else /* LAG */ {
if (ignoreNulls) {
for (int j = i - 1; n > 0 && j >= 0; j--) {
v = ordered.get(j)[0];
if (v != ValueNull.INSTANCE) {
n--;
}
}
if (n > 0) {
v = null;
}
} else {
if (n <= i) {
v = ordered.get(i - n)[0];
}
}
}
if (v == null) {
if (numExpressions >= 3) {
v = row[2].convertTo(dataType);
} else {
v = ValueNull.INSTANCE;
}
}
result.put(rowId, v);
}
}
private void getNth(Session session, HashMap<Integer, Value> result, ArrayList<Value[]> ordered, int rowIdColumn) { private void getNth(Session session, HashMap<Integer, Value> result, ArrayList<Value[]> ordered, int rowIdColumn) {
int size = ordered.size(); int size = ordered.size();
for (int i = 0; i < size; i++) { for (int i = 0; i < size; i++) {
...@@ -320,10 +357,9 @@ public class WindowFunction extends AbstractAggregate { ...@@ -320,10 +357,9 @@ public class WindowFunction extends AbstractAggregate {
int rowId = row[rowIdColumn].getInt(); int rowId = row[rowIdColumn].getInt();
Value v; Value v;
switch (type) { switch (type) {
case FIRST_VALUE: { case FIRST_VALUE:
v = getNthValue(frame.iterator(session, ordered, getOverOrderBySort(), i, false), 0, ignoreNulls); v = getNthValue(frame.iterator(session, ordered, getOverOrderBySort(), i, false), 0, ignoreNulls);
break; break;
}
case LAST_VALUE: case LAST_VALUE:
v = getNthValue(frame.iterator(session, ordered, getOverOrderBySort(), i, true), 0, ignoreNulls); v = getNthValue(frame.iterator(session, ordered, getOverOrderBySort(), i, true), 0, ignoreNulls);
break; break;
...@@ -386,10 +422,13 @@ public class WindowFunction extends AbstractAggregate { ...@@ -386,10 +422,13 @@ public class WindowFunction extends AbstractAggregate {
case ROW_NUMBER: case ROW_NUMBER:
case RANK: case RANK:
case DENSE_RANK: case DENSE_RANK:
case NTILE:
return Value.INT; return Value.INT;
case PERCENT_RANK: case PERCENT_RANK:
case CUME_DIST: case CUME_DIST:
return Value.DOUBLE; return Value.DOUBLE;
case LEAD:
case LAG:
case FIRST_VALUE: case FIRST_VALUE:
case LAST_VALUE: case LAST_VALUE:
case NTH_VALUE: case NTH_VALUE:
...@@ -402,6 +441,8 @@ public class WindowFunction extends AbstractAggregate { ...@@ -402,6 +441,8 @@ public class WindowFunction extends AbstractAggregate {
@Override @Override
public int getScale() { public int getScale() {
switch (type) { switch (type) {
case LEAD:
case LAG:
case FIRST_VALUE: case FIRST_VALUE:
case LAST_VALUE: case LAST_VALUE:
case NTH_VALUE: case NTH_VALUE:
...@@ -417,10 +458,13 @@ public class WindowFunction extends AbstractAggregate { ...@@ -417,10 +458,13 @@ public class WindowFunction extends AbstractAggregate {
case ROW_NUMBER: case ROW_NUMBER:
case RANK: case RANK:
case DENSE_RANK: case DENSE_RANK:
case NTILE:
return ValueInt.PRECISION; return ValueInt.PRECISION;
case PERCENT_RANK: case PERCENT_RANK:
case CUME_DIST: case CUME_DIST:
return ValueDouble.PRECISION; return ValueDouble.PRECISION;
case LEAD:
case LAG:
case FIRST_VALUE: case FIRST_VALUE:
case LAST_VALUE: case LAST_VALUE:
case NTH_VALUE: case NTH_VALUE:
...@@ -436,10 +480,13 @@ public class WindowFunction extends AbstractAggregate { ...@@ -436,10 +480,13 @@ public class WindowFunction extends AbstractAggregate {
case ROW_NUMBER: case ROW_NUMBER:
case RANK: case RANK:
case DENSE_RANK: case DENSE_RANK:
case NTILE:
return ValueInt.DISPLAY_SIZE; return ValueInt.DISPLAY_SIZE;
case PERCENT_RANK: case PERCENT_RANK:
case CUME_DIST: case CUME_DIST:
return ValueDouble.DISPLAY_SIZE; return ValueDouble.DISPLAY_SIZE;
case LEAD:
case LAG:
case FIRST_VALUE: case FIRST_VALUE:
case LAST_VALUE: case LAST_VALUE:
case NTH_VALUE: case NTH_VALUE:
...@@ -451,52 +498,31 @@ public class WindowFunction extends AbstractAggregate { ...@@ -451,52 +498,31 @@ public class WindowFunction extends AbstractAggregate {
@Override @Override
public String getSQL() { public String getSQL() {
String text; String name = type.getSQL();
int numArgs = 0; StringBuilder builder = new StringBuilder().append(name).append('(');
switch (type) { if (args != null) {
case ROW_NUMBER: for (int i = 0, numArgs = args.length; i < numArgs; i++) {
text = "ROW_NUMBER"; if (i > 0) {
break; builder.append(", ");
case RANK: }
text = "RANK"; builder.append(args[i].getSQL());
break;
case DENSE_RANK:
text = "DENSE_RANK";
break;
case PERCENT_RANK:
text = "PERCENT_RANK";
break;
case CUME_DIST:
text = "CUME_DIST";
break;
case FIRST_VALUE:
text = "FIRST_VALUE";
numArgs = 1;
break;
case LAST_VALUE:
text = "LAST_VALUE";
numArgs = 1;
break;
case NTH_VALUE:
text = "NTH_VALUE";
numArgs = 2;
break;
default:
throw DbException.throwInternalError("type=" + type);
}
StringBuilder builder = new StringBuilder().append(text).append('(');
for (int i = 0; i < numArgs; i++) {
if (i > 0) {
builder.append(", ");
} }
builder.append(args[i].getSQL());
} }
builder.append(')'); builder.append(')');
if (fromLast && type == WindowFunctionType.NTH_VALUE) { if (fromLast && type == WindowFunctionType.NTH_VALUE) {
builder.append(" FROM LAST"); builder.append(" FROM LAST");
} }
if (ignoreNulls && (type == WindowFunctionType.FIRST_VALUE || type == WindowFunctionType.LAST_VALUE)) { if (ignoreNulls) {
builder.append(" IGNORE NULLS"); switch (type) {
case LEAD:
case LAG:
case FIRST_VALUE:
case LAST_VALUE:
case NTH_VALUE:
builder.append(" IGNORE NULLS");
//$FALL-THROUGH$
default:
}
} }
return appendTailConditions(builder).toString(); return appendTailConditions(builder).toString();
} }
......
/*
* 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 NTILE() window function.
*/
NTILE,
/**
* 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 "NTILE":
return NTILE;
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;
}
}
/**
* Returns SQL representation.
*
* @return SQL representation.
* @see org.h2.expression.Expression#getSQL()
*/
public String getSQL() {
return name();
}
}
\ No newline at end of file
...@@ -179,7 +179,7 @@ public class TestScript extends TestDb { ...@@ -179,7 +179,7 @@ public class TestScript extends TestDb {
"parsedatetime", "quarter", "second", "truncate", "week", "year", "date_trunc" }) { "parsedatetime", "quarter", "second", "truncate", "week", "year", "date_trunc" }) {
testScript("functions/timeanddate/" + s + ".sql"); testScript("functions/timeanddate/" + s + ".sql");
} }
for (String s : new String[] { "row_number", "nth_value" }) { for (String s : new String[] { "lead", "nth_value", "ntile", "row_number" }) {
testScript("functions/window/" + s + ".sql"); testScript("functions/window/" + s + ".sql");
} }
......
...@@ -394,14 +394,14 @@ CREATE TABLE TEST (ID INT, VALUE INT); ...@@ -394,14 +394,14 @@ CREATE TABLE TEST (ID INT, VALUE INT);
> ok > ok
INSERT INTO TEST VALUES INSERT INTO TEST VALUES
(1, 1), (1, 1),
(2, 1), (2, 1),
(3, 2), (3, 2),
(4, 2), (4, 2),
(5, 3), (5, 3),
(6, 3), (6, 3),
(7, 4), (7, 4),
(8, 4); (8, 4);
> update count: 8 > update count: 8
SELECT *, ARRAY_AGG(ID) OVER (ORDER BY VALUE RANGE BETWEEN 2 PRECEDING AND 1 PRECEDING) FROM TEST; 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
-- 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
--
SELECT NTILE(1) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 1));
>> 1
SELECT NTILE(2) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 1));
>> 1
SELECT NTILE(3) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 1));
>> 1
SELECT NTILE(1) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 2));
> NTILE(1) OVER (ORDER BY X)
> --------------------------
> 1
> 1
> rows (ordered): 2
SELECT NTILE(2) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 2));
> NTILE(2) OVER (ORDER BY X)
> --------------------------
> 1
> 2
> rows (ordered): 2
SELECT NTILE(2) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 3));
> NTILE(2) OVER (ORDER BY X)
> --------------------------
> 1
> 1
> 2
> rows (ordered): 3
SELECT NTILE(2) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 4));
> NTILE(2) OVER (ORDER BY X)
> --------------------------
> 1
> 1
> 2
> 2
> rows (ordered): 4
SELECT NTILE(2) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 5));
> NTILE(2) OVER (ORDER BY X)
> --------------------------
> 1
> 1
> 1
> 2
> 2
> rows (ordered): 5
SELECT NTILE(2) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 6));
> NTILE(2) OVER (ORDER BY X)
> --------------------------
> 1
> 1
> 1
> 2
> 2
> 2
> rows (ordered): 6
SELECT NTILE(10) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 3));
> NTILE(10) OVER (ORDER BY X)
> ---------------------------
> 1
> 2
> 3
> rows (ordered): 3
SELECT NTILE(10) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 22));
> NTILE(10) OVER (ORDER BY X)
> ---------------------------
> 1
> 1
> 1
> 2
> 2
> 2
> 3
> 3
> 4
> 4
> 5
> 5
> 6
> 6
> 7
> 7
> 8
> 8
> 9
> 9
> 10
> 10
> rows (ordered): 22
SELECT NTILE(0) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 1));
> exception INVALID_VALUE_2
SELECT NTILE(X) OVER (ORDER BY X) FROM (SELECT * FROM SYSTEM_RANGE(1, 6));
> NTILE(X) OVER (ORDER BY X)
> --------------------------
> 1
> 1
> 2
> 2
> 4
> 6
> rows (ordered): 6
...@@ -796,4 +796,4 @@ interior envelopes multilinestring multipoint packed exterior normalization awkw ...@@ -796,4 +796,4 @@ interior envelopes multilinestring multipoint packed exterior normalization awkw
xym normalizes coord setz xyzm geometrycollection multipolygon mixup rings polygons rejection finite xym normalizes coord setz xyzm geometrycollection multipolygon mixup rings polygons rejection finite
pointzm pointz pointm dimensionality redefine forum measures pointzm pointz pointm dimensionality redefine forum measures
mpg casted pzm mls constrained subtypes complains 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 tiles tile ntile
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论