Skip to content
项目
群组
代码片段
帮助
正在加载...
帮助
为 GitLab 提交贡献
登录/注册
切换导航
H
h2database
项目
项目
详情
活动
周期分析
仓库
仓库
文件
提交
分支
标签
贡献者
分枝图
比较
统计图
议题
0
议题
0
列表
看板
标记
里程碑
合并请求
0
合并请求
0
CI / CD
CI / CD
流水线
作业
计划
统计图
Wiki
Wiki
代码片段
代码片段
成员
成员
折叠边栏
关闭边栏
活动
分枝图
统计图
创建新议题
作业
提交
议题看板
打开侧边栏
Administrator
h2database
Commits
a1314402
Unverified
提交
a1314402
authored
9月 18, 2018
作者:
Evgenij Ryazanov
提交者:
GitHub
9月 18, 2018
浏览文件
操作
浏览文件
下载
差异文件
Merge pull request #1454 from katzyn/window
Add FIRST_VALUE(), LAST_VALUE(), and NTH_VALUE()
上级
b6cde128
0c17e600
全部展开
隐藏空白字符变更
内嵌
并排
正在显示
13 个修改的文件
包含
1059 行增加
和
35 行删除
+1059
-35
help.csv
h2/src/docsrc/help/help.csv
+76
-7
changelog.html
h2/src/docsrc/html/changelog.html
+12
-0
roadmap.html
h2/src/docsrc/html/roadmap.html
+0
-5
Parser.java
h2/src/main/org/h2/command/Parser.java
+103
-2
AbstractAggregate.java
...c/main/org/h2/expression/aggregate/AbstractAggregate.java
+28
-4
Window.java
h2/src/main/org/h2/expression/aggregate/Window.java
+41
-2
WindowFrame.java
h2/src/main/org/h2/expression/aggregate/WindowFrame.java
+360
-0
WindowFunction.java
h2/src/main/org/h2/expression/aggregate/WindowFunction.java
+236
-11
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
+32
-2
sum.sql
h2/src/test/org/h2/test/scripts/functions/aggregate/sum.sql
+19
-0
nth_value.sql
...c/test/org/h2/test/scripts/functions/window/nth_value.sql
+150
-0
dictionary.txt
h2/src/tools/org/h2/build/doc/dictionary.txt
+1
-1
没有找到文件。
h2/src/docsrc/help/help.csv
浏览文件 @
a1314402
...
...
@@ -48,8 +48,8 @@ SELECT * FROM TEST ORDER BY NAME;
SELECT ID, COUNT(*) FROM TEST GROUP BY ID;
SELECT NAME, COUNT(*) FROM TEST GROUP BY NAME HAVING COUNT(*) > 2;
SELECT 'ID' COL, MAX(ID) AS MAX FROM TEST UNION SELECT 'NAME', MAX(NAME) FROM TEST;
SELECT * FROM TEST OFFSET 1000 ROWS FETCH
NEX
T 1000 ROWS ONLY;
SELECT A, B FROM TEST ORDER BY A FETCH
NEX
T 10 ROWS WITH TIES;
SELECT * FROM TEST OFFSET 1000 ROWS FETCH
FIRS
T 1000 ROWS ONLY;
SELECT A, B FROM TEST ORDER BY A FETCH
FIRS
T 10 ROWS WITH TIES;
SELECT * FROM (SELECT ID, COUNT(*) FROM TEST
GROUP BY ID UNION SELECT NULL, COUNT(*) FROM TEST)
ORDER BY 1 NULLS LAST;
...
...
@@ -2534,9 +2534,11 @@ SELECT * FROM (VALUES(1, 'Hello'), (2, 'World')) AS V;
"
"Other Grammar","Window specification","
([PARTITION BY expression [,...]] [ORDER BY order [,...]])
([PARTITION BY expression [,...]] [ORDER BY order [,...]]
[windowFrame])
","
A window specification for a window function or aggregate.
Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
...
...
@@ -2544,6 +2546,21 @@ They also may require a lot of memory for large queries.
(ORDER BY ID)
(PARTITION BY CATEGORY)
(PARTITION BY CATEGORY ORDER BY NAME, ID)
(ORDER BY Y RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES)
"
"Other Grammar","Window frame","
[RANGE BETWEEN {
UNBOUNDED PRECEDING AND CURRENT ROW
|CURRENT ROW AND UNBOUNDED FOLLOWING
|UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
}]
[EXCLUDE {CURRENT ROW|GROUP|TIES|NO OTHERS}]
","
A window frame clause.
Is currently supported only in aggregates and FIRST_VALUE(), LAST_VALUE(), and NTH_VALUE() window functions.
","
RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE GROUP
"
"Other Grammar","Term","
...
...
@@ -2712,9 +2729,9 @@ INTERVAL '11:12.123' MINUTE TO SECOND
"Other Grammar","Interval","
intervalYear | intervalMonth | intervalDay | intervalHour | intervalMinute
| intervalSecond | intervalYearToMonth | intervalDayToHour
| intervalDayToMinute | intervalDayToSecond | intervalHourToMinute
| intervalHourToSecond | intervalMinuteToSecond
| intervalSecond | intervalYearToMonth | intervalDayToHour
| intervalDayToMinute | intervalDayToSecond | intervalHourToMinute
| intervalHourToSecond | intervalMinuteToSecond
","
An interval literal.
","
...
...
@@ -2723,7 +2740,7 @@ INTERVAL '1-2' YEAR TO MONTH
"Other Grammar","Value","
string | dollarQuotedString | numeric | dateAndTime | boolean | bytes
| interval | array | null
| interval | array | null
","
A literal value of any data type, or null.
","
...
...
@@ -5138,6 +5155,58 @@ SELECT CUME_DIST() OVER (ORDER BY ID), * FROM TEST;
SELECT CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"
"Functions (Window)","FIRST_VALUE","
FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS] OVER windowSpecification
","
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.
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 FIRST_VALUE(X) OVER (ORDER BY ID), * FROM TEST;
SELECT FIRST_VALUE(X) IGNORE NULLS OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"
"Functions (Window)","LAST_VALUE","
LAST_VALUE(value) [{RESPECT|IGNORE} NULLS] OVER windowSpecification
","
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 there is no non-null value it returns NULL.
Note that the last value is actually a value in the current row if window frame is not specified.
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 LAST_VALUE(X) OVER (ORDER BY ID), * FROM TEST;
SELECT LAST_VALUE(X) IGNORE NULLS OVER (
PARTITION BY CATEGORY ORDER BY ID
RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
), * FROM TEST;
"
"Functions (Window)","NTH_VALUE","
NTH_VALUE(value, nInt) [FROM {FIRST|LAST}] [{RESPECT|IGNORE} NULLS]
OVER windowSpecification
","
Returns the value in a row with a specified relative number in a window.
Relative row number must be positive.
If FROM LAST is specified rows a counted backwards from the last row.
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.
Note that the last row is actually a current row if window frame is not specified.
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 NTH_VALUE(X) OVER (ORDER BY ID), * FROM TEST;
SELECT NTH_VALUE(X) IGNORE NULLS OVER (
PARTITION BY CATEGORY ORDER BY ID
RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
), * FROM TEST;
"
"System Tables","Information Schema","
INFORMATION_SCHEMA
","
...
...
h2/src/docsrc/html/changelog.html
浏览文件 @
a1314402
...
...
@@ -21,6 +21,16 @@ Change Log
<h2>
Next Version (unreleased)
</h2>
<ul>
<li>
PR #1454: Add FIRST_VALUE(), LAST_VALUE(), and NTH_VALUE()
</li>
<li>
PR #1453, Issue #1161: Add ROW_NUMBER(), RANK(), DENSE_RANK(), PERCENT_RANK(), and CUME_DIST() window functions
</li>
<li>
PR #1452: Reset aggregates before reuse
</li>
<li>
PR #1451: Add experimental support for aggregates with OVER (ORDER BY *)
</li>
<li>
PR #1450: Evaluate window aggregates only once for each partition
</li>
<li>
PR #1449: Move more code from Aggregate and JavaAggregate to AbstractAggregate
</li>
<li>
PR #1448: Add experimental implementation of grouped window queries
...
...
@@ -33,6 +43,8 @@ Change Log
</li>
<li>
PR #1444: Add experimental unoptimized support for OVER ([PARTITION BY ...]) in aggregates
</li>
<li>
PR #1442: Bugfix - Release MVStore lock and file resources rightly even if errors when compacting database
</li>
<li>
PR #1441: Add GEOMETRY type subtypes with type and SRID constraints
</li>
<li>
PR #1434: Add support for ENUM in CAST and other changes
...
...
h2/src/docsrc/html/roadmap.html
浏览文件 @
a1314402
...
...
@@ -60,8 +60,6 @@ See also <a href="build.html#providing_patches">Providing Patches</a>.
DBMS_METADATA.GET_DDL / GET_DEPENDENT_DDL.
</li><li>
Clustering: support mixed clustering mode (one embedded, others in server mode).
</li><li>
Clustering: reads should be randomly distributed (optional) or to a designated database on RAM (parameter: READ_FROM=3).
</li><li>
Window functions: RANK() and DENSE_RANK(), partition using OVER().
select *, count(*) over() as fullCount from ... limit 4;
</li><li>
PostgreSQL catalog: use BEFORE SELECT triggers instead of views over metadata tables.
</li><li>
Test very large databases and LOBs (up to 256 GB).
</li><li>
Store all temp files in the temp directory.
...
...
@@ -87,7 +85,6 @@ See also <a href="build.html#providing_patches">Providing Patches</a>.
</li><li>
Index usage for (ID, NAME)=(1, 'Hi'); document.
</li><li>
Set a connection read only (Connection.setReadOnly) or using a connection parameter.
</li><li>
Access rights: finer grained access control (grant access for specific functions).
</li><li>
ROW_NUMBER() OVER([PARTITION BY columnName][ORDER BY columnName]).
</li><li>
Version check: docs / web console (using Javascript), and maybe in the library (using TCP/IP).
</li><li>
Web server classloader: override findResource / getResourceFrom.
</li><li>
Cost for embedded temporary view is calculated wrong, if result is constant.
...
...
@@ -120,7 +117,6 @@ See also <a href="build.html#providing_patches">Providing Patches</a>.
</li><li>
The HELP information schema can be directly exposed in the Console.
</li><li>
Maybe use the 0x1234 notation for binary fields, see MS SQL Server.
</li><li>
Support Oracle CONNECT BY in some way: http://www.adp-gmbh.ch/ora/sql/connect_by.html http://philip.greenspun.com/sql/trees.html
</li><li>
SQL Server 2005, Oracle: support COUNT(*) OVER(). See http://www.orafusion.com/art_anlytc.htm
</li><li>
SQL 2003: http://www.wiscorp.com/sql_2003_standard.zip
</li><li>
Version column (number/sequence and timestamp based).
</li><li>
Test and document UPDATE TEST SET (ID, NAME) = (SELECT ID*10, NAME || '!' FROM TEST T WHERE T.ID=TEST.ID).
...
...
@@ -413,7 +409,6 @@ See also <a href="build.html#providing_patches">Providing Patches</a>.
</li><li>
Issue 196: Function based indexes
</li><li>
Fix the disk space leak (killing the process at the exact right moment will increase
the disk space usage; this space is not re-used). See TestDiskSpaceLeak.java
</li><li>
ROWNUM: Oracle compatibility when used within a subquery. Issue 198.
</li><li>
Allow to access the database over HTTP (possibly using port 80) and a servlet in a REST way.
</li><li>
ODBC: encrypted databases are not supported because the ;CIPHER= can not be set.
</li><li>
Support CLOB and BLOB update, specially conn.createBlob().setBinaryStream(1);
...
...
h2/src/main/org/h2/command/Parser.java
浏览文件 @
a1314402
...
...
@@ -175,6 +175,9 @@ import org.h2.expression.aggregate.Aggregate;
import
org.h2.expression.aggregate.Aggregate.AggregateType
;
import
org.h2.expression.aggregate.JavaAggregate
;
import
org.h2.expression.aggregate.Window
;
import
org.h2.expression.aggregate.WindowFrame
;
import
org.h2.expression.aggregate.WindowFrame.SimpleExtent
;
import
org.h2.expression.aggregate.WindowFrame.WindowFrameExclusion
;
import
org.h2.expression.aggregate.WindowFunction
;
import
org.h2.expression.aggregate.WindowFunction.WindowFunctionType
;
import
org.h2.index.Index
;
...
...
@@ -3061,8 +3064,24 @@ public class Parser {
}
else
if
(!
isAggregate
)
{
orderBy
=
new
ArrayList
<>(
0
);
}
WindowFrame
frame
;
if
(
aggregate
instanceof
WindowFunction
)
{
WindowFunction
w
=
(
WindowFunction
)
aggregate
;
switch
(
w
.
getFunctionType
())
{
case
FIRST_VALUE:
case
LAST_VALUE:
case
NTH_VALUE:
frame
=
readWindowFrame
();
break
;
default
:
frame
=
new
WindowFrame
(
SimpleExtent
.
RANGE_BETWEEN_UNBOUNDED_PRECEDING_AND_CURRENT_ROW
,
WindowFrameExclusion
.
EXCLUDE_NO_OTHERS
);
}
}
else
{
frame
=
readWindowFrame
();
}
read
(
CLOSE_PAREN
);
over
=
new
Window
(
partitionBy
,
orderBy
);
over
=
new
Window
(
partitionBy
,
orderBy
,
frame
);
aggregate
.
setOverCondition
(
over
);
currentSelect
.
setWindowQuery
();
}
else
if
(!
isAggregate
)
{
...
...
@@ -3072,6 +3091,49 @@ public class Parser {
}
}
private
WindowFrame
readWindowFrame
()
{
SimpleExtent
extent
;
WindowFrameExclusion
exclusion
=
WindowFrameExclusion
.
EXCLUDE_NO_OTHERS
;
if
(
readIf
(
"RANGE"
))
{
read
(
"BETWEEN"
);
if
(
readIf
(
"UNBOUNDED"
))
{
read
(
"PRECEDING"
);
read
(
"AND"
);
if
(
readIf
(
"CURRENT"
))
{
read
(
"ROW"
);
extent
=
SimpleExtent
.
RANGE_BETWEEN_UNBOUNDED_PRECEDING_AND_CURRENT_ROW
;
}
else
{
read
(
"UNBOUNDED"
);
read
(
"FOLLOWING"
);
extent
=
SimpleExtent
.
RANGE_BETWEEN_UNBOUNDED_PRECEDING_AND_UNBOUNDED_FOLLOWING
;
}
}
else
{
read
(
"CURRENT"
);
read
(
"ROW"
);
read
(
"AND"
);
read
(
"UNBOUNDED"
);
read
(
"FOLLOWING"
);
extent
=
SimpleExtent
.
RANGE_BETWEEN_CURRENT_ROW_AND_UNBOUNDED_FOLLOWING
;
}
if
(
readIf
(
"EXCLUDE"
))
{
if
(
readIf
(
"CURRENT"
))
{
read
(
"ROW"
);
exclusion
=
WindowFrameExclusion
.
EXCLUDE_CURRENT_ROW
;
}
else
if
(
readIf
(
GROUP
))
{
exclusion
=
WindowFrameExclusion
.
EXCLUDE_GROUP
;
}
else
if
(
readIf
(
"TIES"
))
{
exclusion
=
WindowFrameExclusion
.
EXCLUDE_TIES
;
}
else
{
read
(
"NO"
);
read
(
"OTHERS"
);
}
}
}
else
{
extent
=
SimpleExtent
.
RANGE_BETWEEN_UNBOUNDED_PRECEDING_AND_CURRENT_ROW
;
}
return
new
WindowFrame
(
extent
,
exclusion
);
}
private
AggregateType
getAggregateType
(
String
name
)
{
if
(!
identifiersToUpper
)
{
// if not yet converted to uppercase, do it now
...
...
@@ -3270,12 +3332,51 @@ public class Parser {
if
(
currentSelect
==
null
)
{
throw
getSyntaxError
();
}
int
numArgs
=
WindowFunction
.
getArgumentCount
(
type
);
Expression
[]
args
=
null
;
if
(
numArgs
>
0
)
{
args
=
new
Expression
[
numArgs
];
for
(
int
i
=
0
;
i
<
numArgs
;
i
++)
{
if
(
i
>
0
)
{
read
(
COMMA
);
}
args
[
i
]
=
readExpression
();
}
}
read
(
CLOSE_PAREN
);
WindowFunction
function
=
new
WindowFunction
(
type
,
currentSelect
);
WindowFunction
function
=
new
WindowFunction
(
type
,
currentSelect
,
args
);
if
(
type
==
WindowFunctionType
.
NTH_VALUE
)
{
readFromFirstOrLast
(
function
);
}
switch
(
type
)
{
case
FIRST_VALUE:
case
LAST_VALUE:
case
NTH_VALUE:
readRespectOrIgnoreNulls
(
function
);
//$FALL-THROUGH$
default
:
// Avoid warning
}
readFilterAndOver
(
function
);
return
function
;
}
private
void
readFromFirstOrLast
(
WindowFunction
function
)
{
if
(
readIf
(
FROM
)
&&
!
readIf
(
"FIRST"
))
{
read
(
"LAST"
);
function
.
setFromLast
(
true
);
}
}
private
void
readRespectOrIgnoreNulls
(
WindowFunction
function
)
{
if
(
readIf
(
"RESPECT"
))
{
read
(
"NULLS"
);
}
else
if
(
readIf
(
"IGNORE"
))
{
read
(
"NULLS"
);
function
.
setIgnoreNulls
(
true
);
}
}
private
Expression
readFunctionWithoutParameters
(
String
name
)
{
if
(
database
.
isAllowBuiltinAliasOverride
())
{
FunctionAlias
functionAlias
=
database
.
getSchema
(
session
.
getCurrentSchemaName
()).
findFunction
(
name
);
...
...
h2/src/main/org/h2/expression/aggregate/AbstractAggregate.java
浏览文件 @
a1314402
...
...
@@ -8,6 +8,7 @@ package org.h2.expression.aggregate;
import
java.util.ArrayList
;
import
java.util.Collections
;
import
java.util.HashMap
;
import
java.util.Iterator
;
import
org.h2.api.ErrorCode
;
import
org.h2.command.dml.Select
;
...
...
@@ -113,6 +114,7 @@ public abstract class AbstractAggregate extends Expression {
@Override
public
Expression
optimize
(
Session
session
)
{
if
(
over
!=
null
)
{
over
.
optimize
(
session
);
ArrayList
<
SelectOrderBy
>
orderBy
=
over
.
getOrderBy
();
if
(
orderBy
!=
null
)
{
overOrderBySort
=
createOrder
(
session
,
orderBy
,
getNumExpressions
());
...
...
@@ -423,10 +425,32 @@ public abstract class AbstractAggregate extends Expression {
*/
protected
void
getOrderedResultLoop
(
Session
session
,
HashMap
<
Integer
,
Value
>
result
,
ArrayList
<
Value
[]>
ordered
,
int
rowIdColumn
)
{
Object
aggregateData
=
createAggregateData
();
for
(
Value
[]
row
:
ordered
)
{
updateFromExpressions
(
session
,
aggregateData
,
row
);
result
.
put
(
row
[
rowIdColumn
].
getInt
(),
getAggregatedValue
(
session
,
aggregateData
));
WindowFrame
frame
=
over
.
getWindowFrame
();
if
(
frame
.
isDefault
())
{
Object
aggregateData
=
createAggregateData
();
for
(
Value
[]
row
:
ordered
)
{
updateFromExpressions
(
session
,
aggregateData
,
row
);
result
.
put
(
row
[
rowIdColumn
].
getInt
(),
getAggregatedValue
(
session
,
aggregateData
));
}
}
else
if
(
frame
.
isFullPartition
())
{
Object
aggregateData
=
createAggregateData
();
for
(
Value
[]
row
:
ordered
)
{
updateFromExpressions
(
session
,
aggregateData
,
row
);
}
Value
value
=
getAggregatedValue
(
session
,
aggregateData
);
for
(
Value
[]
row
:
ordered
)
{
result
.
put
(
row
[
rowIdColumn
].
getInt
(),
value
);
}
}
else
{
int
size
=
ordered
.
size
();
for
(
int
i
=
0
;
i
<
size
;
i
++)
{
Object
aggregateData
=
createAggregateData
();
for
(
Iterator
<
Value
[]>
iter
=
frame
.
iterator
(
ordered
,
getOverOrderBySort
(),
i
,
false
);
iter
.
hasNext
();)
{
updateFromExpressions
(
session
,
aggregateData
,
iter
.
next
());
}
result
.
put
(
ordered
.
get
(
i
)[
rowIdColumn
].
getInt
(),
getAggregatedValue
(
session
,
aggregateData
));
}
}
}
...
...
h2/src/main/org/h2/expression/aggregate/Window.java
浏览文件 @
a1314402
...
...
@@ -26,6 +26,8 @@ public final class Window {
private
final
ArrayList
<
SelectOrderBy
>
orderBy
;
private
final
WindowFrame
frame
;
/**
* @param builder
* string builder
...
...
@@ -34,7 +36,10 @@ public final class Window {
*/
static
void
appendOrderBy
(
StringBuilder
builder
,
ArrayList
<
SelectOrderBy
>
orderBy
)
{
if
(
orderBy
!=
null
&&
!
orderBy
.
isEmpty
())
{
builder
.
append
(
" ORDER BY "
);
if
(
builder
.
charAt
(
builder
.
length
()
-
1
)
!=
'('
)
{
builder
.
append
(
' '
);
}
builder
.
append
(
"ORDER BY "
);
for
(
int
i
=
0
;
i
<
orderBy
.
size
();
i
++)
{
SelectOrderBy
o
=
orderBy
.
get
(
i
);
if
(
i
>
0
)
{
...
...
@@ -53,10 +58,13 @@ public final class Window {
* PARTITION BY clause, or null
* @param orderBy
* ORDER BY clause, or null
* @param frame
* window frame clause
*/
public
Window
(
ArrayList
<
Expression
>
partitionBy
,
ArrayList
<
SelectOrderBy
>
orderBy
)
{
public
Window
(
ArrayList
<
Expression
>
partitionBy
,
ArrayList
<
SelectOrderBy
>
orderBy
,
WindowFrame
frame
)
{
this
.
partitionBy
=
partitionBy
;
this
.
orderBy
=
orderBy
;
this
.
frame
=
frame
;
}
/**
...
...
@@ -81,6 +89,25 @@ public final class Window {
}
}
/**
* Try to optimize the window conditions.
*
* @param session
* the session
*/
public
void
optimize
(
Session
session
)
{
if
(
partitionBy
!=
null
)
{
for
(
int
i
=
0
;
i
<
partitionBy
.
size
();
i
++)
{
partitionBy
.
set
(
i
,
partitionBy
.
get
(
i
).
optimize
(
session
));
}
}
if
(
orderBy
!=
null
)
{
for
(
SelectOrderBy
o
:
orderBy
)
{
o
.
expression
=
o
.
expression
.
optimize
(
session
);
}
}
}
/**
* Tell the expression columns whether the table filter can return values
* now. This is used when optimizing the query.
...
...
@@ -113,6 +140,15 @@ public final class Window {
return
orderBy
;
}
/**
* Returns window frame.
*
* @return window frame
*/
public
WindowFrame
getWindowFrame
()
{
return
frame
;
}
/**
* Returns the key for the current group.
*
...
...
@@ -155,6 +191,9 @@ public final class Window {
}
}
appendOrderBy
(
builder
,
orderBy
);
if
(!
frame
.
isDefault
())
{
builder
.
append
(
' '
).
append
(
frame
.
getSQL
());
}
return
builder
.
append
(
')'
).
toString
();
}
...
...
h2/src/main/org/h2/expression/aggregate/WindowFrame.java
0 → 100644
浏览文件 @
a1314402
差异被折叠。
点击展开。
h2/src/main/org/h2/expression/aggregate/WindowFunction.java
浏览文件 @
a1314402
差异被折叠。
点击展开。
h2/src/test/org/h2/test/scripts/TestScript.java
浏览文件 @
a1314402
...
...
@@ -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"
})
{
for
(
String
s
:
new
String
[]
{
"row_number"
,
"nth_value"
})
{
testScript
(
"functions/window/"
+
s
+
".sql"
);
}
...
...
h2/src/test/org/h2/test/scripts/functions/aggregate/array-agg.sql
浏览文件 @
a1314402
...
...
@@ -233,8 +233,8 @@ SELECT
>
rows
:
6
SELECT
ARRAY_AGG
(
SUM
(
ID
))
OVER
(
ORDER
/**/
BY
ID
)
FROM
TEST
GROUP
BY
ID
;
>
ARRAY_AGG
(
SUM
(
ID
))
OVER
(
ORDER
BY
ID
)
>
-------------------------------------
-
>
ARRAY_AGG
(
SUM
(
ID
))
OVER
(
ORDER
BY
ID
)
>
-------------------------------------
>
(
1
)
>
(
1
,
2
)
>
(
1
,
2
,
3
)
...
...
@@ -245,3 +245,33 @@ SELECT ARRAY_AGG(SUM(ID)) OVER(ORDER /**/ BY ID) FROM TEST GROUP BY ID;
DROP
TABLE
TEST
;
>
ok
CREATE
TABLE
TEST
(
ID
INT
,
G
INT
);
>
ok
INSERT
INTO
TEST
VALUES
(
1
,
1
),
(
2
,
2
),
(
3
,
2
),
(
4
,
2
),
(
5
,
3
);
>
update
count
:
5
SELECT
ARRAY_AGG
(
ID
)
OVER
(
ORDER
BY
G
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
UNBOUNDED
FOLLOWING
)
D
,
ARRAY_AGG
(
ID
)
OVER
(
ORDER
BY
G
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
UNBOUNDED
FOLLOWING
EXCLUDE
CURRENT
ROW
)
R
,
ARRAY_AGG
(
ID
)
OVER
(
ORDER
BY
G
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
UNBOUNDED
FOLLOWING
EXCLUDE
GROUP
)
G
,
ARRAY_AGG
(
ID
)
OVER
(
ORDER
BY
G
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
UNBOUNDED
FOLLOWING
EXCLUDE
TIES
)
T
,
ARRAY_AGG
(
ID
)
OVER
(
ORDER
BY
G
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
UNBOUNDED
FOLLOWING
EXCLUDE
NO
OTHERS
)
N
FROM
TEST
;
>
D
R
G
T
N
>
--------------- ------------ ------------ --------------- ---------------
>
(
1
,
2
,
3
,
4
,
5
)
(
2
,
3
,
4
,
5
)
(
2
,
3
,
4
,
5
)
(
1
,
2
,
3
,
4
,
5
)
(
1
,
2
,
3
,
4
,
5
)
>
(
1
,
2
,
3
,
4
,
5
)
(
1
,
3
,
4
,
5
)
(
1
,
5
)
(
1
,
2
,
5
)
(
1
,
2
,
3
,
4
,
5
)
>
(
1
,
2
,
3
,
4
,
5
)
(
1
,
2
,
4
,
5
)
(
1
,
5
)
(
1
,
3
,
5
)
(
1
,
2
,
3
,
4
,
5
)
>
(
1
,
2
,
3
,
4
,
5
)
(
1
,
2
,
3
,
5
)
(
1
,
5
)
(
1
,
4
,
5
)
(
1
,
2
,
3
,
4
,
5
)
>
(
1
,
2
,
3
,
4
,
5
)
(
1
,
2
,
3
,
4
)
(
1
,
2
,
3
,
4
)
(
1
,
2
,
3
,
4
,
5
)
(
1
,
2
,
3
,
4
,
5
)
>
rows
(
ordered
):
5
DROP
TABLE
TEST
;
>
ok
h2/src/test/org/h2/test/scripts/functions/aggregate/sum.sql
浏览文件 @
a1314402
...
...
@@ -62,3 +62,22 @@ SELECT SUM(ID) OVER () FROM TEST;
DROP
TABLE
TEST
;
>
ok
SELECT
ID
,
SUM
(
ID
)
OVER
(
ORDER
BY
ID
)
S
,
SUM
(
ID
)
OVER
(
ORDER
BY
ID
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
CURRENT
ROW
)
S_U_C
,
SUM
(
ID
)
OVER
(
ORDER
BY
ID
RANGE
BETWEEN
CURRENT
ROW
AND
UNBOUNDED
FOLLOWING
)
S_C_U
,
SUM
(
ID
)
OVER
(
ORDER
BY
ID
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
UNBOUNDED
FOLLOWING
)
S_U_U
FROM
(
SELECT
X
ID
FROM
SYSTEM_RANGE
(
1
,
8
));
>
ID
S
S_U_C
S_C_U
S_U_U
>
-- -- ----- ----- -----
>
1
1
1
36
36
>
2
3
3
35
36
>
3
6
6
33
36
>
4
10
10
30
36
>
5
15
15
26
36
>
6
21
21
21
36
>
7
28
28
15
36
>
8
36
36
8
36
>
rows
(
ordered
):
8
h2/src/test/org/h2/test/scripts/functions/window/nth_value.sql
0 → 100644
浏览文件 @
a1314402
-- 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
FIRST_VALUE
(
1
)
OVER
(
PARTITION
BY
ID
);
>
exception
COLUMN_NOT_FOUND_1
SELECT
FIRST_VALUE
(
1
)
OVER
(
ORDER
BY
ID
);
>
exception
COLUMN_NOT_FOUND_1
CREATE
TABLE
TEST
(
ID
INT
PRIMARY
KEY
,
CATEGORY
INT
,
VALUE
INT
);
>
ok
INSERT
INTO
TEST
VALUES
(
1
,
1
,
NULL
),
(
2
,
1
,
12
),
(
3
,
1
,
NULL
),
(
4
,
1
,
13
),
(
5
,
1
,
NULL
),
(
6
,
1
,
13
),
(
7
,
2
,
21
),
(
8
,
2
,
22
),
(
9
,
3
,
31
),
(
10
,
3
,
32
),
(
11
,
3
,
33
),
(
12
,
4
,
41
),
(
13
,
4
,
NULL
);
>
update
count
:
13
SELECT
*
,
FIRST_VALUE
(
VALUE
)
OVER
(
ORDER
BY
ID
)
FIRST
,
FIRST_VALUE
(
VALUE
)
RESPECT
NULLS
OVER
(
ORDER
BY
ID
)
FIRST_N
,
FIRST_VALUE
(
VALUE
)
IGNORE
NULLS
OVER
(
ORDER
BY
ID
)
FIRST_NN
,
LAST_VALUE
(
VALUE
)
OVER
(
ORDER
BY
ID
)
LAST
,
LAST_VALUE
(
VALUE
)
RESPECT
NULLS
OVER
(
ORDER
BY
ID
)
LAST_N
,
LAST_VALUE
(
VALUE
)
IGNORE
NULLS
OVER
(
ORDER
BY
ID
)
LAST_NN
FROM
TEST
FETCH
FIRST
6
ROWS
ONLY
;
>
ID
CATEGORY
VALUE
FIRST
FIRST_N
FIRST_NN
LAST
LAST_N
LAST_NN
>
-- -------- ----- ----- ------- -------- ---- ------ -------
>
1
1
null
null
null
null
null
null
null
>
2
1
12
null
null
12
12
12
12
>
3
1
null
null
null
12
null
null
12
>
4
1
13
null
null
12
13
13
13
>
5
1
null
null
null
12
null
null
13
>
6
1
13
null
null
12
13
13
13
>
rows
(
ordered
):
6
SELECT
*
,
FIRST_VALUE
(
VALUE
)
OVER
(
ORDER
BY
ID
)
FIRST
,
FIRST_VALUE
(
VALUE
)
RESPECT
NULLS
OVER
(
ORDER
BY
ID
)
FIRST_N
,
FIRST_VALUE
(
VALUE
)
IGNORE
NULLS
OVER
(
ORDER
BY
ID
)
FIRST_NN
,
LAST_VALUE
(
VALUE
)
OVER
(
ORDER
BY
ID
)
LAST
,
LAST_VALUE
(
VALUE
)
RESPECT
NULLS
OVER
(
ORDER
BY
ID
)
LAST_N
,
LAST_VALUE
(
VALUE
)
IGNORE
NULLS
OVER
(
ORDER
BY
ID
)
LAST_NN
FROM
TEST
WHERE
ID
>
1
FETCH
FIRST
3
ROWS
ONLY
;
>
ID
CATEGORY
VALUE
FIRST
FIRST_N
FIRST_NN
LAST
LAST_N
LAST_NN
>
-- -------- ----- ----- ------- -------- ---- ------ -------
>
2
1
12
12
12
12
12
12
12
>
3
1
null
12
12
12
null
null
12
>
4
1
13
12
12
12
13
13
13
>
rows
(
ordered
):
3
SELECT
*
,
NTH_VALUE
(
VALUE
,
2
)
OVER
(
ORDER
BY
ID
)
NTH
,
NTH_VALUE
(
VALUE
,
2
)
FROM
FIRST
OVER
(
ORDER
BY
ID
)
NTH_FF
,
NTH_VALUE
(
VALUE
,
2
)
FROM
LAST
OVER
(
ORDER
BY
ID
)
NTH_FL
,
NTH_VALUE
(
VALUE
,
2
)
RESPECT
NULLS
OVER
(
ORDER
BY
ID
)
NTH_N
,
NTH_VALUE
(
VALUE
,
2
)
FROM
FIRST
RESPECT
NULLS
OVER
(
ORDER
BY
ID
)
NTH_FF_N
,
NTH_VALUE
(
VALUE
,
2
)
FROM
LAST
RESPECT
NULLS
OVER
(
ORDER
BY
ID
)
NTH_FL_N
,
NTH_VALUE
(
VALUE
,
2
)
IGNORE
NULLS
OVER
(
ORDER
BY
ID
)
NTH_NN
,
NTH_VALUE
(
VALUE
,
2
)
FROM
FIRST
IGNORE
NULLS
OVER
(
ORDER
BY
ID
)
NTH_FF_NN
,
NTH_VALUE
(
VALUE
,
2
)
FROM
LAST
IGNORE
NULLS
OVER
(
ORDER
BY
ID
)
NTH_FL_NN
FROM
TEST
FETCH
FIRST
6
ROWS
ONLY
;
>
ID
CATEGORY
VALUE
NTH
NTH_FF
NTH_FL
NTH_N
NTH_FF_N
NTH_FL_N
NTH_NN
NTH_FF_NN
NTH_FL_NN
>
-- -------- ----- ---- ------ ------ ----- -------- -------- ------ --------- ---------
>
1
1
null
null
null
null
null
null
null
null
null
null
>
2
1
12
12
12
null
12
12
null
null
null
null
>
3
1
null
12
12
12
12
12
12
null
null
null
>
4
1
13
12
12
null
12
12
null
13
13
12
>
5
1
null
12
12
13
12
12
13
13
13
12
>
6
1
13
12
12
null
12
12
null
13
13
13
>
rows
(
ordered
):
6
SELECT
*
,
NTH_VALUE
(
VALUE
,
2
)
OVER
(
ORDER
BY
ID
)
F
,
NTH_VALUE
(
VALUE
,
2
)
OVER
(
ORDER
BY
ID
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
CURRENT
ROW
)
F_U_C
,
NTH_VALUE
(
VALUE
,
2
)
OVER
(
ORDER
BY
ID
RANGE
BETWEEN
CURRENT
ROW
AND
UNBOUNDED
FOLLOWING
)
F_C_U
,
NTH_VALUE
(
VALUE
,
2
)
OVER
(
ORDER
BY
ID
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
UNBOUNDED
FOLLOWING
)
F_U_U
,
NTH_VALUE
(
VALUE
,
2
)
FROM
LAST
OVER
(
ORDER
BY
ID
)
L
,
NTH_VALUE
(
VALUE
,
2
)
FROM
LAST
OVER
(
ORDER
BY
ID
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
CURRENT
ROW
)
L_U_C
,
NTH_VALUE
(
VALUE
,
2
)
FROM
LAST
OVER
(
ORDER
BY
ID
RANGE
BETWEEN
CURRENT
ROW
AND
UNBOUNDED
FOLLOWING
)
L_C_U
,
NTH_VALUE
(
VALUE
,
2
)
FROM
LAST
OVER
(
ORDER
BY
ID
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
UNBOUNDED
FOLLOWING
)
L_U_U
FROM
TEST
;
>
ID
CATEGORY
VALUE
F
F_U_C
F_C_U
F_U_U
L
L_U_C
L_C_U
L_U_U
>
-- -------- ----- ---- ----- ----- ----- ---- ----- ----- -----
>
1
1
null
null
null
12
12
null
null
41
41
>
2
1
12
12
12
null
12
null
null
41
41
>
3
1
null
12
12
13
12
12
12
41
41
>
4
1
13
12
12
null
12
null
null
41
41
>
5
1
null
12
12
13
12
13
13
41
41
>
6
1
13
12
12
21
12
null
null
41
41
>
7
2
21
12
12
22
12
13
13
41
41
>
8
2
22
12
12
31
12
21
21
41
41
>
9
3
31
12
12
32
12
22
22
41
41
>
10
3
32
12
12
33
12
31
31
41
41
>
11
3
33
12
12
41
12
32
32
41
41
>
12
4
41
12
12
null
12
33
33
41
41
>
13
4
null
12
12
null
12
41
41
null
41
>
rows
(
ordered
):
13
SELECT
NTH_VALUE
(
VALUE
,
0
)
OVER
(
ORDER
BY
ID
)
FROM
TEST
;
>
exception
INVALID_VALUE_2
SELECT
*
,
FIRST_VALUE
(
VALUE
)
OVER
(
PARTITION
BY
CATEGORY
ORDER
BY
ID
)
FIRST
,
LAST_VALUE
(
VALUE
)
OVER
(
PARTITION
BY
CATEGORY
ORDER
BY
ID
)
LAST
,
NTH_VALUE
(
VALUE
,
2
)
OVER
(
PARTITION
BY
CATEGORY
ORDER
BY
ID
)
NTH
FROM
TEST
;
>
ID
CATEGORY
VALUE
FIRST
LAST
NTH
>
-- -------- ----- ----- ---- ----
>
1
1
null
null
null
null
>
2
1
12
null
12
12
>
3
1
null
null
null
12
>
4
1
13
null
13
12
>
5
1
null
null
null
12
>
6
1
13
null
13
12
>
7
2
21
21
21
null
>
8
2
22
21
22
22
>
9
3
31
31
31
null
>
10
3
32
31
32
32
>
11
3
33
31
33
32
>
12
4
41
41
41
null
>
13
4
null
41
null
null
>
rows
(
ordered
):
13
SELECT
ID
,
CATEGORY
,
NTH_VALUE
(
CATEGORY
,
2
)
OVER
(
ORDER
BY
CATEGORY
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
CURRENT
ROW
)
C
,
NTH_VALUE
(
CATEGORY
,
2
)
OVER
(
ORDER
BY
CATEGORY
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
CURRENT
ROW
EXCLUDE
CURRENT
ROW
)
FROM
TEST
FETCH
FIRST
3
ROWS
ONLY
;
>
ID
CATEGORY
C
NTH_VALUE
(
CATEGORY
,
2
)
OVER
(
ORDER
BY
CATEGORY
RANGE
BETWEEN
UNBOUNDED
PRECEDING
AND
CURRENT
ROW
EXCLUDE
CURRENT
ROW
)
>
-- -------- ---- ---------------------------------------------------------------------------------------------------------------------
>
1
1
null
null
>
2
1
1
null
>
3
1
1
1
>
rows
(
ordered
):
3
DROP
TABLE
TEST
;
>
ok
h2/src/tools/org/h2/build/doc/dictionary.txt
浏览文件 @
a1314402
...
...
@@ -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
ranks rno dro rko precede cume
reopens preceding unbounded rightly itr
编写
预览
Markdown
格式
0%
重试
或
添加新文件
添加附件
取消
您添加了
0
人
到此讨论。请谨慎行事。
请先完成此评论的编辑!
取消
请
注册
或者
登录
后发表评论