Skip to content

Commit

Permalink
Improved handling of LIMIT clause in SQL Server
Browse files Browse the repository at this point in the history
  • Loading branch information
xitology committed Apr 21, 2023
1 parent 58c7402 commit 5eea5d5
Show file tree
Hide file tree
Showing 3 changed files with 79 additions and 6 deletions.
54 changes: 53 additions & 1 deletion docs/src/test/clauses.md
Original file line number Diff line number Diff line change
Expand Up @@ -768,7 +768,6 @@ Non-standard MySQL and SQLite syntax is supported.
LIMIT 10
=#


Both limit (the number of rows) and offset (number of rows to skip) can
be specified.

Expand Down Expand Up @@ -865,6 +864,59 @@ It is possible to specify the limit with ties.
FETCH FIRST 10 ROWS WITH TIES
=#

SQL Server automatically replaces `FETCH` clause with `TOP` when possible.

c = FROM(:person) |>
ORDER(:year_of_birth) |>
LIMIT(10) |>
SELECT(:person_id)

print(render(c, dialect = :sqlserver))
#=>
SELECT TOP 10 [person_id]
FROM [person]
ORDER BY [year_of_birth]
=#

c = FROM(:person) |>
ORDER(:year_of_birth) |>
LIMIT(100, 10) |>
SELECT(:person_id)

print(render(c, dialect = :sqlserver))
#=>
SELECT [person_id]
FROM [person]
ORDER BY [year_of_birth]
OFFSET 100 ROWS
FETCH NEXT 10 ROWS ONLY
=#

SQL Server prohibits `ORDER BY` without limiting in a nested query, so FunSQL
automatically adds `OFFSET 0` clause to the query.

c = FROM(:person) |>
ORDER(:year_of_birth) |>
SELECT(:person_id, :gender_concept_id) |>
AS(:person) |>
FROM() |>
WHERE(FUN("=", :gender_concept_id, 8507)) |>
SELECT(:person_id)

print(render(c, dialect = :sqlserver))
#=>
SELECT [person_id]
FROM (
SELECT
[person_id],
[gender_concept_id]
FROM [person]
ORDER BY [year_of_birth]
OFFSET 0 ROWS
) AS [person]
WHERE ([gender_concept_id] = 8507)
=#


## `JOIN` Clause

Expand Down
6 changes: 5 additions & 1 deletion src/dialects.jl
Original file line number Diff line number Diff line change
Expand Up @@ -28,6 +28,7 @@ module LIMIT_STYLE
ANSI
MYSQL
SQLITE
SQLSERVER
end

Base.convert(::Type{LimitStyle}, s::Symbol) =
Expand All @@ -37,8 +38,10 @@ Base.convert(::Type{LimitStyle}, s::Symbol) =
MYSQL :
s in (:sqlite, :SQLITE) ?
SQLITE :
s in (:sqlserver, :SQLSERVER) ?
SQLSERVER :
throw(DomainError(QuoteNode(s),
"expected :ansi, :mysql, or :sqlite"))
"expected :ansi, :mysql, :sqlite, or :sqlserver"))

end

Expand Down Expand Up @@ -154,6 +157,7 @@ const sqlserver_dialect =
has_boolean_literals = false,
has_recursive_annotation = false,
identifier_quotes = ('[', ']'),
limit_style = LIMIT_STYLE.SQLSERVER,
values_column_prefix = nothing,
variable_prefix = '?',
variable_style = VARIABLE_STYLE.POSITIONAL)
Expand Down
25 changes: 21 additions & 4 deletions src/serialize.jl
Original file line number Diff line number Diff line change
Expand Up @@ -746,22 +746,39 @@ function serialize!(c::SelectClause, ctx)
newline(ctx)
end
ctx.nested = true
print(ctx, "SELECT")
over = c.over
limit = nothing
with_ties = false
offset_0_rows = false
top = c.top
if top !== nothing
print(ctx, " TOP ", top.limit)
if top.with_ties
limit = top.limit
with_ties = top.with_ties
elseif ctx.dialect.limit_style === LIMIT_STYLE.SQLSERVER
if @dissect(over, limit_over |> LIMIT(offset = nothing, limit = limit, with_ties = with_ties))
over = limit_over
elseif nested && @dissect(over, ORDER())
offset_0_rows = true
end
end
print(ctx, "SELECT")
if limit !== nothing
print(ctx, " TOP ", limit)
if with_ties
print(ctx, " WITH TIES")
end
end
if c.distinct
print(ctx, " DISTINCT")
end
serialize_lines!(c.args, ctx)
over = c.over
if over !== nothing
serialize!(over, ctx)
end
if offset_0_rows
newline(ctx)
print(ctx, "OFFSET 0 ROWS")
end
ctx.nested = nested
if nested
ctx.level -= 1
Expand Down

0 comments on commit 5eea5d5

Please sign in to comment.