mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-11-29 19:12:03 +00:00
Allow SQL standard FETCH without OFFSET
This commit is contained in:
parent
aa2b8aa893
commit
289d9849d4
@ -292,6 +292,9 @@ bool ParserSelectQuery::parseImpl(Pos & pos, ASTPtr & node, Expected & expected)
|
||||
/// This is needed for TOP expression, because it can also use WITH TIES.
|
||||
bool limit_with_ties_occured = false;
|
||||
|
||||
bool has_offset_clause = false;
|
||||
bool offset_clause_has_sql_standard_row_or_rows = false; /// OFFSET offset_row_count {ROW | ROWS}
|
||||
|
||||
/// LIMIT length | LIMIT offset, length | LIMIT count BY expr-list | LIMIT offset, length BY expr-list
|
||||
if (s_limit.ignore(pos, expected))
|
||||
{
|
||||
@ -316,6 +319,8 @@ bool ParserSelectQuery::parseImpl(Pos & pos, ASTPtr & node, Expected & expected)
|
||||
{
|
||||
if (!exp_elem.parse(pos, limit_offset, expected))
|
||||
return false;
|
||||
|
||||
has_offset_clause = true;
|
||||
}
|
||||
else if (s_with_ties.ignore(pos, expected))
|
||||
{
|
||||
@ -351,60 +356,65 @@ bool ParserSelectQuery::parseImpl(Pos & pos, ASTPtr & node, Expected & expected)
|
||||
}
|
||||
else if (s_offset.ignore(pos, expected))
|
||||
{
|
||||
/// OFFSET offset_row_count {ROW | ROWS} FETCH {FIRST | NEXT} fetch_row_count {ROW | ROWS} {ONLY | WITH TIES}
|
||||
bool offset_with_fetch_maybe = false;
|
||||
/// OFFSET without LIMIT
|
||||
|
||||
has_offset_clause = true;
|
||||
|
||||
if (!exp_elem.parse(pos, limit_offset, expected))
|
||||
return false;
|
||||
|
||||
/// SQL standard OFFSET N ROW[S] ...
|
||||
|
||||
if (s_row.ignore(pos, expected))
|
||||
offset_clause_has_sql_standard_row_or_rows = true;
|
||||
|
||||
if (s_rows.ignore(pos, expected))
|
||||
{
|
||||
if (offset_clause_has_sql_standard_row_or_rows)
|
||||
throw Exception(ErrorCodes::ROW_AND_ROWS_TOGETHER, "Can not use ROW and ROWS together");
|
||||
|
||||
offset_clause_has_sql_standard_row_or_rows = true;
|
||||
}
|
||||
}
|
||||
|
||||
/// SQL standard FETCH (either following SQL standard OFFSET or following ORDER BY)
|
||||
if ((!has_offset_clause || offset_clause_has_sql_standard_row_or_rows)
|
||||
&& s_fetch.ignore(pos, expected))
|
||||
{
|
||||
/// FETCH clause must exist with "ORDER BY"
|
||||
if (!order_expression_list)
|
||||
throw Exception(ErrorCodes::OFFSET_FETCH_WITHOUT_ORDER_BY, "Can not use OFFSET FETCH clause without ORDER BY");
|
||||
|
||||
if (s_first.ignore(pos, expected))
|
||||
{
|
||||
if (s_next.ignore(pos, expected))
|
||||
throw Exception(ErrorCodes::FIRST_AND_NEXT_TOGETHER, "Can not use FIRST and NEXT together");
|
||||
}
|
||||
else if (!s_next.ignore(pos, expected))
|
||||
return false;
|
||||
|
||||
if (!exp_elem.parse(pos, limit_length, expected))
|
||||
return false;
|
||||
|
||||
if (s_row.ignore(pos, expected))
|
||||
{
|
||||
if (s_rows.ignore(pos, expected))
|
||||
throw Exception(ErrorCodes::ROW_AND_ROWS_TOGETHER, "Can not use ROW and ROWS together");
|
||||
offset_with_fetch_maybe = true;
|
||||
}
|
||||
else if (s_rows.ignore(pos, expected))
|
||||
else if (!s_rows.ignore(pos, expected))
|
||||
return false;
|
||||
|
||||
if (s_with_ties.ignore(pos, expected))
|
||||
{
|
||||
offset_with_fetch_maybe = true;
|
||||
select_query->limit_with_ties = true;
|
||||
}
|
||||
|
||||
if (offset_with_fetch_maybe && s_fetch.ignore(pos, expected))
|
||||
else if (s_only.ignore(pos, expected))
|
||||
{
|
||||
/// OFFSET FETCH clause must exists with "ORDER BY"
|
||||
if (!order_expression_list)
|
||||
throw Exception(ErrorCodes::OFFSET_FETCH_WITHOUT_ORDER_BY, "Can not use OFFSET FETCH clause without ORDER BY");
|
||||
|
||||
if (s_first.ignore(pos, expected))
|
||||
{
|
||||
if (s_next.ignore(pos, expected))
|
||||
throw Exception(ErrorCodes::FIRST_AND_NEXT_TOGETHER, "Can not use FIRST and NEXT together");
|
||||
}
|
||||
else if (!s_next.ignore(pos, expected))
|
||||
return false;
|
||||
|
||||
if (!exp_elem.parse(pos, limit_length, expected))
|
||||
return false;
|
||||
|
||||
if (s_row.ignore(pos, expected))
|
||||
{
|
||||
if (s_rows.ignore(pos, expected))
|
||||
throw Exception(ErrorCodes::ROW_AND_ROWS_TOGETHER, "Can not use ROW and ROWS together");
|
||||
}
|
||||
else if (!s_rows.ignore(pos, expected))
|
||||
return false;
|
||||
|
||||
if (s_with_ties.ignore(pos, expected))
|
||||
{
|
||||
select_query->limit_with_ties = true;
|
||||
}
|
||||
else if (s_only.ignore(pos, expected))
|
||||
{
|
||||
select_query->limit_with_ties = false;
|
||||
}
|
||||
else
|
||||
{
|
||||
return false;
|
||||
}
|
||||
select_query->limit_with_ties = false;
|
||||
}
|
||||
else
|
||||
{
|
||||
return false;
|
||||
}
|
||||
}
|
||||
|
||||
|
36
tests/queries/0_stateless/02790_sql_standard_fetch.reference
Normal file
36
tests/queries/0_stateless/02790_sql_standard_fetch.reference
Normal file
@ -0,0 +1,36 @@
|
||||
┌─id─┬─name──┬─department─┬─salary─┐
|
||||
│ 25 │ Frank │ it │ 120 │
|
||||
│ 23 │ Henry │ it │ 104 │
|
||||
│ 24 │ Irene │ it │ 104 │
|
||||
│ 33 │ Alice │ sales │ 100 │
|
||||
│ 32 │ Dave │ sales │ 96 │
|
||||
└────┴───────┴────────────┴────────┘
|
||||
┌─id─┬─name──┬─department─┬─salary─┐
|
||||
│ 25 │ Frank │ it │ 120 │
|
||||
│ 23 │ Henry │ it │ 104 │
|
||||
│ 24 │ Irene │ it │ 104 │
|
||||
│ 33 │ Alice │ sales │ 100 │
|
||||
│ 32 │ Dave │ sales │ 96 │
|
||||
└────┴───────┴────────────┴────────┘
|
||||
┌─id─┬─name──┬─department─┬─salary─┐
|
||||
│ 25 │ Frank │ it │ 120 │
|
||||
│ 23 │ Henry │ it │ 104 │
|
||||
│ 24 │ Irene │ it │ 104 │
|
||||
│ 33 │ Alice │ sales │ 100 │
|
||||
│ 31 │ Cindy │ sales │ 96 │
|
||||
│ 32 │ Dave │ sales │ 96 │
|
||||
└────┴───────┴────────────┴────────┘
|
||||
┌─id─┬─name──┬─department─┬─salary─┐
|
||||
│ 33 │ Alice │ sales │ 100 │
|
||||
│ 31 │ Cindy │ sales │ 96 │
|
||||
│ 32 │ Dave │ sales │ 96 │
|
||||
│ 22 │ Grace │ it │ 90 │
|
||||
│ 21 │ Emma │ it │ 84 │
|
||||
└────┴───────┴────────────┴────────┘
|
||||
┌─id─┬─name──┬─department─┬─salary─┐
|
||||
│ 33 │ Alice │ sales │ 100 │
|
||||
│ 31 │ Cindy │ sales │ 96 │
|
||||
│ 32 │ Dave │ sales │ 96 │
|
||||
│ 22 │ Grace │ it │ 90 │
|
||||
│ 21 │ Emma │ it │ 84 │
|
||||
└────┴───────┴────────────┴────────┘
|
31
tests/queries/0_stateless/02790_sql_standard_fetch.sql
Normal file
31
tests/queries/0_stateless/02790_sql_standard_fetch.sql
Normal file
@ -0,0 +1,31 @@
|
||||
# https://antonz.org/sql-fetch/
|
||||
|
||||
CREATE TEMPORARY TABLE employees (id UInt64, name String, department String, salary UInt64);
|
||||
INSERT INTO employees VALUES (23, 'Henry', 'it', 104), (24, 'Irene', 'it', 104), (25, 'Frank', 'it', 120), (31, 'Cindy', 'sales', 96), (33, 'Alice', 'sales', 100), (32, 'Dave', 'sales', 96), (22, 'Grace', 'it', 90), (21, 'Emma', 'it', '84');
|
||||
|
||||
select * from employees
|
||||
order by salary desc
|
||||
limit 5
|
||||
format PrettyCompactNoEscapes;
|
||||
|
||||
select * from employees
|
||||
order by salary desc
|
||||
fetch first 5 rows only
|
||||
format PrettyCompactNoEscapes;
|
||||
|
||||
select * from employees
|
||||
order by salary desc
|
||||
fetch first 5 rows with ties
|
||||
format PrettyCompactNoEscapes;
|
||||
|
||||
select * from employees
|
||||
order by salary desc
|
||||
offset 3 rows
|
||||
fetch next 5 rows only
|
||||
format PrettyCompactNoEscapes;
|
||||
|
||||
select * from employees
|
||||
order by salary desc
|
||||
offset 3 rows
|
||||
fetch first 5 rows only
|
||||
format PrettyCompactNoEscapes;
|
Loading…
Reference in New Issue
Block a user