提交 8fd4b83d authored 作者: Evgenij Ryazanov's avatar Evgenij Ryazanov

Add NTILE window function

上级 d129b3c9
......@@ -5176,6 +5176,22 @@ SELECT CUME_DIST() OVER (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
......
......@@ -42,6 +42,7 @@ public class WindowFunction extends AbstractAggregate {
*/
public static int getMinArgumentCount(WindowFunctionType type) {
switch (type) {
case NTILE:
case LEAD:
case LAG:
case FIRST_VALUE:
......@@ -63,12 +64,13 @@ public class WindowFunction extends AbstractAggregate {
*/
public static int getMaxArgumentCount(WindowFunctionType type) {
switch (type) {
case LEAD:
case LAG:
return 3;
case NTILE:
case FIRST_VALUE:
case LAST_VALUE:
return 1;
case LEAD:
case LAG:
return 3;
case NTH_VALUE:
return 2;
default:
......@@ -186,6 +188,9 @@ public class WindowFunction extends AbstractAggregate {
case CUME_DIST:
getCumeDist(session, result, ordered, rowIdColumn);
return;
case NTILE:
getNtile(session, result, ordered, rowIdColumn);
return;
case LEAD:
case LAG:
getLeadLag(session, result, ordered, rowIdColumn);
......@@ -232,11 +237,6 @@ public class WindowFunction extends AbstractAggregate {
}
break;
}
case CUME_DIST: {
int nm = number;
v = ValueDouble.get((double) nm / size);
break;
}
default:
throw DbException.throwInternalError("type=" + type);
}
......@@ -262,6 +262,28 @@ 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();
......@@ -400,6 +422,7 @@ public class WindowFunction extends AbstractAggregate {
case ROW_NUMBER:
case RANK:
case DENSE_RANK:
case NTILE:
return Value.INT;
case PERCENT_RANK:
case CUME_DIST:
......@@ -435,6 +458,7 @@ public class WindowFunction extends AbstractAggregate {
case ROW_NUMBER:
case RANK:
case DENSE_RANK:
case NTILE:
return ValueInt.PRECISION;
case PERCENT_RANK:
case CUME_DIST:
......@@ -456,6 +480,7 @@ public class WindowFunction extends AbstractAggregate {
case ROW_NUMBER:
case RANK:
case DENSE_RANK:
case NTILE:
return ValueInt.DISPLAY_SIZE;
case PERCENT_RANK:
case CUME_DIST:
......@@ -473,42 +498,8 @@ public class WindowFunction extends AbstractAggregate {
@Override
public String getSQL() {
String text;
switch (type) {
case ROW_NUMBER:
text = "ROW_NUMBER";
break;
case RANK:
text = "RANK";
break;
case DENSE_RANK:
text = "DENSE_RANK";
break;
case PERCENT_RANK:
text = "PERCENT_RANK";
break;
case CUME_DIST:
text = "CUME_DIST";
break;
case LEAD:
text = "LEAD";
break;
case LAG:
text = "LAG";
break;
case FIRST_VALUE:
text = "FIRST_VALUE";
break;
case LAST_VALUE:
text = "LAST_VALUE";
break;
case NTH_VALUE:
text = "NTH_VALUE";
break;
default:
throw DbException.throwInternalError("type=" + type);
}
StringBuilder builder = new StringBuilder().append(text).append('(');
String name = type.getSQL();
StringBuilder builder = new StringBuilder().append(name).append('(');
if (args != null) {
for (int i = 0, numArgs = args.length; i < numArgs; i++) {
if (i > 0) {
......
......@@ -35,6 +35,11 @@ public enum WindowFunctionType {
*/
CUME_DIST,
/**
* The type for NTILE() window function.
*/
NTILE,
/**
* The type for LEAD() window function.
*/
......@@ -81,6 +86,8 @@ public enum WindowFunctionType {
return PERCENT_RANK;
case "CUME_DIST":
return CUME_DIST;
case "NTILE":
return NTILE;
case "LEAD":
return LEAD;
case "LAG":
......@@ -96,4 +103,14 @@ public enum WindowFunctionType {
}
}
/**
* 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 {
"parsedatetime", "quarter", "second", "truncate", "week", "year", "date_trunc" }) {
testScript("functions/timeanddate/" + s + ".sql");
}
for (String s : new String[] { "lead", "row_number", "nth_value" }) {
for (String s : new String[] { "lead", "nth_value", "ntile", "row_number" }) {
testScript("functions/window/" + s + ".sql");
}
......
-- 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
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 lag maximal
ranks rno dro rko precede cume reopens preceding unbounded rightly itr lag maximal tiles tile ntile
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论