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

Merge pull request #1711 from katzyn/qualify

Add QUALIFY clause to SELECT command
......@@ -6,10 +6,12 @@
SELECT [ TOP term [ PERCENT ] [ WITH TIES ] ]
[ DISTINCT [ ON ( expression [,...] ) ] | ALL ]
selectExpression [,...]
FROM tableExpression [,...] [ WHERE expression ]
[ FROM tableExpression [,...] ]
[ WHERE expression ]
[ GROUP BY expression [,...] ] [ HAVING expression ]
[ QUALIFY expression ]
[ WINDOW { { windowName AS windowSpecification } [,...] } ]
[ { UNION [ ALL ] | MINUS | EXCEPT | INTERSECT } select ]
[ { UNION [ ALL ] | EXCEPT | MINUS | INTERSECT } select ]
[ ORDER BY order [,...] ]
[ LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] ]
[ [ OFFSET expression { ROW | ROWS } ]
......@@ -18,26 +20,35 @@ FROM tableExpression [,...] [ WHERE expression ]
[ FOR UPDATE ]
","
Selects data from a table or multiple tables.
WHERE filters rows before other operations.
GROUP BY groups the result by the given expression(s).
HAVING filters rows after grouping.
If GROUP BY clause is not specified, but non-window aggregate functions are used or HAVING is specified
all rows are grouped together.
Aggregate functions are evaluated, SAMPLE_SIZE limits the number of rows read.
HAVING filters rows after grouping and evaluation of aggregate functions.
Window functions are evaluated.
QUALIFY filters rows after evaluation of window functions.
DISTINCT removes duplicates.
UNION, EXCEPT (MINUS), and INTERSECT combine the result of this query with the results of another query.
Multiple set operators (UNION, INTERSECT, MINUS, EXCEPT) are evaluated from left to right.
For compatibility with other databases and future versions of H2 please use parentheses.
ORDER BY sorts the result by the given column(s) or expression(s).
UNION combines the result of this query with the results of another query.
Number of rows in output can be limited either with standard OFFSET / FETCH,
with non-standard LIMIT / OFFSET, or with non-standard TOP clauses.
Different clauses cannot be used together.
OFFSET specifies how many rows to skip.
Please note that queries with high offset values can be slow.
FETCH FIRST/NEXT, LIMIT or TOP limits the number of rows returned by the query (no limit if null or smaller than zero).
If PERCENT is specified number of rows is specified as a percent of the total number of rows
and should be an integer value between 0 and 100 inclusive.
WITH TIES can be used only together with ORDER BY and means that all additional rows that have the same sorting position
as the last row will be also returned.
OFFSET specifies how many rows to skip.
Please note that queries with high offset values can be slow.
SAMPLE_SIZE limits the number of rows read for aggregate queries.
Multiple set operators (UNION, INTERSECT, MINUS, EXCEPT) are evaluated
from left to right. For compatibility with other databases and future versions
of H2 please use parentheses.
If FOR UPDATE is specified, the tables or rows are locked for writing.
This clause is not allowed in DISTINCT queries and in queries with non-window aggregates, GROUP BY, or HAVING clauses.
......@@ -246,7 +257,7 @@ Selects data from a table.
This command is an equivalent to SELECT * FROM tableName.
FROM, WHERE, GROUP BY, HAVING, and WINDOW clauses from the SELECT command are not allowed.
FROM, WHERE, GROUP BY, HAVING, QUALIFY, and WINDOW clauses from the SELECT command are not allowed.
","
TABLE TEST;
TABLE TEST ORDER BY ID FETCH FIRST ROW ONLY;
......
......@@ -480,9 +480,9 @@ CURRENT_TIME, CURRENT_TIMESTAMP, CURRENT_USER, DISTINCT, EXCEPT,
EXISTS, FALSE, FETCH, FOR, FOREIGN, FROM, FULL, GROUP, HAVING,
IF, INNER, INTERSECT, INTERSECTS, INTERVAL, IS, JOIN, LIKE,
LIMIT, LOCALTIME, LOCALTIMESTAMP, MINUS, NATURAL, NOT, NULL,
OFFSET, ON, ORDER, PRIMARY, ROW, ROWNUM, SELECT, SYSDATE,
SYSTIME, SYSTIMESTAMP, TABLE, TODAY, TOP, TRUE, UNION, UNIQUE,
VALUES, WHERE, WINDOW, WITH
OFFSET, ON, ORDER, PRIMARY, QUALIFY, ROW, ROWNUM, SELECT,
SYSDATE, SYSTIME, SYSTIMESTAMP, TABLE, TODAY, TOP, TRUE, UNION,
UNIQUE, VALUES, WHERE, WINDOW, WITH
</code>
</p><p>
Certain words of this list are keywords because they are functions that can be used without '()',
......
......@@ -21,6 +21,8 @@ Change Log
<h2>Next Version (unreleased)</h2>
<ul>
<li>PR #1711: Add QUALIFY clause to SELECT command
</li>
<li>Issue #1708: CREATE TABLE AS doesn't support column lists without data types
</li>
<li>PR #1707: Fix sort order and ENUM data type in external results
......
......@@ -49,6 +49,7 @@ import static org.h2.util.ParserUtil.OFFSET;
import static org.h2.util.ParserUtil.ON;
import static org.h2.util.ParserUtil.ORDER;
import static org.h2.util.ParserUtil.PRIMARY;
import static org.h2.util.ParserUtil.QUALIFY;
import static org.h2.util.ParserUtil.ROW;
import static org.h2.util.ParserUtil.ROWNUM;
import static org.h2.util.ParserUtil.SELECT;
......@@ -507,6 +508,8 @@ public class Parser {
"ORDER",
// PRIMARY
"PRIMARY",
// QUALIFY
"QUALIFY",
// ROW
"ROW",
// ROWNUM
......@@ -2748,6 +2751,11 @@ public class Parser {
Expression condition = readExpression();
command.setHaving(condition);
}
if (readIf(QUALIFY)) {
command.setWindowQuery();
Expression condition = readExpression();
command.setQualify(condition);
}
if (readIf(WINDOW)) {
do {
int index = parseIndex;
......
......@@ -77,9 +77,21 @@ public class Select extends Query {
private final ArrayList<TableFilter> filters = Utils.newSmallArrayList();
private final ArrayList<TableFilter> topFilters = Utils.newSmallArrayList();
private Expression having;
/**
* WHERE condition.
*/
private Expression condition;
/**
* HAVING condition.
*/
private Expression having;
/**
* QUALIFY condition.
*/
private Expression qualify;
/**
* The visible columns (the ones required in the result).
*/
......@@ -112,6 +124,8 @@ public class Select extends Query {
private int havingIndex;
private int qualifyIndex;
private int[] groupByCopies;
/**
......@@ -413,7 +427,7 @@ public class Select extends Query {
initGroupData(columnCount);
try {
gatherGroup(columnCount, DataAnalysisOperation.STAGE_WINDOW);
processGroupResult(columnCount, result, offset, quickOffset);
processGroupResult(columnCount, result, offset, quickOffset, false);
} finally {
groupData.reset();
}
......@@ -433,7 +447,7 @@ public class Select extends Query {
}
}
groupData.done();
processGroupResult(columnCount, result, offset, quickOffset);
processGroupResult(columnCount, result, offset, quickOffset, /* Having was performed earlier */ false);
} finally {
isGroupWindowStage2 = false;
}
......@@ -446,7 +460,7 @@ public class Select extends Query {
initGroupData(columnCount);
try {
gatherGroup(columnCount, DataAnalysisOperation.STAGE_GROUP);
processGroupResult(columnCount, result, offset, quickOffset);
processGroupResult(columnCount, result, offset, quickOffset, true);
} finally {
groupData.reset();
}
......@@ -498,7 +512,8 @@ public class Select extends Query {
}
}
private void processGroupResult(int columnCount, LocalResult result, long offset, boolean quickOffset) {
private void processGroupResult(int columnCount, LocalResult result, long offset, boolean quickOffset,
boolean withHaving) {
for (ValueRow currentGroupsKey; (currentGroupsKey = groupData.next()) != null;) {
Value[] keyValues = currentGroupsKey.getList();
Value[] row = new Value[columnCount];
......@@ -519,7 +534,10 @@ public class Select extends Query {
Expression expr = expressions.get(j);
row[j] = expr.getValue(session);
}
if (isHavingNullOrFalse(row)) {
if (withHaving && isHavingNullOrFalse(row)) {
continue;
}
if (qualifyIndex >= 0 && !row[qualifyIndex].getBoolean()) {
continue;
}
if (quickOffset && offset > 0) {
......@@ -1063,6 +1081,13 @@ public class Select extends Query {
} else {
havingIndex = -1;
}
if (qualify != null) {
expressions.add(qualify);
qualifyIndex = expressions.size() - 1;
qualify = null;
} else {
qualifyIndex = -1;
}
if (withTies && !hasOrder()) {
throw DbException.get(ErrorCode.WITH_TIES_WITHOUT_ORDER_BY);
......@@ -1130,12 +1155,17 @@ public class Select extends Query {
for (TableFilter f : filters) {
mapColumns(f, 0);
}
if (havingIndex >= 0) {
Expression expr = expressions.get(havingIndex);
mapCondition(havingIndex);
mapCondition(qualifyIndex);
checkInit = true;
}
private void mapCondition(int index) {
if (index >= 0) {
Expression expr = expressions.get(index);
SelectListColumnResolver res = new SelectListColumnResolver(this);
expr.mapColumns(res, 0, Expression.MAP_INITIAL);
}
checkInit = true;
}
private int mergeGroupByExpressions(Database db, int index, ArrayList<String> expressionSQL, boolean scanPrevious)
......@@ -1221,14 +1251,9 @@ public class Select extends Query {
}
}
}
if (isGroupQuery && groupIndex == null &&
havingIndex < 0 && filters.size() == 1) {
if (condition == null) {
Table t = filters.get(0).getTable();
ExpressionVisitor optimizable = ExpressionVisitor.
getOptimizableVisitor(t);
isQuickAggregateQuery = isEverything(optimizable);
}
if (isGroupQuery && groupIndex == null && havingIndex < 0 && qualifyIndex < 0 && condition == null
&& filters.size() == 1) {
isQuickAggregateQuery = isEverything(ExpressionVisitor.getOptimizableVisitor(filters.get(0).getTable()));
}
cost = preparePlan(session.isParsingCreateView());
if (distinct && session.getDatabase().getSettings().optimizeDistinct &&
......@@ -1504,18 +1529,8 @@ public class Select extends Query {
g.getUnenclosedSQL(buff.builder());
}
}
if (having != null) {
// could be set in addGlobalCondition
// in this case the query is not run directly, just getPlanSQL is
// called
Expression h = having;
buff.append("\nHAVING ");
h.getUnenclosedSQL(buff.builder());
} else if (havingIndex >= 0) {
Expression h = exprList[havingIndex];
buff.append("\nHAVING ");
h.getUnenclosedSQL(buff.builder());
}
getFilterSQL(buff, "\nHAVING ", exprList, having, havingIndex);
getFilterSQL(buff, "\nQUALIFY ", exprList, qualify, qualifyIndex);
if (sort != null) {
buff.append("\nORDER BY ").append(
sort.getSQL(exprList, visibleColumnCount));
......@@ -1554,6 +1569,17 @@ public class Select extends Query {
return buff.toString();
}
private static void getFilterSQL(StatementBuilder buff, String sql, Expression[] exprList, Expression condition,
int conditionIndex) {
if (condition != null) {
buff.append(sql);
condition.getUnenclosedSQL(buff.builder());
} else if (conditionIndex >= 0) {
buff.append(sql);
exprList[conditionIndex].getUnenclosedSQL(buff.builder());
}
}
public void setHaving(Expression having) {
this.having = having;
}
......@@ -1562,6 +1588,14 @@ public class Select extends Query {
return having;
}
public void setQualify(Expression qualify) {
this.qualify = qualify;
}
public Expression getQualify() {
return qualify;
}
@Override
public int getColumnCount() {
return visibleColumnCount;
......@@ -1696,6 +1730,9 @@ public class Select extends Query {
if (having != null) {
having.updateAggregate(s, stage);
}
if (qualify != null) {
qualify.updateAggregate(s, stage);
}
}
@Override
......@@ -1747,6 +1784,9 @@ public class Select extends Query {
if (having != null && !having.isEverything(v2)) {
return false;
}
if (qualify != null && !qualify.isEverything(v2)) {
return false;
}
return true;
}
......
......@@ -1542,7 +1542,7 @@ public class JdbcDatabaseMetaData extends TraceObject implements
* table/column/index name, in addition to the SQL-2003 keywords. The list
* returned is:
* <pre>
* INTERSECTS,LIMIT,MINUS,OFFSET,ROWNUM,SYSDATE,SYSTIME,SYSTIMESTAMP,TODAY,TOP
* INTERSECTS,LIMIT,MINUS,OFFSET,QUALIFY,ROWNUM,SYSDATE,SYSTIME,SYSTIMESTAMP,TODAY,TOP
* </pre>
* The complete list of keywords (including SQL-2003 keywords) is:
* <pre>
......@@ -1551,9 +1551,9 @@ public class JdbcDatabaseMetaData extends TraceObject implements
* EXISTS, FALSE, FETCH, FOR, FOREIGN, FROM, FULL, GROUP, HAVING,
* IF, INNER, INTERSECT, INTERSECTS, INTERVAL, IS, JOIN, LIKE,
* LIMIT, LOCALTIME, LOCALTIMESTAMP, MINUS, NATURAL, NOT, NULL,
* OFFSET, ON, ORDER, PRIMARY, ROW, ROWNUM, SELECT, SYSDATE,
* SYSTIME, SYSTIMESTAMP, TABLE, TODAY, TOP, TRUE, UNION, UNIQUE,
* VALUES, WHERE, WINDOW, WITH
* OFFSET, ON, ORDER, PRIMARY, QUALIFY, ROW, ROWNUM, SELECT,
* SYSDATE, SYSTIME, SYSTIMESTAMP, TABLE, TODAY, TOP, TRUE, UNION,
* UNIQUE, VALUES, WHERE, WINDOW, WITH
* </pre>
*
* @return a list of additional the keywords
......@@ -1561,7 +1561,7 @@ public class JdbcDatabaseMetaData extends TraceObject implements
@Override
public String getSQLKeywords() {
debugCodeCall("getSQLKeywords");
return "IF,INTERSECTS,LIMIT,MINUS,OFFSET,ROWNUM,SYSDATE,SYSTIME,SYSTIMESTAMP,TODAY,TOP";
return "IF,INTERSECTS,LIMIT,MINUS,OFFSET,QUALIFY,ROWNUM,SYSDATE,SYSTIME,SYSTIMESTAMP,TODAY,TOP";
}
/**
......
......@@ -217,10 +217,15 @@ public class ParserUtil {
*/
public static final int PRIMARY = ORDER + 1;
/**
* The token "QUALIFY".
*/
public static final int QUALIFY = PRIMARY + 1;
/**
* The token "ROW".
*/
public static final int ROW = PRIMARY + 1;
public static final int ROW = QUALIFY + 1;
/**
* The token "ROWNUM".
......@@ -476,6 +481,11 @@ public class ParserUtil {
return PRIMARY;
}
return IDENTIFIER;
case 'Q':
if (eq("QUALIFY", s, ignoreCase, start, end)) {
return QUALIFY;
}
return IDENTIFIER;
case 'R':
if (eq("ROW", s, ignoreCase, start, end)) {
return ROW;
......
......@@ -463,7 +463,7 @@ public class TestMetaData extends TestDb {
assertEquals("schema", meta.getSchemaTerm());
assertEquals("\\", meta.getSearchStringEscape());
assertEquals("IF,INTERSECTS,LIMIT,MINUS,OFFSET,ROWNUM,SYSDATE,SYSTIME,SYSTIMESTAMP,TODAY,TOP",
assertEquals("IF,INTERSECTS,LIMIT,MINUS,OFFSET,QUALIFY,ROWNUM,SYSDATE,SYSTIME,SYSTIMESTAMP,TODAY,TOP",
meta.getSQLKeywords());
assertTrue(meta.getURL().startsWith("jdbc:h2:"));
......
......@@ -609,3 +609,19 @@ SELECT * FROM TEST WHERE (A, B) IN ((1000000000000, 2), (3, 4));
DROP TABLE TEST;
> ok
CREATE TABLE TEST(I) AS VALUES 1, 2, 3;
> ok
SELECT COUNT(*) C FROM TEST HAVING C < 1;
> C
> -
> rows: 0
SELECT COUNT(*) C FROM TEST QUALIFY C < 1;
> C
> -
> rows: 0
DROP TABLE TEST;
> ok
......@@ -168,6 +168,22 @@ SELECT ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME), NAME FROM
> [[4, 5, 6]] c
> rows: 3
SELECT ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME), NAME FROM TEST
WHERE ID <> 5
GROUP BY NAME HAVING ARRAY_AGG(ID ORDER BY ID)[1] > 1
QUALIFY ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME) <> ARRAY[ARRAY[3]];
> ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME) NAME
> ------------------------------------------------------------- ----
> [[4, 6]] c
> rows: 1
EXPLAIN
SELECT ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME), NAME FROM TEST
WHERE ID <> 5
GROUP BY NAME HAVING ARRAY_AGG(ID ORDER BY ID)[1] > 1
QUALIFY ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME) <> ARRAY[ARRAY[3]];
>> SELECT ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME), NAME FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */ WHERE ID <> 5 GROUP BY NAME HAVING ARRAY_GET(ARRAY_AGG(ID ORDER BY ID), 1) > 1 QUALIFY ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME) <> ARRAY [ARRAY [3]]
SELECT ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME), NAME FROM TEST
GROUP BY NAME ORDER BY NAME OFFSET 1 ROW;
> ARRAY_AGG(ARRAY_AGG(ID ORDER BY ID)) OVER (PARTITION BY NAME) NAME
......
......@@ -83,6 +83,33 @@ SELECT *,
> 9 4 41 1 1 1 0.0 1.0
> rows: 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 QUALIFY ROW_NUMBER() OVER (PARTITION BY CATEGORY ORDER BY ID) = 2;
> ID CATEGORY VALUE RN RK DR PR CD
> -- -------- ----- -- -- -- --- ----
> 2 1 12 2 2 2 0.5 0.67
> 5 2 22 2 2 2 1.0 1.0
> 7 3 32 2 2 2 0.5 0.67
> rows: 3
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 QUALIFY RN = 3;
> ID CATEGORY VALUE RN RK DR PR CD
> -- -------- ----- -- -- -- --- ---
> 3 1 13 3 3 3 1.0 1.0
> 8 3 33 3 3 3 1.0 1.0
> rows: 2
SELECT
ROW_NUMBER() OVER (ORDER BY CATEGORY) RN,
RANK() OVER (ORDER BY CATEGORY) RK,
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论