Skip to content
项目
群组
代码片段
帮助
正在加载...
帮助
为 GitLab 提交贡献
登录/注册
切换导航
H
h2database
项目
项目
详情
活动
周期分析
仓库
仓库
文件
提交
分支
标签
贡献者
分枝图
比较
统计图
议题
0
议题
0
列表
看板
标记
里程碑
合并请求
0
合并请求
0
CI / CD
CI / CD
流水线
作业
计划
统计图
Wiki
Wiki
代码片段
代码片段
成员
成员
折叠边栏
关闭边栏
活动
分枝图
统计图
创建新议题
作业
提交
议题看板
打开侧边栏
Administrator
h2database
Commits
b0105180
Unverified
提交
b0105180
authored
9月 19, 2018
作者:
Evgenij Ryazanov
提交者:
GitHub
9月 19, 2018
浏览文件
操作
浏览文件
下载
差异文件
Merge pull request #1457 from katzyn/window
Add NTILE(), LEAD() and LAG() window functions
上级
4f23bb18
8fd4b83d
全部展开
隐藏空白字符变更
内嵌
并排
正在显示
9 个修改的文件
包含
616 行增加
和
149 行删除
+616
-149
help.csv
h2/src/docsrc/help/help.csv
+56
-0
Parser.java
h2/src/main/org/h2/command/Parser.java
+28
-7
WindowFunction.java
h2/src/main/org/h2/expression/aggregate/WindowFunction.java
+158
-132
WindowFunctionType.java
.../main/org/h2/expression/aggregate/WindowFunctionType.java
+116
-0
TestScript.java
h2/src/test/org/h2/test/scripts/TestScript.java
+1
-1
array-agg.sql
...est/org/h2/test/scripts/functions/aggregate/array-agg.sql
+8
-8
lead.sql
h2/src/test/org/h2/test/scripts/functions/window/lead.sql
+133
-0
ntile.sql
h2/src/test/org/h2/test/scripts/functions/window/ntile.sql
+115
-0
dictionary.txt
h2/src/tools/org/h2/build/doc/dictionary.txt
+1
-1
没有找到文件。
h2/src/docsrc/help/help.csv
浏览文件 @
b0105180
...
@@ -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
","
","
...
...
h2/src/main/org/h2/command/Parser.java
浏览文件 @
b0105180
...
@@ -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
.WindowFunction
Type
;
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
.
get
Min
ArgumentCount
(
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:
...
...
h2/src/main/org/h2/expression/aggregate/WindowFunction.java
浏览文件 @
b0105180
差异被折叠。
点击展开。
h2/src/main/org/h2/expression/aggregate/WindowFunctionType.java
0 → 100644
浏览文件 @
b0105180
/*
* 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
h2/src/test/org/h2/test/scripts/TestScript.java
浏览文件 @
b0105180
...
@@ -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"
);
}
}
...
...
h2/src/test/org/h2/test/scripts/functions/aggregate/array-agg.sql
浏览文件 @
b0105180
...
@@ -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
;
...
...
h2/src/test/org/h2/test/scripts/functions/window/lead.sql
0 → 100644
浏览文件 @
b0105180
-- 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
h2/src/test/org/h2/test/scripts/functions/window/ntile.sql
0 → 100644
浏览文件 @
b0105180
-- 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
h2/src/tools/org/h2/build/doc/dictionary.txt
浏览文件 @
b0105180
...
@@ -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
人
到此讨论。请谨慎行事。
请先完成此评论的编辑!
取消
请
注册
或者
登录
后发表评论