提交 f4591330 authored 作者: Evgenij Ryazanov's avatar Evgenij Ryazanov

Add support of PERCENT in FETCH and TOP clauses

上级 a00b17bd
...@@ -3,7 +3,7 @@ ...@@ -3,7 +3,7 @@
# Initial Developer: H2 Group # Initial Developer: H2 Group
"SECTION","TOPIC","SYNTAX","TEXT","EXAMPLE" "SECTION","TOPIC","SYNTAX","TEXT","EXAMPLE"
"Commands (DML)","SELECT"," "Commands (DML)","SELECT","
SELECT [ TOP term [ WITH TIES ] ] SELECT [ TOP term [ PERCENT ] [ WITH TIES ] ]
[ DISTINCT [ ON ( expression [,...] ) ] | ALL ] [ DISTINCT [ ON ( expression [,...] ) ] | ALL ]
selectExpression [,...] selectExpression [,...]
FROM tableExpression [,...] [ WHERE expression ] FROM tableExpression [,...] [ WHERE expression ]
...@@ -12,7 +12,7 @@ FROM tableExpression [,...] [ WHERE expression ] ...@@ -12,7 +12,7 @@ FROM tableExpression [,...] [ WHERE expression ]
[ ORDER BY order [,...] ] [ ORDER BY order [,...] ]
[ { LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] } [ { LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] }
| { [ OFFSET expression { ROW | ROWS } ] | { [ OFFSET expression { ROW | ROWS } ]
[ FETCH { FIRST | NEXT } expression { ROW | ROWS } [ FETCH { FIRST | NEXT } [ [ expression ] PERCENT ] { ROW | ROWS }
{ ONLY | WITH TIES } ] } ] { ONLY | WITH TIES } ] } ]
[ FOR UPDATE ] [ FOR UPDATE ]
"," ","
...@@ -22,7 +22,7 @@ HAVING filter rows after grouping. ...@@ -22,7 +22,7 @@ HAVING filter rows after grouping.
ORDER BY sorts the result by the given column(s) or expression(s). 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. UNION combines the result of this query with the results of another query.
LIMIT and FETCH FIRST/NEXT ROW(S) ONLY limits the number of rows returned by the query (no limit if null or smaller than zero). FETCH FIRST/NEXT, LIMIT or TOP limits the number of rows returned by the query (no limit if null or smaller than zero).
OFFSET specified how many rows to skip. OFFSET specified how many rows to skip.
Please note using high offset values should be avoided because it can cause performance problems. Please note using high offset values should be avoided because it can cause performance problems.
SAMPLE_SIZE limits the number of rows read for aggregate queries. SAMPLE_SIZE limits the number of rows read for aggregate queries.
......
...@@ -2372,11 +2372,14 @@ public class Parser { ...@@ -2372,11 +2372,14 @@ public class Parser {
if (!readIf("FIRST")) { if (!readIf("FIRST")) {
read("NEXT"); read("NEXT");
} }
if (readIf("ROW")) { if (readIf("ROW") || readIf("ROWS")) {
command.setLimit(ValueExpression.get(ValueInt.get(1))); command.setLimit(ValueExpression.get(ValueInt.get(1)));
} else { } else {
Expression limit = readExpression().optimize(session); Expression limit = readExpression().optimize(session);
command.setLimit(limit); command.setLimit(limit);
if (readIf("PERCENT")) {
command.setFetchPercent(true);
}
if (!readIf("ROW")) { if (!readIf("ROW")) {
read("ROWS"); read("ROWS");
} }
...@@ -2532,6 +2535,9 @@ public class Parser { ...@@ -2532,6 +2535,9 @@ public class Parser {
// SELECT TOP 1 (+?) AS A FROM TEST // SELECT TOP 1 (+?) AS A FROM TEST
Expression limit = readTerm().optimize(session); Expression limit = readTerm().optimize(session);
command.setLimit(limit); command.setLimit(limit);
if (readIf("PERCENT")) {
command.setFetchPercent(true);
}
if (readIf(WITH)) { if (readIf(WITH)) {
read("TIES"); read("TIES");
command.setWithTies(true); command.setWithTies(true);
......
...@@ -48,6 +48,11 @@ public abstract class Query extends Prepared { ...@@ -48,6 +48,11 @@ public abstract class Query extends Prepared {
*/ */
protected Expression limitExpr; protected Expression limitExpr;
/**
* Whether limit expression specifies percentage of rows.
*/
protected boolean fetchPercent;
/** /**
* Whether tied rows should be included in result too. * Whether tied rows should be included in result too.
*/ */
...@@ -650,8 +655,16 @@ public abstract class Query extends Prepared { ...@@ -650,8 +655,16 @@ public abstract class Query extends Prepared {
return limitExpr; return limitExpr;
} }
public void setFetchPercent(boolean fetchPercent) {
this.fetchPercent = fetchPercent;
}
public boolean isFetchPercent() {
return fetchPercent;
}
public void setWithTies(boolean withTies) { public void setWithTies(boolean withTies) {
this.withTies = true; this.withTies = withTies;
} }
public boolean isWithTies() { public boolean isWithTies() {
...@@ -699,12 +712,18 @@ public abstract class Query extends Prepared { ...@@ -699,12 +712,18 @@ public abstract class Query extends Prepared {
void appendLimitToSQL(StringBuilder buff) { void appendLimitToSQL(StringBuilder buff) {
if (limitExpr != null) { if (limitExpr != null) {
if (withTies) { if (fetchPercent || withTies) {
if (offsetExpr != null) { if (offsetExpr != null) {
buff.append("\nOFFSET ").append(StringUtils.unEnclose(offsetExpr.getSQL())).append(" ROWS"); buff.append("\nOFFSET ").append(StringUtils.unEnclose(offsetExpr.getSQL())).append(" ROWS");
} }
buff.append("\nFETCH NEXT ").append(StringUtils.unEnclose(limitExpr.getSQL())) buff.append("\nFETCH NEXT ").append(StringUtils.unEnclose(limitExpr.getSQL()));
.append(" ROWS WITH TIES"); if (fetchPercent) {
buff.append(" PERCENT");
}
buff.append(" ROWS");
if (withTies) {
buff.append(" WITH TIES");
}
} else { } else {
buff.append("\nLIMIT ").append(StringUtils.unEnclose(limitExpr.getSQL())); buff.append("\nLIMIT ").append(StringUtils.unEnclose(limitExpr.getSQL()));
if (offsetExpr != null) { if (offsetExpr != null) {
......
...@@ -724,6 +724,17 @@ public class Select extends Query { ...@@ -724,6 +724,17 @@ public class Select extends Query {
limitRows = Math.min(l, limitRows); limitRows = Math.min(l, limitRows);
} }
} }
boolean fetchPercent = this.fetchPercent;
if (fetchPercent) {
// Need to check it row, because negative limit has special treatment later
if (limitRows < 0 || limitRows > 100) {
throw DbException.getInvalidValueException("FETCH PERCENT", limitRows);
}
// 0 PERCENT means 0
if (limitRows == 0) {
fetchPercent = false;
}
}
long offset; long offset;
if (offsetExpr != null) { if (offsetExpr != null) {
offset = offsetExpr.getValue(session).getLong(); offset = offsetExpr.getValue(session).getLong();
...@@ -735,7 +746,7 @@ public class Select extends Query { ...@@ -735,7 +746,7 @@ public class Select extends Query {
} }
boolean lazy = session.isLazyQueryExecution() && boolean lazy = session.isLazyQueryExecution() &&
target == null && !isForUpdate && !isQuickAggregateQuery && target == null && !isForUpdate && !isQuickAggregateQuery &&
limitRows != 0 && !withTies && offset == 0 && isReadOnly(); limitRows != 0 && !fetchPercent && !withTies && offset == 0 && isReadOnly();
int columnCount = expressions.size(); int columnCount = expressions.size();
LocalResult result = null; LocalResult result = null;
if (!lazy && (target == null || if (!lazy && (target == null ||
...@@ -743,7 +754,7 @@ public class Select extends Query { ...@@ -743,7 +754,7 @@ public class Select extends Query {
result = createLocalResult(result); result = createLocalResult(result);
} }
// Do not add rows before OFFSET to result if possible // Do not add rows before OFFSET to result if possible
boolean quickOffset = true; boolean quickOffset = !fetchPercent;
if (sort != null && (!sortUsingIndex || isAnyDistinct() || withTies)) { if (sort != null && (!sortUsingIndex || isAnyDistinct() || withTies)) {
result = createLocalResult(result); result = createLocalResult(result);
result.setSortOrder(sort); result.setSortOrder(sort);
...@@ -791,6 +802,8 @@ public class Select extends Query { ...@@ -791,6 +802,8 @@ public class Select extends Query {
lazy &= to == null; lazy &= to == null;
LazyResult lazyResult = null; LazyResult lazyResult = null;
if (limitRows != 0) { if (limitRows != 0) {
// Cannot apply limit now if percent is specified
int limit = fetchPercent ? -1 : limitRows;
try { try {
if (isQuickAggregateQuery) { if (isQuickAggregateQuery) {
queryQuick(columnCount, to, quickOffset && offset > 0); queryQuick(columnCount, to, quickOffset && offset > 0);
...@@ -801,9 +814,9 @@ public class Select extends Query { ...@@ -801,9 +814,9 @@ public class Select extends Query {
queryGroup(columnCount, result, offset, quickOffset); queryGroup(columnCount, result, offset, quickOffset);
} }
} else if (isDistinctQuery) { } else if (isDistinctQuery) {
queryDistinct(to, offset, limitRows, withTies, quickOffset); queryDistinct(to, offset, limit, withTies, quickOffset);
} else { } else {
lazyResult = queryFlat(columnCount, to, offset, limitRows, withTies, quickOffset); lazyResult = queryFlat(columnCount, to, offset, limit, withTies, quickOffset);
} }
if (quickOffset) { if (quickOffset) {
offset = 0; offset = 0;
...@@ -833,6 +846,7 @@ public class Select extends Query { ...@@ -833,6 +846,7 @@ public class Select extends Query {
} }
if (limitRows >= 0) { if (limitRows >= 0) {
result.setLimit(limitRows); result.setLimit(limitRows);
result.setFetchPercent(fetchPercent);
result.setWithTies(withTies); result.setWithTies(withTies);
} }
if (result != null) { if (result != null) {
......
...@@ -193,7 +193,7 @@ public class SelectUnion extends Query { ...@@ -193,7 +193,7 @@ public class SelectUnion extends Query {
int columnCount = left.getColumnCount(); int columnCount = left.getColumnCount();
if (session.isLazyQueryExecution() && unionType == UnionType.UNION_ALL && !distinct && if (session.isLazyQueryExecution() && unionType == UnionType.UNION_ALL && !distinct &&
sort == null && !randomAccessResult && !isForUpdate && sort == null && !randomAccessResult && !isForUpdate &&
offsetExpr == null && isReadOnly()) { offsetExpr == null && !fetchPercent && !withTies && isReadOnly()) {
int limit = -1; int limit = -1;
if (limitExpr != null) { if (limitExpr != null) {
Value v = limitExpr.getValue(session); Value v = limitExpr.getValue(session);
...@@ -284,6 +284,7 @@ public class SelectUnion extends Query { ...@@ -284,6 +284,7 @@ public class SelectUnion extends Query {
Value v = limitExpr.getValue(session); Value v = limitExpr.getValue(session);
if (v != ValueNull.INSTANCE) { if (v != ValueNull.INSTANCE) {
result.setLimit(v.getInt()); result.setLimit(v.getInt());
result.setFetchPercent(fetchPercent);
result.setWithTies(withTies); result.setWithTies(withTies);
} }
} }
......
...@@ -41,6 +41,7 @@ public class LocalResult implements ResultInterface, ResultTarget { ...@@ -41,6 +41,7 @@ public class LocalResult implements ResultInterface, ResultTarget {
private Value[] currentRow; private Value[] currentRow;
private int offset; private int offset;
private int limit = -1; private int limit = -1;
private boolean fetchPercent;
private boolean withTies; private boolean withTies;
private boolean limitsWereApplied; private boolean limitsWereApplied;
private ResultExternal external; private ResultExternal external;
...@@ -387,9 +388,16 @@ public class LocalResult implements ResultInterface, ResultTarget { ...@@ -387,9 +388,16 @@ public class LocalResult implements ResultInterface, ResultTarget {
} }
int offset = Math.max(this.offset, 0); int offset = Math.max(this.offset, 0);
int limit = this.limit; int limit = this.limit;
if (offset == 0 && limit < 0 || rowCount == 0) { if (offset == 0 && limit < 0 && !fetchPercent || rowCount == 0) {
return; return;
} }
if (fetchPercent) {
if (limit < 0 || limit > 100) {
throw DbException.getInvalidValueException("FETCH PERCENT", limit);
}
// Oracle rounds percent up, do the same for now
limit = (limit * rowCount + 99) / 100;
}
boolean clearAll = offset >= rowCount || limit == 0; boolean clearAll = offset >= rowCount || limit == 0;
if (!clearAll) { if (!clearAll) {
int remaining = rowCount - offset; int remaining = rowCount - offset;
...@@ -484,6 +492,13 @@ public class LocalResult implements ResultInterface, ResultTarget { ...@@ -484,6 +492,13 @@ public class LocalResult implements ResultInterface, ResultTarget {
this.limit = limit; this.limit = limit;
} }
/**
* @param fetchPercent whether limit expression specifies percentage of rows
*/
public void setFetchPercent(boolean fetchPercent) {
this.fetchPercent = fetchPercent;
}
/** /**
* @param withTies whether tied rows should be included in result too * @param withTies whether tied rows should be included in result too
*/ */
......
...@@ -56,7 +56,7 @@ SELECT * FROM TEST ORDER BY A, B FETCH FIRST 4 ROWS WITH TIES; ...@@ -56,7 +56,7 @@ SELECT * FROM TEST ORDER BY A, B FETCH FIRST 4 ROWS WITH TIES;
> 1 2 3 > 1 2 3
> rows: 6 > rows: 6
SELECT * FROM TEST ORDER BY A FETCH FIRST 1 ROW WITH TIES; SELECT * FROM TEST ORDER BY A FETCH FIRST ROW WITH TIES;
> A B C > A B C
> - - - > - - -
> 1 1 1 > 1 1 1
...@@ -78,6 +78,31 @@ SELECT TOP (1) WITH TIES * FROM TEST ORDER BY A; ...@@ -78,6 +78,31 @@ SELECT TOP (1) WITH TIES * FROM TEST ORDER BY A;
> 1 2 3 > 1 2 3
> rows: 6 > rows: 6
SELECT TOP 1 PERCENT WITH TIES * FROM TEST ORDER BY A;
> A B C
> - - -
> 1 1 1
> 1 1 2
> 1 1 3
> 1 2 1
> 1 2 2
> 1 2 3
> rows: 6
SELECT TOP 51 PERCENT WITH TIES * FROM TEST ORDER BY A, B;
> A B C
> - - -
> 1 1 1
> 1 1 2
> 1 1 3
> 1 2 1
> 1 2 2
> 1 2 3
> 2 1 1
> 2 1 2
> 2 1 3
> rows: 9
SELECT * FROM TEST ORDER BY A, B OFFSET 3 ROWS FETCH NEXT 1 ROW WITH TIES; SELECT * FROM TEST ORDER BY A, B OFFSET 3 ROWS FETCH NEXT 1 ROW WITH TIES;
> A B C > A B C
> - - - > - - -
...@@ -86,6 +111,43 @@ SELECT * FROM TEST ORDER BY A, B OFFSET 3 ROWS FETCH NEXT 1 ROW WITH TIES; ...@@ -86,6 +111,43 @@ SELECT * FROM TEST ORDER BY A, B OFFSET 3 ROWS FETCH NEXT 1 ROW WITH TIES;
> 1 2 3 > 1 2 3
> rows: 3 > rows: 3
SELECT * FROM TEST FETCH NEXT ROWS ONLY;
> A B C
> - - -
> 1 1 1
> rows: 1
SELECT * FROM TEST FETCH FIRST 101 PERCENT ROWS ONLY;
> exception INVALID_VALUE_2
SELECT * FROM TEST FETCH FIRST -1 PERCENT ROWS ONLY;
> exception INVALID_VALUE_2
SELECT * FROM TEST FETCH FIRST 0 PERCENT ROWS ONLY;
> A B C
> - - -
> rows: 0
SELECT * FROM TEST FETCH FIRST 1 PERCENT ROWS ONLY;
> A B C
> - - -
> 1 1 1
> rows: 1
SELECT * FROM TEST FETCH FIRST 10 PERCENT ROWS ONLY;
> A B C
> - - -
> 1 1 1
> 1 1 2
> rows: 2
SELECT * FROM TEST OFFSET 2 ROWS FETCH NEXT 10 PERCENT ROWS ONLY;
> A B C
> - - -
> 1 1 3
> 1 2 1
> rows: 2
CREATE INDEX TEST_A_IDX ON TEST(A); CREATE INDEX TEST_A_IDX ON TEST(A);
> ok > ok
...@@ -123,12 +185,39 @@ SELECT * FROM TEST FETCH FIRST 1 ROW WITH TIES; ...@@ -123,12 +185,39 @@ SELECT * FROM TEST FETCH FIRST 1 ROW WITH TIES;
> 1 2 4 > 1 2 4
> rows: 4 > rows: 4
(SELECT * FROM TEST) UNION (SELECT 1, 2, 4) ORDER BY A, B OFFSET 3 ROWS FETCH NEXT 50 PERCENT ROWS ONLY;
> A B C
> - - -
> 1 2 1
> 1 2 2
> 1 2 3
> 1 2 4
> 2 1 1
> 2 1 2
> 2 1 3
> rows: 7
(SELECT * FROM TEST) UNION (SELECT 1, 2, 4) ORDER BY A, B OFFSET 3 ROWS FETCH NEXT 40 PERCENT ROWS WITH TIES;
> A B C
> - - -
> 1 2 1
> 1 2 2
> 1 2 3
> 1 2 4
> 2 1 1
> 2 1 2
> 2 1 3
> rows: 7
(SELECT * FROM TEST) UNION (SELECT 1, 2, 4) FETCH NEXT 1 ROW WITH TIES; (SELECT * FROM TEST) UNION (SELECT 1, 2, 4) FETCH NEXT 1 ROW WITH TIES;
> exception WITH_TIES_WITHOUT_ORDER_BY > exception WITH_TIES_WITHOUT_ORDER_BY
EXPLAIN SELECT * FROM TEST ORDER BY A, B OFFSET 3 ROWS FETCH NEXT 1 ROW WITH TIES; EXPLAIN SELECT * FROM TEST ORDER BY A, B OFFSET 3 ROWS FETCH NEXT 1 ROW WITH TIES;
>> SELECT TEST.A, TEST.B, TEST.C FROM PUBLIC.TEST /* PUBLIC.TEST_A_B_IDX */ ORDER BY 1, 2 OFFSET 3 ROWS FETCH NEXT 1 ROWS WITH TIES /* index sorted */ >> SELECT TEST.A, TEST.B, TEST.C FROM PUBLIC.TEST /* PUBLIC.TEST_A_B_IDX */ ORDER BY 1, 2 OFFSET 3 ROWS FETCH NEXT 1 ROWS WITH TIES /* index sorted */
EXPLAIN SELECT * FROM TEST ORDER BY A, B OFFSET 3 ROWS FETCH NEXT 1 PERCENT ROWS WITH TIES;
>> SELECT TEST.A, TEST.B, TEST.C FROM PUBLIC.TEST /* PUBLIC.TEST_A_B_IDX */ ORDER BY 1, 2 OFFSET 3 ROWS FETCH NEXT 1 PERCENT ROWS WITH TIES /* index sorted */
DROP TABLE TEST; DROP TABLE TEST;
> ok > ok
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论