From 5eea5d58eb1455ece56cefe1edad34cc72687bda Mon Sep 17 00:00:00 2001 From: Kyrylo Simonov Date: Fri, 21 Apr 2023 08:54:34 -0500 Subject: [PATCH] Improved handling of LIMIT clause in SQL Server --- docs/src/test/clauses.md | 54 +++++++++++++++++++++++++++++++++++++++- src/dialects.jl | 6 ++++- src/serialize.jl | 25 ++++++++++++++++--- 3 files changed, 79 insertions(+), 6 deletions(-) diff --git a/docs/src/test/clauses.md b/docs/src/test/clauses.md index 76fc9572..9781b649 100644 --- a/docs/src/test/clauses.md +++ b/docs/src/test/clauses.md @@ -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. @@ -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 diff --git a/src/dialects.jl b/src/dialects.jl index 64cbb23c..e370c618 100644 --- a/src/dialects.jl +++ b/src/dialects.jl @@ -28,6 +28,7 @@ module LIMIT_STYLE ANSI MYSQL SQLITE + SQLSERVER end Base.convert(::Type{LimitStyle}, s::Symbol) = @@ -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 @@ -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) diff --git a/src/serialize.jl b/src/serialize.jl index f3e9d7a0..ce31607b 100644 --- a/src/serialize.jl +++ b/src/serialize.jl @@ -746,11 +746,25 @@ 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 @@ -758,10 +772,13 @@ function serialize!(c::SelectClause, ctx) 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