提交 0cb3d7fc authored 作者: Evgenij Ryazanov's avatar Evgenij Ryazanov

Forbid mixed OFFSET/FETCH/LIMIT/TOP clauses and improve documentation

上级 90b08cd0
......@@ -22,9 +22,16 @@ HAVING filter rows after grouping.
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.
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.
Please note using high offset values should be avoided because it can cause performance problems.
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
......@@ -41,7 +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 LIMIT 1000;
SELECT * FROM TEST OFFSET 1000 ROWS FETCH NEXT 1000 ROWS ONLY;
SELECT A, B FROM TEST ORDER BY A FETCH NEXT 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;
......
......@@ -2358,59 +2358,64 @@ public class Parser {
command.setOrder(orderList);
currentSelect = oldSelect;
}
// make sure aggregate functions will not work here
Select temp = currentSelect;
currentSelect = null;
// Standard SQL OFFSET / FETCH
if (readIf(OFFSET)) {
command.setOffset(readExpression().optimize(session));
if (!readIf("ROW")) {
readIf("ROWS");
if (command.getLimit() == null) {
// make sure aggregate functions will not work here
Select temp = currentSelect;
currentSelect = null;
boolean hasOffsetOrFetch = false;
// Standard SQL OFFSET / FETCH
if (readIf(OFFSET)) {
hasOffsetOrFetch = true;
command.setOffset(readExpression().optimize(session));
if (!readIf("ROW")) {
readIf("ROWS");
}
}
}
if (readIf(FETCH)) {
if (!readIf("FIRST")) {
read("NEXT");
if (readIf(FETCH)) {
hasOffsetOrFetch = true;
if (!readIf("FIRST")) {
read("NEXT");
}
if (readIf("ROW") || readIf("ROWS")) {
command.setLimit(ValueExpression.get(ValueInt.get(1)));
} else {
Expression limit = readExpression().optimize(session);
command.setLimit(limit);
if (readIf("PERCENT")) {
command.setFetchPercent(true);
}
if (!readIf("ROW")) {
read("ROWS");
}
}
if (readIf(WITH)) {
read("TIES");
command.setWithTies(true);
} else {
read("ONLY");
}
}
if (readIf("ROW") || readIf("ROWS")) {
command.setLimit(ValueExpression.get(ValueInt.get(1)));
} else {
// MySQL-style LIMIT / OFFSET
if (!hasOffsetOrFetch && readIf(LIMIT)) {
Expression limit = readExpression().optimize(session);
command.setLimit(limit);
if (readIf("PERCENT")) {
command.setFetchPercent(true);
}
if (!readIf("ROW")) {
read("ROWS");
if (readIf(OFFSET)) {
Expression offset = readExpression().optimize(session);
command.setOffset(offset);
} else if (readIf(COMMA)) {
// MySQL: [offset, ] rowcount
Expression offset = limit;
limit = readExpression().optimize(session);
command.setOffset(offset);
command.setLimit(limit);
}
}
if (readIf(WITH)) {
read("TIES");
command.setWithTies(true);
} else {
read("ONLY");
if (readIf("SAMPLE_SIZE")) {
Expression sampleSize = readExpression().optimize(session);
command.setSampleSize(sampleSize);
}
currentSelect = temp;
}
// MySQL-style LIMIT / OFFSET
if (readIf(LIMIT)) {
Expression limit = readExpression().optimize(session);
command.setLimit(limit);
if (readIf(OFFSET)) {
Expression offset = readExpression().optimize(session);
command.setOffset(offset);
} else if (readIf(COMMA)) {
// MySQL: [offset, ] rowcount
Expression offset = limit;
limit = readExpression().optimize(session);
command.setOffset(offset);
command.setLimit(limit);
}
}
if (readIf("SAMPLE_SIZE")) {
Expression sampleSize = readExpression().optimize(session);
command.setSampleSize(sampleSize);
}
currentSelect = temp;
if (readIf(FOR)) {
if (readIf("UPDATE")) {
if (readIf("OF")) {
......
......@@ -267,3 +267,25 @@ DROP TABLE TEST1;
DROP TABLE TEST2;
> ok
-- Disallowed mixed OFFSET/FETCH/LIMIT/TOP clauses
CREATE TABLE TEST (ID BIGINT);
> ok
SELECT TOP 1 ID FROM TEST OFFSET 1 ROW;
> exception SYNTAX_ERROR_1
SELECT TOP 1 ID FROM TEST FETCH NEXT ROW ONLY;
> exception SYNTAX_ERROR_1
SELECT TOP 1 ID FROM TEST LIMIT 1;
> exception SYNTAX_ERROR_1
SELECT ID FROM TEST OFFSET 1 ROW LIMIT 1;
> exception SYNTAX_ERROR_1
SELECT ID FROM TEST FETCH NEXT ROW ONLY LIMIT 1;
> exception SYNTAX_ERROR_1
DROP TABLE TEST;
> ok
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论