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

Merge pull request #1453 from katzyn/window

Add ROW_NUMBER(), RANK(), DENSE_RANK(), PERCENT_RANK(), and CUME_DIST() window functions
...@@ -2533,6 +2533,19 @@ The column list of the resulting table is C1, C2, and so on. ...@@ -2533,6 +2533,19 @@ The column list of the resulting table is C1, C2, and so on.
SELECT * FROM (VALUES(1, 'Hello'), (2, 'World')) AS V; SELECT * FROM (VALUES(1, 'Hello'), (2, 'World')) AS V;
" "
"Other Grammar","Window specification","
([PARTITION BY expression [,...]] [ORDER BY order [,...]])
","
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.
","
()
(ORDER BY ID)
(PARTITION BY CATEGORY)
(PARTITION BY CATEGORY ORDER BY NAME, ID)
"
"Other Grammar","Term"," "Other Grammar","Term","
value value
| columnName | columnName
...@@ -3251,7 +3264,8 @@ INTERVAL MINUTE TO SECOND ...@@ -3251,7 +3264,8 @@ INTERVAL MINUTE TO SECOND
" "
"Functions (Aggregate)","AVG"," "Functions (Aggregate)","AVG","
AVG ( [ DISTINCT ] { numeric } ) [ FILTER ( WHERE expression ) ] AVG ( [ DISTINCT ] { numeric } )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The average (mean) value. The average (mean) value.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3262,7 +3276,8 @@ AVG(X) ...@@ -3262,7 +3276,8 @@ AVG(X)
" "
"Functions (Aggregate)","BIT_AND"," "Functions (Aggregate)","BIT_AND","
BIT_AND(expression) [ FILTER ( WHERE expression ) ] BIT_AND(expression)
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The bitwise AND of all non-null values. The bitwise AND of all non-null values.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3272,7 +3287,8 @@ BIT_AND(ID) ...@@ -3272,7 +3287,8 @@ BIT_AND(ID)
" "
"Functions (Aggregate)","BIT_OR"," "Functions (Aggregate)","BIT_OR","
BIT_OR(expression) [ FILTER ( WHERE expression ) ] BIT_OR(expression)
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The bitwise OR of all non-null values. The bitwise OR of all non-null values.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3282,7 +3298,8 @@ BIT_OR(ID) ...@@ -3282,7 +3298,8 @@ BIT_OR(ID)
" "
"Functions (Aggregate)","BOOL_AND"," "Functions (Aggregate)","BOOL_AND","
BOOL_AND(boolean) [ FILTER ( WHERE expression ) ] BOOL_AND(boolean)
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
Returns true if all expressions are true. Returns true if all expressions are true.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3292,7 +3309,8 @@ BOOL_AND(ID>10) ...@@ -3292,7 +3309,8 @@ BOOL_AND(ID>10)
" "
"Functions (Aggregate)","BOOL_OR"," "Functions (Aggregate)","BOOL_OR","
BOOL_OR(boolean) [ FILTER ( WHERE expression ) ] BOOL_OR(boolean)
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
Returns true if any expression is true. Returns true if any expression is true.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3302,7 +3320,8 @@ BOOL_OR(NAME LIKE 'W%') ...@@ -3302,7 +3320,8 @@ BOOL_OR(NAME LIKE 'W%')
" "
"Functions (Aggregate)","COUNT"," "Functions (Aggregate)","COUNT","
COUNT( { * | { [ DISTINCT ] expression } } ) [ FILTER ( WHERE expression ) ] COUNT( { * | { [ DISTINCT ] expression } } )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The count of all row, or of the non-null values. The count of all row, or of the non-null values.
This method returns a long. This method returns a long.
...@@ -3315,7 +3334,8 @@ COUNT(*) ...@@ -3315,7 +3334,8 @@ COUNT(*)
"Functions (Aggregate)","GROUP_CONCAT"," "Functions (Aggregate)","GROUP_CONCAT","
GROUP_CONCAT ( [ DISTINCT ] string GROUP_CONCAT ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ] [ ORDER BY { expression [ ASC | DESC ] } [,...] ]
[ SEPARATOR expression ] ) [ FILTER ( WHERE expression ) ] [ SEPARATOR expression ] )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
Concatenates strings with a separator. Concatenates strings with a separator.
The default separator is a ',' (without space). The default separator is a ',' (without space).
...@@ -3329,7 +3349,7 @@ GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ') ...@@ -3329,7 +3349,7 @@ GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ')
"Functions (Aggregate)","ARRAY_AGG"," "Functions (Aggregate)","ARRAY_AGG","
ARRAY_AGG ( [ DISTINCT ] string ARRAY_AGG ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ] ) [ ORDER BY { expression [ ASC | DESC ] } [,...] ] )
[ FILTER ( WHERE expression ) ] [FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
Aggregate the value into an array. Aggregate the value into an array.
This method returns an array. This method returns an array.
...@@ -3340,7 +3360,8 @@ ARRAY_AGG(NAME ORDER BY ID) ...@@ -3340,7 +3360,8 @@ ARRAY_AGG(NAME ORDER BY ID)
" "
"Functions (Aggregate)","MAX"," "Functions (Aggregate)","MAX","
MAX(value) [ FILTER ( WHERE expression ) ] MAX(value)
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The highest value. The highest value.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3351,7 +3372,8 @@ MAX(NAME) ...@@ -3351,7 +3372,8 @@ MAX(NAME)
" "
"Functions (Aggregate)","MIN"," "Functions (Aggregate)","MIN","
MIN(value) [ FILTER ( WHERE expression ) ] MIN(value)
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The lowest value. The lowest value.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3362,7 +3384,8 @@ MIN(NAME) ...@@ -3362,7 +3384,8 @@ MIN(NAME)
" "
"Functions (Aggregate)","SUM"," "Functions (Aggregate)","SUM","
SUM( [ DISTINCT ] { numeric } ) [ FILTER ( WHERE expression ) ] SUM( [ DISTINCT ] { numeric } )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The sum of all values. The sum of all values.
If no rows are selected, the result is NULL. If no rows are selected, the result is NULL.
...@@ -3374,7 +3397,8 @@ SUM(X) ...@@ -3374,7 +3397,8 @@ SUM(X)
" "
"Functions (Aggregate)","SELECTIVITY"," "Functions (Aggregate)","SELECTIVITY","
SELECTIVITY(value) [ FILTER ( WHERE expression ) ] SELECTIVITY(value)
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
Estimates the selectivity (0-100) of a value. Estimates the selectivity (0-100) of a value.
The value is defined as (100 * distinctCount / rowCount). The value is defined as (100 * distinctCount / rowCount).
...@@ -3386,7 +3410,8 @@ SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000 ...@@ -3386,7 +3410,8 @@ SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000
" "
"Functions (Aggregate)","STDDEV_POP"," "Functions (Aggregate)","STDDEV_POP","
STDDEV_POP( [ DISTINCT ] numeric ) [ FILTER ( WHERE expression ) ] STDDEV_POP( [ DISTINCT ] numeric )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The population standard deviation. The population standard deviation.
This method returns a double. This method returns a double.
...@@ -3397,7 +3422,8 @@ STDDEV_POP(X) ...@@ -3397,7 +3422,8 @@ STDDEV_POP(X)
" "
"Functions (Aggregate)","STDDEV_SAMP"," "Functions (Aggregate)","STDDEV_SAMP","
STDDEV_SAMP( [ DISTINCT ] numeric ) [ FILTER ( WHERE expression ) ] STDDEV_SAMP( [ DISTINCT ] numeric )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The sample standard deviation. The sample standard deviation.
This method returns a double. This method returns a double.
...@@ -3408,7 +3434,8 @@ STDDEV(X) ...@@ -3408,7 +3434,8 @@ STDDEV(X)
" "
"Functions (Aggregate)","VAR_POP"," "Functions (Aggregate)","VAR_POP","
VAR_POP( [ DISTINCT ] numeric ) [ FILTER ( WHERE expression ) ] VAR_POP( [ DISTINCT ] numeric )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The population variance (square of the population standard deviation). The population variance (square of the population standard deviation).
This method returns a double. This method returns a double.
...@@ -3419,7 +3446,8 @@ VAR_POP(X) ...@@ -3419,7 +3446,8 @@ VAR_POP(X)
" "
"Functions (Aggregate)","VAR_SAMP"," "Functions (Aggregate)","VAR_SAMP","
VAR_SAMP( [ DISTINCT ] numeric ) [ FILTER ( WHERE expression ) ] VAR_SAMP( [ DISTINCT ] numeric )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The sample variance (square of the sample standard deviation). The sample variance (square of the sample standard deviation).
This method returns a double. This method returns a double.
...@@ -3430,7 +3458,8 @@ VAR_SAMP(X) ...@@ -3430,7 +3458,8 @@ VAR_SAMP(X)
" "
"Functions (Aggregate)","MEDIAN"," "Functions (Aggregate)","MEDIAN","
MEDIAN( [ DISTINCT ] value ) [ FILTER ( WHERE expression ) ] MEDIAN( [ DISTINCT ] value )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
The value separating the higher half of a values from the lower half. The value separating the higher half of a values from the lower half.
Returns the middle value or an interpolated value between two middle values if number of values is even. Returns the middle value or an interpolated value between two middle values if number of values is even.
...@@ -3445,7 +3474,7 @@ MEDIAN(X) ...@@ -3445,7 +3474,7 @@ MEDIAN(X)
"Functions (Aggregate)","MODE"," "Functions (Aggregate)","MODE","
{ MODE( value ) [ ORDER BY expression [ ASC | DESC ] ] } { MODE( value ) [ ORDER BY expression [ ASC | DESC ] ] }
| { MODE() WITHIN GROUP(ORDER BY expression [ ASC | DESC ]) } | { MODE() WITHIN GROUP(ORDER BY expression [ ASC | DESC ]) }
[ FILTER ( WHERE expression ) ] [FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
Returns the value that occurs with the greatest frequency. Returns the value that occurs with the greatest frequency.
If there are multiple values with the same frequency only one value will be returned. If there are multiple values with the same frequency only one value will be returned.
...@@ -3464,7 +3493,8 @@ MODE() WITHIN GROUP(ORDER BY X) ...@@ -3464,7 +3493,8 @@ MODE() WITHIN GROUP(ORDER BY X)
" "
"Functions (Aggregate)","ENVELOPE"," "Functions (Aggregate)","ENVELOPE","
ENVELOPE( value ) [ FILTER ( WHERE expression ) ] ENVELOPE( value )
[FILTER (WHERE expression)] [OVER windowSpecification]
"," ","
Returns the minimum bounding box that encloses all specified GEOMETRY values. Returns the minimum bounding box that encloses all specified GEOMETRY values.
Only 2D coordinate plane is supported. Only 2D coordinate plane is supported.
...@@ -4931,14 +4961,14 @@ READONLY() ...@@ -4931,14 +4961,14 @@ READONLY()
" "
"Functions (System)","ROWNUM"," "Functions (System)","ROWNUM","
{ ROWNUM() } | { ROW_NUMBER() OVER() } ROWNUM()
"," ","
Returns the number of the current row. Returns the number of the current row.
This method returns a long. This method returns an integer value.
It is supported for SELECT statements, as well as for DELETE and UPDATE. It is supported for SELECT statements, as well as for DELETE and UPDATE.
The first row has the row number 1, and is calculated before ordering and grouping the result set, The first row has the row number 1, and is calculated before ordering and grouping the result set,
but after evaluating index conditions (even when the index conditions are specified in an outer query). but after evaluating index conditions (even when the index conditions are specified in an outer query).
To get the row number after ordering and grouping, use a subquery. Use the ROW_NUMBER() OVER () function to get row numbers after grouping or in specified order.
"," ","
SELECT ROWNUM(), * FROM TEST; SELECT ROWNUM(), * FROM TEST;
SELECT ROWNUM(), * FROM (SELECT * FROM TEST ORDER BY NAME); SELECT ROWNUM(), * FROM (SELECT * FROM TEST ORDER BY NAME);
...@@ -5036,6 +5066,78 @@ Returns the H2 version as a String. ...@@ -5036,6 +5066,78 @@ Returns the H2 version as a String.
H2VERSION() H2VERSION()
" "
"Functions (Window)","ROW_NUMBER","
ROW_NUMBER() OVER windowSpecification
","
Returns the number of the current row starting with 1.
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 ROW_NUMBER() OVER (), * FROM TEST;
SELECT ROW_NUMBER() OVER (ORDER BY ID), * FROM TEST;
SELECT ROW_NUMBER() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"
"Functions (Window)","RANK","
RANK() OVER windowSpecification
","
Returns the rank of the current row.
The rank of a row is the number of rows that precede this row plus 1.
If two or more rows have the same values in ORDER BY columns, these rows get the same rank from the first row with the same values.
It means that gaps in ranks are possible.
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 RANK() OVER (ORDER BY ID), * FROM TEST;
SELECT RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"
"Functions (Window)","DENSE_RANK","
DENSE_RANK() OVER windowSpecification
","
Returns the dense rank of the current row.
The rank of a row is the number of groups of rows with the same values in ORDER BY columns that precede group with this row plus 1.
If two or more rows have the same values in ORDER BY columns, these rows get the same rank.
Gaps in ranks are not possible.
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 DENSE_RANK() OVER (ORDER BY ID), * FROM TEST;
SELECT DENSE_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"
"Functions (Window)","PERCENT_RANK","
PERCENT_RANK() OVER windowSpecification
","
Returns the relative rank of the current row.
The relative rank is calculated as (RANK - 1) / (NR - 1),
where RANK is a rank of the row and NR is a number of rows in window partition with this row.
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 PERCENT_RANK() OVER (ORDER BY ID), * FROM TEST;
SELECT PERCENT_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"
"Functions (Window)","CUME_DIST","
CUME_DIST() OVER windowSpecification
","
Returns the relative rank of the current row.
The relative rank is calculated as NP / NR
where NP is a number of rows that precede the current row or have the same values in ORDER BY columns
and NR is a number of rows in window partition with this row.
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 CUME_DIST() OVER (ORDER BY ID), * FROM TEST;
SELECT CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"
"System Tables","Information Schema"," "System Tables","Information Schema","
INFORMATION_SCHEMA INFORMATION_SCHEMA
"," ","
......
...@@ -159,6 +159,34 @@ syntax-end --> ...@@ -159,6 +159,34 @@ syntax-end -->
</table> </table>
<!-- railroad-end --> <!-- railroad-end -->
<h3>Window Functions</h3>
<!-- syntax-start
<p class="notranslate">
<c:forEach var="item" items="functionsWindow">
<a href="#${item.link}" >${item.topic}</a><br />
</c:forEach>
</p>
syntax-end -->
<!-- railroad-start -->
<table class="notranslate index">
<tr>
<td class="index">
<c:forEach var="item" items="functionsWindow-0">
<a href="#${item.link}" >${item.topic}</a><br />
</c:forEach>
</td><td class="index">
<c:forEach var="item" items="functionsWindow-1">
<a href="#${item.link}" >${item.topic}</a><br />
</c:forEach>
</td><td class="index">
<c:forEach var="item" items="functionsWindow-2">
<a href="#${item.link}" >${item.topic}</a><br />
</c:forEach>
</td>
</tr>
</table>
<!-- railroad-end -->
<!-- railroad-start --> <!-- railroad-start -->
<h2>Details</h2> <h2>Details</h2>
<p>Click on the header to switch between railroad diagram and BNF.</p> <p>Click on the header to switch between railroad diagram and BNF.</p>
...@@ -269,6 +297,27 @@ syntax-end --> ...@@ -269,6 +297,27 @@ syntax-end -->
<p class="notranslate">${item.example}</p> <p class="notranslate">${item.example}</p>
</c:forEach> </c:forEach>
<h2>Window Functions</h2>
<c:forEach var="item" items="functionsWindow">
<h3 id="${item.link}" class="notranslate" onclick="switchBnf(this)">${item.topic}</h3>
<!-- railroad-start -->
<pre name="bnf" style="display: none">
${item.syntax}
</pre>
<div name="railroad">
${item.railroad}
</div>
<!-- railroad-end -->
<!-- syntax-start
<pre>
${item.syntax}
</pre>
syntax-end -->
<p>${item.text}</p>
<p>Example:</p>
<p class="notranslate">${item.example}</p>
</c:forEach>
<!--[if lte IE 7]><script language="javascript">switchBnf(null);</script><![endif]--> <!--[if lte IE 7]><script language="javascript">switchBnf(null);</script><![endif]-->
<!-- [close] { --></div></td></tr></table><!-- } --><!-- analytics --></body></html> <!-- [close] { --></div></td></tr></table><!-- } --><!-- analytics --></body></html>
......
...@@ -175,6 +175,8 @@ import org.h2.expression.aggregate.Aggregate; ...@@ -175,6 +175,8 @@ import org.h2.expression.aggregate.Aggregate;
import org.h2.expression.aggregate.Aggregate.AggregateType; import org.h2.expression.aggregate.Aggregate.AggregateType;
import org.h2.expression.aggregate.JavaAggregate; import org.h2.expression.aggregate.JavaAggregate;
import org.h2.expression.aggregate.Window; import org.h2.expression.aggregate.Window;
import org.h2.expression.aggregate.WindowFunction;
import org.h2.expression.aggregate.WindowFunction.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;
...@@ -3032,13 +3034,15 @@ public class Parser { ...@@ -3032,13 +3034,15 @@ public class Parser {
} }
private void readFilterAndOver(AbstractAggregate aggregate) { private void readFilterAndOver(AbstractAggregate aggregate) {
if (readIf("FILTER")) { boolean isAggregate = aggregate.isAggregate();
if (isAggregate && readIf("FILTER")) {
read(OPEN_PAREN); read(OPEN_PAREN);
read(WHERE); read(WHERE);
Expression filterCondition = readExpression(); Expression filterCondition = readExpression();
read(CLOSE_PAREN); read(CLOSE_PAREN);
aggregate.setFilterCondition(filterCondition); aggregate.setFilterCondition(filterCondition);
} }
Window over = null;
if (readIf("OVER")) { if (readIf("OVER")) {
read(OPEN_PAREN); read(OPEN_PAREN);
ArrayList<Expression> partitionBy = null; ArrayList<Expression> partitionBy = null;
...@@ -3054,10 +3058,15 @@ public class Parser { ...@@ -3054,10 +3058,15 @@ public class Parser {
if (readIf(ORDER)) { if (readIf(ORDER)) {
read("BY"); read("BY");
orderBy = parseSimpleOrderList(); orderBy = parseSimpleOrderList();
} else if (!isAggregate) {
orderBy = new ArrayList<>(0);
} }
read(CLOSE_PAREN); read(CLOSE_PAREN);
aggregate.setOverCondition(new Window(partitionBy, orderBy)); over = new Window(partitionBy, orderBy);
aggregate.setOverCondition(over);
currentSelect.setWindowQuery(); currentSelect.setWindowQuery();
} else if (!isAggregate) {
throw getSyntaxError();
} else { } else {
currentSelect.setGroupQuery(); currentSelect.setGroupQuery();
} }
...@@ -3088,6 +3097,10 @@ public class Parser { ...@@ -3088,6 +3097,10 @@ public class Parser {
} }
Function function = Function.getFunction(database, name); Function function = Function.getFunction(database, name);
if (function == null) { if (function == null) {
WindowFunction windowFunction = readWindowFunction(name);
if (windowFunction != null) {
return windowFunction;
}
UserAggregate aggregate = database.findAggregate(name); UserAggregate aggregate = database.findAggregate(name);
if (aggregate != null) { if (aggregate != null) {
return readJavaAggregate(aggregate); return readJavaAggregate(aggregate);
...@@ -3233,16 +3246,6 @@ public class Parser { ...@@ -3233,16 +3246,6 @@ public class Parser {
tf.setColumns(columns); tf.setColumns(columns);
break; break;
} }
case Function.ROW_NUMBER:
read(CLOSE_PAREN);
read("OVER");
read(OPEN_PAREN);
read(CLOSE_PAREN);
if (currentSelect == null && currentPrepared == null) {
throw getSyntaxError();
}
return new Rownum(currentSelect == null ? currentPrepared
: currentSelect);
default: default:
if (!readIf(CLOSE_PAREN)) { if (!readIf(CLOSE_PAREN)) {
int i = 0; int i = 0;
...@@ -3255,6 +3258,24 @@ public class Parser { ...@@ -3255,6 +3258,24 @@ public class Parser {
return function; return function;
} }
private WindowFunction readWindowFunction(String name) {
if (!database.getSettings().databaseToUpper) {
// if not yet converted to uppercase, do it now
name = StringUtils.toUpperEnglish(name);
}
WindowFunctionType type = WindowFunctionType.get(name);
if (type == null) {
return null;
}
if (currentSelect == null) {
throw getSyntaxError();
}
read(CLOSE_PAREN);
WindowFunction function = new WindowFunction(type, currentSelect);
readFilterAndOver(function);
return function;
}
private Expression readFunctionWithoutParameters(String name) { private Expression readFunctionWithoutParameters(String name) {
if (database.isAllowBuiltinAliasOverride()) { if (database.isAllowBuiltinAliasOverride()) {
FunctionAlias functionAlias = database.getSchema(session.getCurrentSchemaName()).findFunction(name); FunctionAlias functionAlias = database.getSchema(session.getCurrentSchemaName()).findFunction(name);
......
...@@ -146,8 +146,6 @@ public class Function extends Expression implements FunctionCall { ...@@ -146,8 +146,6 @@ public class Function extends Expression implements FunctionCall {
*/ */
public static final int H2VERSION = 231; public static final int H2VERSION = 231;
public static final int ROW_NUMBER = 300;
protected static final int VAR_ARGS = -1; protected static final int VAR_ARGS = -1;
private static final long PRECISION_UNKNOWN = -1; private static final long PRECISION_UNKNOWN = -1;
...@@ -470,9 +468,6 @@ public class Function extends Expression implements FunctionCall { ...@@ -470,9 +468,6 @@ public class Function extends Expression implements FunctionCall {
addFunctionWithNull("TABLE_DISTINCT", TABLE_DISTINCT, addFunctionWithNull("TABLE_DISTINCT", TABLE_DISTINCT,
VAR_ARGS, Value.RESULT_SET); VAR_ARGS, Value.RESULT_SET);
// pseudo function
addFunctionWithNull("ROW_NUMBER", ROW_NUMBER, 0, Value.LONG);
// ON DUPLICATE KEY VALUES function // ON DUPLICATE KEY VALUES function
addFunction("VALUES", VALUES, 1, Value.NULL, false, true, false); addFunction("VALUES", VALUES, 1, Value.NULL, false, true, false);
} }
......
...@@ -15,6 +15,7 @@ import org.h2.command.dml.SelectGroups; ...@@ -15,6 +15,7 @@ import org.h2.command.dml.SelectGroups;
import org.h2.command.dml.SelectOrderBy; import org.h2.command.dml.SelectOrderBy;
import org.h2.engine.Session; import org.h2.engine.Session;
import org.h2.expression.Expression; import org.h2.expression.Expression;
import org.h2.expression.ExpressionVisitor;
import org.h2.message.DbException; import org.h2.message.DbException;
import org.h2.result.SortOrder; import org.h2.result.SortOrder;
import org.h2.table.ColumnResolver; import org.h2.table.ColumnResolver;
...@@ -25,7 +26,7 @@ import org.h2.value.ValueArray; ...@@ -25,7 +26,7 @@ import org.h2.value.ValueArray;
import org.h2.value.ValueInt; import org.h2.value.ValueInt;
/** /**
* A base class for aggregates. * A base class for aggregates and window functions.
*/ */
public abstract class AbstractAggregate extends Expression { public abstract class AbstractAggregate extends Expression {
...@@ -37,7 +38,7 @@ public abstract class AbstractAggregate extends Expression { ...@@ -37,7 +38,7 @@ public abstract class AbstractAggregate extends Expression {
protected Window over; protected Window over;
private SortOrder overOrderBySort; protected SortOrder overOrderBySort;
private int lastGroupRowId; private int lastGroupRowId;
...@@ -65,7 +66,11 @@ public abstract class AbstractAggregate extends Expression { ...@@ -65,7 +66,11 @@ public abstract class AbstractAggregate extends Expression {
* FILTER condition * FILTER condition
*/ */
public void setFilterCondition(Expression filterCondition) { public void setFilterCondition(Expression filterCondition) {
if (isAggregate()) {
this.filterCondition = filterCondition; this.filterCondition = filterCondition;
} else {
throw DbException.getUnsupportedException("Window function");
}
} }
/** /**
...@@ -78,6 +83,23 @@ public abstract class AbstractAggregate extends Expression { ...@@ -78,6 +83,23 @@ public abstract class AbstractAggregate extends Expression {
this.over = over; this.over = over;
} }
/**
* Checks whether this expression is an aggregate function.
*
* @return true if this is an aggregate function (including aggregates with
* OVER clause), false if this is a window function
*/
public abstract boolean isAggregate();
/**
* Returns the sort order for OVER clause.
*
* @return the sort order for OVER clause
*/
SortOrder getOverOrderBySort() {
return overOrderBySort;
}
@Override @Override
public void mapColumns(ColumnResolver resolver, int level) { public void mapColumns(ColumnResolver resolver, int level) {
if (filterCondition != null) { if (filterCondition != null) {
...@@ -271,6 +293,30 @@ public abstract class AbstractAggregate extends Expression { ...@@ -271,6 +293,30 @@ public abstract class AbstractAggregate extends Expression {
protected abstract Object createAggregateData(); protected abstract Object createAggregateData();
@Override
public boolean isEverything(ExpressionVisitor visitor) {
if (over == null) {
return true;
}
switch (visitor.getType()) {
case ExpressionVisitor.QUERY_COMPARABLE:
case ExpressionVisitor.OPTIMIZABLE_MIN_MAX_COUNT_ALL:
case ExpressionVisitor.DETERMINISTIC:
case ExpressionVisitor.INDEPENDENT:
return false;
case ExpressionVisitor.EVALUATABLE:
case ExpressionVisitor.READONLY:
case ExpressionVisitor.NOT_FROM_RESOLVER:
case ExpressionVisitor.GET_DEPENDENCIES:
case ExpressionVisitor.SET_MAX_DATA_MODIFICATION_ID:
case ExpressionVisitor.GET_COLUMNS1:
case ExpressionVisitor.GET_COLUMNS2:
return true;
default:
throw DbException.throwInternalError("type=" + visitor.getType());
}
}
@Override @Override
public Value getValue(Session session) { public Value getValue(Session session) {
SelectGroups groupData = select.getGroupDataIfCurrent(over != null); SelectGroups groupData = select.getGroupDataIfCurrent(over != null);
...@@ -322,6 +368,15 @@ public abstract class AbstractAggregate extends Expression { ...@@ -322,6 +368,15 @@ public abstract class AbstractAggregate extends Expression {
return result; return result;
} }
/***
* Returns aggregated value.
*
* @param session
* the session
* @param aggregateData
* the aggregate data
* @return aggregated value.
*/
protected abstract Value getAggregatedValue(Session session, Object aggregateData); protected abstract Value getAggregatedValue(Session session, Object aggregateData);
private void updateOrderedAggregate(Session session, SelectGroups groupData, int groupRowId, private void updateOrderedAggregate(Session session, SelectGroups groupData, int groupRowId,
...@@ -348,15 +403,31 @@ public abstract class AbstractAggregate extends Expression { ...@@ -348,15 +403,31 @@ public abstract class AbstractAggregate extends Expression {
@SuppressWarnings("unchecked") @SuppressWarnings("unchecked")
ArrayList<Value[]> orderedData = (ArrayList<Value[]>) data; ArrayList<Value[]> orderedData = (ArrayList<Value[]>) data;
int ne = getNumExpressions(); int ne = getNumExpressions();
int last = ne + over.getOrderBy().size(); int rowIdColumn = ne + over.getOrderBy().size();
Collections.sort(orderedData, overOrderBySort); Collections.sort(orderedData, overOrderBySort);
getOrderedResultLoop(session, result, orderedData, rowIdColumn);
partition.setOrderedResult(result);
}
return result.get(groupData.getCurrentGroupRowId());
}
/**
* @param session
* the session
* @param result
* the map to append result to
* @param ordered
* ordered data
* @param rowIdColumn
* the index of row id value
*/
protected void getOrderedResultLoop(Session session, HashMap<Integer, Value> result, ArrayList<Value[]> ordered,
int rowIdColumn) {
Object aggregateData = createAggregateData(); Object aggregateData = createAggregateData();
for (Value[] row : orderedData) { for (Value[] row : ordered) {
updateFromExpressions(session, aggregateData, row); updateFromExpressions(session, aggregateData, row);
result.put(row[last].getInt(), getAggregatedValue(session, aggregateData)); result.put(row[rowIdColumn].getInt(), getAggregatedValue(session, aggregateData));
}
} }
return result.get(groupData.getCurrentGroupRowId());
} }
protected StringBuilder appendTailConditions(StringBuilder builder) { protected StringBuilder appendTailConditions(StringBuilder builder) {
......
...@@ -251,6 +251,11 @@ public class Aggregate extends AbstractAggregate { ...@@ -251,6 +251,11 @@ public class Aggregate extends AbstractAggregate {
return AGGREGATES.get(name); return AGGREGATES.get(name);
} }
@Override
public boolean isAggregate() {
return true;
}
/** /**
* Set the order for ARRAY_AGG() or GROUP_CONCAT() aggregate. * Set the order for ARRAY_AGG() or GROUP_CONCAT() aggregate.
* *
...@@ -741,6 +746,9 @@ public class Aggregate extends AbstractAggregate { ...@@ -741,6 +746,9 @@ public class Aggregate extends AbstractAggregate {
@Override @Override
public boolean isEverything(ExpressionVisitor visitor) { public boolean isEverything(ExpressionVisitor visitor) {
if (!super.isEverything(visitor)) {
return false;
}
if (filterCondition != null && !filterCondition.isEverything(visitor)) { if (filterCondition != null && !filterCondition.isEverything(visitor)) {
return false; return false;
} }
......
...@@ -40,6 +40,11 @@ public class JavaAggregate extends AbstractAggregate { ...@@ -40,6 +40,11 @@ public class JavaAggregate extends AbstractAggregate {
this.args = args; this.args = args;
} }
@Override
public boolean isAggregate() {
return true;
}
@Override @Override
public int getCost() { public int getCost() {
int cost = 5; int cost = 5;
...@@ -86,6 +91,9 @@ public class JavaAggregate extends AbstractAggregate { ...@@ -86,6 +91,9 @@ public class JavaAggregate extends AbstractAggregate {
@Override @Override
public boolean isEverything(ExpressionVisitor visitor) { public boolean isEverything(ExpressionVisitor visitor) {
if (!super.isEverything(visitor)) {
return false;
}
switch (visitor.getType()) { switch (visitor.getType()) {
case ExpressionVisitor.DETERMINISTIC: case ExpressionVisitor.DETERMINISTIC:
// TODO optimization: some functions are deterministic, but we don't // TODO optimization: some functions are deterministic, but we don't
......
...@@ -33,7 +33,7 @@ public final class Window { ...@@ -33,7 +33,7 @@ public final class Window {
* ORDER BY clause, or null * ORDER BY clause, or null
*/ */
static void appendOrderBy(StringBuilder builder, ArrayList<SelectOrderBy> orderBy) { static void appendOrderBy(StringBuilder builder, ArrayList<SelectOrderBy> orderBy) {
if (orderBy != null) { if (orderBy != null && !orderBy.isEmpty()) {
builder.append(" ORDER BY "); builder.append(" ORDER BY ");
for (int i = 0; i < orderBy.size(); i++) { for (int i = 0; i < orderBy.size(); i++) {
SelectOrderBy o = orderBy.get(i); SelectOrderBy o = orderBy.get(i);
......
/*
* 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;
import java.util.ArrayList;
import java.util.HashMap;
import org.h2.command.dml.Select;
import org.h2.engine.Session;
import org.h2.message.DbException;
import org.h2.value.Value;
import org.h2.value.ValueDouble;
import org.h2.value.ValueInt;
/**
* A window function.
*/
public class WindowFunction extends AbstractAggregate {
/**
* 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,
;
/**
* 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 WindowFunctionType.ROW_NUMBER;
case "RANK":
return RANK;
case "DENSE_RANK":
return WindowFunctionType.DENSE_RANK;
case "PERCENT_RANK":
return WindowFunctionType.PERCENT_RANK;
case "CUME_DIST":
return WindowFunctionType.CUME_DIST;
default:
return null;
}
}
}
private final WindowFunctionType type;
/**
* Creates new instance of a window function.
*
* @param type
* the type
* @param select
* the select statement
*/
public WindowFunction(WindowFunctionType type, Select select) {
super(select, false);
this.type = type;
}
@Override
public boolean isAggregate() {
return false;
}
@Override
protected void updateAggregate(Session session, Object aggregateData) {
throw DbException.getUnsupportedException("Window function");
}
@Override
protected void updateGroupAggregates(Session session, int stage) {
// Nothing to do
}
@Override
protected int getNumExpressions() {
return 0;
}
@Override
protected void rememberExpressions(Session session, Value[] array) {
// Nothing to do
}
@Override
protected void updateFromExpressions(Session session, Object aggregateData, Value[] array) {
throw DbException.getUnsupportedException("Window function");
}
@Override
protected Object createAggregateData() {
throw DbException.getUnsupportedException("Window function");
}
@Override
protected void getOrderedResultLoop(Session session, HashMap<Integer, Value> result, ArrayList<Value[]> ordered,
int rowIdColumn) {
if (type == WindowFunctionType.CUME_DIST) {
getCumeDist(session, result, ordered, rowIdColumn);
return;
}
int size = ordered.size();
int number = 0;
for (int i = 0; i < size; i++) {
Value[] row = ordered.get(i);
int rowId = row[rowIdColumn].getInt();
Value v;
switch (type) {
case ROW_NUMBER:
v = ValueInt.get(i + 1);
break;
case RANK:
case DENSE_RANK:
case PERCENT_RANK: {
if (i == 0) {
number = 1;
} else {
if (getOverOrderBySort().compare(ordered.get(i - 1), row) != 0) {
switch (type) {
case RANK:
case PERCENT_RANK:
number = i + 1;
break;
default: // DENSE_RANK
number++;
}
}
}
if (type == WindowFunctionType.PERCENT_RANK) {
int nm = number - 1;
v = nm == 0 ? ValueDouble.ZERO : ValueDouble.get((double) nm / (size - 1));
} else {
v = ValueInt.get(number);
}
break;
}
case CUME_DIST: {
int nm = number;
v = ValueDouble.get((double) nm / size);
break;
}
default:
throw DbException.throwInternalError("type=" + type);
}
result.put(rowId, v);
}
}
private void getCumeDist(Session session, HashMap<Integer, Value> result, ArrayList<Value[]> orderedData,
int last) {
int size = orderedData.size();
for (int start = 0; start < size;) {
Value[] array = orderedData.get(start);
int end = start + 1;
while (end < size && overOrderBySort.compare(array, orderedData.get(end)) == 0) {
end++;
}
ValueDouble v = ValueDouble.get((double) end / size);
for (int i = start; i < end; i++) {
int rowId = orderedData.get(i)[last].getInt();
result.put(rowId, v);
}
start = end;
}
}
@Override
protected Value getAggregatedValue(Session session, Object aggregateData) {
throw DbException.getUnsupportedException("Window function");
}
@Override
public int getType() {
switch (type) {
case ROW_NUMBER:
case RANK:
case DENSE_RANK:
return Value.INT;
case PERCENT_RANK:
case CUME_DIST:
return Value.DOUBLE;
default:
throw DbException.throwInternalError("type=" + type);
}
}
@Override
public int getScale() {
return 0;
}
@Override
public long getPrecision() {
switch (type) {
case ROW_NUMBER:
case RANK:
case DENSE_RANK:
return ValueInt.PRECISION;
case PERCENT_RANK:
case CUME_DIST:
return ValueDouble.PRECISION;
default:
throw DbException.throwInternalError("type=" + type);
}
}
@Override
public int getDisplaySize() {
switch (type) {
case ROW_NUMBER:
case RANK:
case DENSE_RANK:
return ValueInt.DISPLAY_SIZE;
case PERCENT_RANK:
case CUME_DIST:
return ValueDouble.DISPLAY_SIZE;
default:
throw DbException.throwInternalError("type=" + type);
}
}
@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;
default:
throw DbException.throwInternalError("type=" + type);
}
StringBuilder builder = new StringBuilder().append(text).append("()");
return appendTailConditions(builder).toString();
}
@Override
public int getCost() {
int cost = 1;
return cost;
}
}
...@@ -9,6 +9,6 @@ Initial Developer: H2 Group ...@@ -9,6 +9,6 @@ Initial Developer: H2 Group
Javadoc package documentation Javadoc package documentation
</title></head><body style="font: 9pt/130% Tahoma, Arial, Helvetica, sans-serif; font-weight: normal;"><p> </title></head><body style="font: 9pt/130% Tahoma, Arial, Helvetica, sans-serif; font-weight: normal;"><p>
Aggregate functions. Aggregate and window functions.
</p></body></html> </p></body></html>
\ No newline at end of file
...@@ -121,7 +121,15 @@ public class TestView extends TestDb { ...@@ -121,7 +121,15 @@ public class TestView extends TestDb {
stat.execute("drop table test if exists"); stat.execute("drop table test if exists");
stat.execute("create table test(id int primary key, name varchar(1))"); stat.execute("create table test(id int primary key, name varchar(1))");
stat.execute("insert into test(id, name) values(1, 'b'), (3, 'a')"); stat.execute("insert into test(id, name) values(1, 'b'), (3, 'a')");
ResultSet rs = stat.executeQuery( ResultSet rs;
rs = stat.executeQuery(
"select nr from (select rownum() as nr, " +
"a.id as id from (select id from test order by name) as a) as b " +
"where b.id = 1;");
assertTrue(rs.next());
assertEquals(2, rs.getInt(1));
assertFalse(rs.next());
rs = stat.executeQuery(
"select nr from (select row_number() over() as nr, " + "select nr from (select row_number() over() as nr, " +
"a.id as id from (select id from test order by name) as a) as b " + "a.id as id from (select id from test order by name) as a) as b " +
"where b.id = 1;"); "where b.id = 1;");
......
...@@ -136,9 +136,9 @@ public class TestScript extends TestDb { ...@@ -136,9 +136,9 @@ public class TestScript extends TestDb {
for (String s : new String[] { "help" }) { for (String s : new String[] { "help" }) {
testScript("other/" + s + ".sql"); testScript("other/" + s + ".sql");
} }
for (String s : new String[] { "avg", "bit-and", "bit-or", "count", "envelope", for (String s : new String[] { "array-agg", "avg", "bit-and", "bit-or", "count", "envelope",
"group-concat", "max", "median", "min", "mode", "selectivity", "stddev-pop", "group-concat", "max", "median", "min", "mode", "selectivity", "stddev-pop",
"stddev-samp", "sum", "var-pop", "var-samp", "array-agg" }) { "stddev-samp", "sum", "var-pop", "var-samp" }) {
testScript("functions/aggregate/" + s + ".sql"); testScript("functions/aggregate/" + s + ".sql");
} }
for (String s : new String[] { "abs", "acos", "asin", "atan", "atan2", for (String s : new String[] { "abs", "acos", "asin", "atan", "atan2",
...@@ -179,6 +179,9 @@ public class TestScript extends TestDb { ...@@ -179,6 +179,9 @@ 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" }) {
testScript("functions/window/" + s + ".sql");
}
deleteDb("script"); deleteDb("script");
System.out.flush(); System.out.flush();
......
...@@ -47,3 +47,25 @@ select count(v), count(v) filter (where v >= 4) from test; ...@@ -47,3 +47,25 @@ select count(v), count(v) filter (where v >= 4) from test;
drop table test; drop table test;
> ok > ok
CREATE TABLE TEST (ID INT PRIMARY KEY, NAME VARCHAR);
> ok
INSERT INTO TEST VALUES (1, 'b'), (3, 'a');
> update count: 2
SELECT COUNT(ID) OVER (ORDER BY NAME) AS NR,
A.ID AS ID FROM (SELECT ID, NAME FROM TEST ORDER BY NAME) AS A;
> NR ID
> -- --
> 1 3
> 2 1
> rows (ordered): 2
SELECT NR FROM (SELECT COUNT(ID) OVER (ORDER BY NAME) AS NR,
A.ID AS ID FROM (SELECT ID, NAME FROM TEST ORDER BY NAME) AS A)
AS B WHERE B.ID = 1;
>> 2
DROP TABLE TEST;
> ok
...@@ -7,7 +7,7 @@ ...@@ -7,7 +7,7 @@
create table test as (select char(x) as str from system_range(48,90)); create table test as (select char(x) as str from system_range(48,90));
> ok > ok
select row_number() over () as rnum, str from test where str = 'A'; select rownum() as rnum, str from test where str = 'A';
> RNUM STR > RNUM STR
> ---- --- > ---- ---
> 1 A > 1 A
......
-- 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, CATEGORY INT, VALUE INT);
> ok
INSERT INTO TEST VALUES
(1, 1, 11),
(2, 1, 12),
(3, 1, 13),
(4, 2, 21),
(5, 2, 22),
(6, 3, 31),
(7, 3, 32),
(8, 3, 33),
(9, 4, 41);
> update count: 9
SELECT *,
ROW_NUMBER() OVER () RN,
RANK() OVER () RK,
DENSE_RANK() OVER () DR,
ROUND(PERCENT_RANK() OVER (), 2) PR,
ROUND(CUME_DIST() OVER (), 2) CD,
ROW_NUMBER() OVER (ORDER BY ID) RNO,
RANK() OVER (ORDER BY ID) RKO,
DENSE_RANK() OVER (ORDER BY ID) DRO,
ROUND(PERCENT_RANK() OVER (ORDER BY ID), 2) PRO,
ROUND(CUME_DIST() OVER (ORDER BY ID), 2) CDO
FROM TEST;
> ID CATEGORY VALUE RN RK DR PR CD RNO RKO DRO PRO CDO
> -- -------- ----- -- -- -- --- --- --- --- --- ---- ----
> 1 1 11 1 1 1 0.0 1.0 1 1 1 0.0 0.11
> 2 1 12 2 1 1 0.0 1.0 2 2 2 0.13 0.22
> 3 1 13 3 1 1 0.0 1.0 3 3 3 0.25 0.33
> 4 2 21 4 1 1 0.0 1.0 4 4 4 0.38 0.44
> 5 2 22 5 1 1 0.0 1.0 5 5 5 0.5 0.56
> 6 3 31 6 1 1 0.0 1.0 6 6 6 0.63 0.67
> 7 3 32 7 1 1 0.0 1.0 7 7 7 0.75 0.78
> 8 3 33 8 1 1 0.0 1.0 8 8 8 0.88 0.89
> 9 4 41 9 1 1 0.0 1.0 9 9 9 1.0 1.0
> rows (ordered): 9
SELECT *,
ROW_NUMBER() OVER (ORDER BY CATEGORY) RN,
RANK() OVER (ORDER BY CATEGORY) RK,
DENSE_RANK() OVER (ORDER BY CATEGORY) DR,
ROUND(PERCENT_RANK() OVER (ORDER BY CATEGORY), 2) PR,
ROUND(CUME_DIST() OVER (ORDER BY CATEGORY), 2) CD
FROM TEST;
> ID CATEGORY VALUE RN RK DR PR CD
> -- -------- ----- -- -- -- ---- ----
> 1 1 11 1 1 1 0.0 0.33
> 2 1 12 2 1 1 0.0 0.33
> 3 1 13 3 1 1 0.0 0.33
> 4 2 21 4 4 2 0.38 0.56
> 5 2 22 5 4 2 0.38 0.56
> 6 3 31 6 6 3 0.63 0.89
> 7 3 32 7 6 3 0.63 0.89
> 8 3 33 8 6 3 0.63 0.89
> 9 4 41 9 9 4 1.0 1.0
> rows (ordered): 9
SELECT *,
ROW_NUMBER() OVER (PARTITION BY CATEGORY ORDER BY ID) RN,
RANK() OVER (PARTITION BY CATEGORY ORDER BY ID) RK,
DENSE_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID) DR,
ROUND(PERCENT_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), 2) PR,
ROUND(CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), 2) CD
FROM TEST;
> ID CATEGORY VALUE RN RK DR PR CD
> -- -------- ----- -- -- -- --- ----
> 1 1 11 1 1 1 0.0 0.33
> 2 1 12 2 2 2 0.5 0.67
> 3 1 13 3 3 3 1.0 1.0
> 4 2 21 1 1 1 0.0 0.5
> 5 2 22 2 2 2 1.0 1.0
> 6 3 31 1 1 1 0.0 0.33
> 7 3 32 2 2 2 0.5 0.67
> 8 3 33 3 3 3 1.0 1.0
> 9 4 41 1 1 1 0.0 1.0
> rows (ordered): 9
SELECT
ROW_NUMBER() OVER () RN,
RANK() OVER () RK,
DENSE_RANK() OVER () DR,
PERCENT_RANK() OVER () PR,
CUME_DIST() OVER () CD
FROM TEST GROUP BY CATEGORY;
> RN RK DR PR CD
> -- -- -- --- ---
> 1 1 1 0.0 1.0
> 2 1 1 0.0 1.0
> 3 1 1 0.0 1.0
> 4 1 1 0.0 1.0
> rows: 4
DROP TABLE TEST;
> ok
CREATE TABLE TEST (ID INT PRIMARY KEY, TYPE VARCHAR, CNT INT);
> ok
INSERT INTO TEST VALUES
(1, 'a', 1),
(2, 'b', 2),
(3, 'c', 4),
(4, 'b', 8);
> update count: 4
SELECT ROW_NUMBER() OVER(ORDER /**/ BY TYPE) RN, TYPE, SUM(CNT) SUM FROM TEST GROUP BY TYPE;
> RN TYPE SUM
> -- ---- ---
> 1 a 1
> 2 b 10
> 3 c 4
> rows: 3
DROP TABLE TEST;
> ok
...@@ -281,21 +281,21 @@ create table test(id int primary key, name varchar(255), row_number int); ...@@ -281,21 +281,21 @@ create table test(id int primary key, name varchar(255), row_number int);
insert into test values(1, 'hello', 10), (2, 'world', 20); insert into test values(1, 'hello', 10), (2, 'world', 20);
> update count: 2 > update count: 2
select row_number() over(), id, name from test order by id; select rownum(), id, name from test order by id;
> ROWNUM() ID NAME > ROWNUM() ID NAME
> -------- -- ----- > -------- -- -----
> 1 1 hello > 1 1 hello
> 2 2 world > 2 2 world
> rows (ordered): 2 > rows (ordered): 2
select row_number() over(), id, name from test order by name; select rownum(), id, name from test order by name;
> ROWNUM() ID NAME > ROWNUM() ID NAME
> -------- -- ----- > -------- -- -----
> 1 1 hello > 1 1 hello
> 2 2 world > 2 2 world
> rows (ordered): 2 > rows (ordered): 2
select row_number() over(), id, name from test order by name desc; select rownum(), id, name from test order by name desc;
> ROWNUM() ID NAME > ROWNUM() ID NAME
> -------- -- ----- > -------- -- -----
> 2 2 world > 2 2 world
......
...@@ -90,6 +90,8 @@ public class GenerateDoc { ...@@ -90,6 +90,8 @@ public class GenerateDoc {
help + "= 'Functions (Time and Date)' ORDER BY ID", true, false); help + "= 'Functions (Time and Date)' ORDER BY ID", true, false);
map("functionsSystem", map("functionsSystem",
help + "= 'Functions (System)' ORDER BY ID", true, false); help + "= 'Functions (System)' ORDER BY ID", true, false);
map("functionsWindow",
help + "= 'Functions (Window)' ORDER BY ID", true, false);
map("dataTypes", map("dataTypes",
help + "LIKE 'Data Types%' ORDER BY SECTION, ID", true, true); help + "LIKE 'Data Types%' ORDER BY SECTION, ID", true, true);
map("intervalDataTypes", map("intervalDataTypes",
......
...@@ -796,3 +796,4 @@ interior envelopes multilinestring multipoint packed exterior normalization awkw ...@@ -796,3 +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
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论