From 38a943ed1b7cecfcb4e93cb6b02cc2e325814af8 Mon Sep 17 00:00:00 2001 From: Aidan Haran Date: Mon, 31 Mar 2025 12:03:56 +0100 Subject: [PATCH 1/5] When using `LIMIT`/`OFFSET` without ordering try to order using projection rather than with the primary key --- CHANGELOG.md | 1 + lib/arel/visitors/sqlserver.rb | 44 ++++++++++++++---- test/cases/order_test_sqlserver.rb | 71 ++++++++++++++++++++++++++++++ 3 files changed, 108 insertions(+), 8 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 63173aedb..8bca8611d 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -3,6 +3,7 @@ #### Fixed - [#1318](https://github.com/rails-sqlserver/activerecord-sqlserver-adapter/pull/1318) Reverse order of values when upserting +- []() When using `LIMIT`/`OFFSET` without ordering try to order using projection rather than with the primary key. ## v8.0.5 diff --git a/lib/arel/visitors/sqlserver.rb b/lib/arel/visitors/sqlserver.rb index 5890b7fc3..d67189a9f 100644 --- a/lib/arel/visitors/sqlserver.rb +++ b/lib/arel/visitors/sqlserver.rb @@ -252,7 +252,11 @@ def visit_Arel_Nodes_SelectStatement_SQLServer_Lock(collector, options = {}) collector end + # AIDO def visit_Orders_And_Let_Fetch_Happen(o, collector) + + # binding.pry if $DEBUG + make_Fetch_Possible_And_Deterministic o if o.orders.any? collector << " ORDER BY " @@ -300,24 +304,48 @@ def select_statement_lock? @select_statement && @select_statement.lock end + # If LIMIT/OFFSET is used without ORDER BY, SQLServer will return an error. + # This method will add a deterministic ORDER BY clause to the query using following rules: + # 1. If the query has projections, use the first projection as the ORDER BY clause. + # 2. If the query has SQL literal projection, use the first part of the SQL literal as the ORDER BY clause. + # 3. If the query has a table with a primary key, use the primary key as the ORDER BY clause. def make_Fetch_Possible_And_Deterministic(o) return if o.limit.nil? && o.offset.nil? return if o.orders.any? - t = table_From_Statement o - pk = primary_Key_From_Table t - return unless pk + # TODO: Refactor to list all projections and then find the first one that looks good. + + projection = o.cores.first.projections.first + + + binding.pry if $DEBUG + + + if projection.is_a?(Arel::Attributes::Attribute) && !projection.name.include?("*") + o.orders = [projection.asc] - # Prefer deterministic vs a simple `(SELECT NULL)` expr. - o.orders = [pk.asc] + # TODO: Use better logic to find first projection that is usable for ordering. + elsif projection.is_a?(Arel::Nodes::SqlLiteral) && !projection.match?(/^\s*(1 as ONE|\*)(\s|,)*/i) + + first_projection = Arel::Nodes::SqlLiteral.new(projection.split(",").first.split(/\sAS\s/i).first) + o.orders = [first_projection.asc] + else + + pk = primary_Key_From_Table(table_From_Statement(o)) + o.orders = [pk.asc] if pk + end + + # rescue => e + # binding.pry end def distinct_One_As_One_Is_So_Not_Fetch(o) core = o.cores.first distinct = Nodes::Distinct === core.set_quantifier - oneasone = core.projections.all? { |x| x == ActiveRecord::FinderMethods::ONE_AS_ONE } - limitone = [nil, 0, 1].include? node_value(o.limit) - if distinct && oneasone && limitone && !o.offset + one_as_one = core.projections.all? { |x| x == ActiveRecord::FinderMethods::ONE_AS_ONE } + limit_one = [nil, 0, 1].include? node_value(o.limit) + + if distinct && one_as_one && limit_one && !o.offset core.projections = [Arel.sql("TOP(1) 1 AS [one]")] o.limit = nil end diff --git a/test/cases/order_test_sqlserver.rb b/test/cases/order_test_sqlserver.rb index 82f43d539..795cc925d 100644 --- a/test/cases/order_test_sqlserver.rb +++ b/test/cases/order_test_sqlserver.rb @@ -150,4 +150,75 @@ class OrderTestSQLServer < ActiveRecord::TestCase sql = Post.order(:id).order("posts.id ASC").to_sql assert_equal "SELECT [posts].* FROM [posts] ORDER BY [posts].[id] ASC, posts.id ASC", sql end + + describe "simple query containing limit" do + it "order by primary key if no projections" do + $DEBUG = false + + sql = Post.limit(5).to_sql + + assert_equal "SELECT [posts].* FROM [posts] ORDER BY [posts].[id] ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY", sql + + $DEBUG = false + end + + it "use order provided" do + # $DEBUG = true + + sql = Post.select(:legacy_comments_count).order(:tags_count).limit(5).to_sql + + assert_equal "SELECT [posts].[legacy_comments_count] FROM [posts] ORDER BY [posts].[tags_count] ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY", sql + + # binding.pry + + end + + it "order by first projection if no order provided" do + # $DEBUG = true + + sql = Post.select(:legacy_comments_count).limit(5).to_sql + + assert_equal "SELECT [posts].[legacy_comments_count] FROM [posts] ORDER BY [posts].[legacy_comments_count] ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY", sql + + # binding.pry + + end + + it "order by first projection (when multiple projections) if no order provided" do + sql = Post.select(:legacy_comments_count, :tags_count).limit(5).to_sql + + assert_equal "SELECT [posts].[legacy_comments_count], [posts].[tags_count] FROM [posts] ORDER BY [posts].[legacy_comments_count] ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY", sql + end + end + + describe "query containing FROM and limit" do + it "uses the provided orderings" do + sql = "SELECT sum(legacy_comments_count), count(*), min(legacy_comments_count) FROM (SELECT [posts].[legacy_comments_count] FROM [posts] ORDER BY [posts].[legacy_comments_count] DESC OFFSET 0 ROWS FETCH NEXT @0 ROWS ONLY) subquery ORDER BY sum(legacy_comments_count) ASC OFFSET 0 ROWS FETCH NEXT @1 ROWS ONLY" + + assert_queries_match(/#{Regexp.escape(sql)}/) do + result = Post.from(Post.order(legacy_comments_count: :desc).limit(5).select(:legacy_comments_count)).pick(Arel.sql("sum(legacy_comments_count), count(*), min(legacy_comments_count)")) + assert_equal result, [11, 5, 1] + end + end + # + it "in the subquery the first projection is used for ordering if none provided" do + sql = "SELECT sum(legacy_comments_count), count(*), min(legacy_comments_count) FROM (SELECT [posts].[legacy_comments_count], [posts].[tags_count] FROM [posts] ORDER BY [posts].[legacy_comments_count] ASC OFFSET 0 ROWS FETCH NEXT @0 ROWS ONLY) subquery ORDER BY sum(legacy_comments_count) ASC OFFSET 0 ROWS FETCH NEXT @1 ROWS ONLY" + + # binding.pry + + assert_queries_match(/#{Regexp.escape(sql)}/) do + result = Post.from(Post.limit(5).select(:legacy_comments_count, :tags_count)).pick(Arel.sql("sum(legacy_comments_count), count(*), min(legacy_comments_count)")) + assert_equal result, [0, 5, 0] + end + end + + it "in the subquery the primary key is used for ordering if none provided" do + sql = "SELECT sum(legacy_comments_count), count(*), min(legacy_comments_count) FROM (SELECT [posts].* FROM [posts] ORDER BY [posts].[id] ASC OFFSET 0 ROWS FETCH NEXT @0 ROWS ONLY) subquery ORDER BY sum(legacy_comments_count) ASC OFFSET 0 ROWS FETCH NEXT @1 ROWS ONLY" + + assert_queries_match(/#{Regexp.escape(sql)}/) do + result = Post.from(Post.limit(5)).pick(Arel.sql("sum(legacy_comments_count), count(*), min(legacy_comments_count)")) + assert_equal result, [10, 5, 0] + end + end + end end From f739a7b5ec2b1248744c195a75fd5f1cdf1fcb7f Mon Sep 17 00:00:00 2001 From: Aidan Haran Date: Tue, 1 Apr 2025 15:29:50 +0100 Subject: [PATCH 2/5] Fix --- lib/arel/visitors/sqlserver.rb | 59 +++++++++++++++++++--------------- 1 file changed, 33 insertions(+), 26 deletions(-) diff --git a/lib/arel/visitors/sqlserver.rb b/lib/arel/visitors/sqlserver.rb index d67189a9f..2724cefa2 100644 --- a/lib/arel/visitors/sqlserver.rb +++ b/lib/arel/visitors/sqlserver.rb @@ -9,6 +9,8 @@ class SQLServer < Arel::Visitors::ToSql FETCH0 = " FETCH FIRST (SELECT 0) " ROWS_ONLY = " ROWS ONLY" + ONE_AS_ONE = ActiveRecord::FinderMethods::ONE_AS_ONE + private # SQLServer ToSql/Visitor (Overrides) @@ -251,12 +253,8 @@ def visit_Arel_Nodes_SelectStatement_SQLServer_Lock(collector, options = {}) end collector end - - # AIDO + def visit_Orders_And_Let_Fetch_Happen(o, collector) - - # binding.pry if $DEBUG - make_Fetch_Possible_And_Deterministic o if o.orders.any? collector << " ORDER BY " @@ -304,8 +302,7 @@ def select_statement_lock? @select_statement && @select_statement.lock end - # If LIMIT/OFFSET is used without ORDER BY, SQLServer will return an error. - # This method will add a deterministic ORDER BY clause to the query using following rules: + # LIMIT/OFFSET cannot be used without an ORDER. This method adds a deterministic ORDER using following rules: # 1. If the query has projections, use the first projection as the ORDER BY clause. # 2. If the query has SQL literal projection, use the first part of the SQL literal as the ORDER BY clause. # 3. If the query has a table with a primary key, use the primary key as the ORDER BY clause. @@ -313,36 +310,46 @@ def make_Fetch_Possible_And_Deterministic(o) return if o.limit.nil? && o.offset.nil? return if o.orders.any? - # TODO: Refactor to list all projections and then find the first one that looks good. - - projection = o.cores.first.projections.first - - - binding.pry if $DEBUG - - - if projection.is_a?(Arel::Attributes::Attribute) && !projection.name.include?("*") + if (projection = projection_to_order_by_for_fetch(o)) o.orders = [projection.asc] - - # TODO: Use better logic to find first projection that is usable for ordering. - elsif projection.is_a?(Arel::Nodes::SqlLiteral) && !projection.match?(/^\s*(1 as ONE|\*)(\s|,)*/i) - - first_projection = Arel::Nodes::SqlLiteral.new(projection.split(",").first.split(/\sAS\s/i).first) - o.orders = [first_projection.asc] else - pk = primary_Key_From_Table(table_From_Statement(o)) o.orders = [pk.asc] if pk end + end + + def projection_to_order_by_for_fetch(o) + o.cores.first.projections.each do |projection| + case projection + when Arel::Attributes::Attribute + return projection unless projection.name.include?("*") + when Arel::Nodes::SqlLiteral + projection.split(",").each do |p| + next if p.match?(/#{Regexp.escape(ONE_AS_ONE)}/i) || p.include?("*") + + return Arel::Nodes::SqlLiteral.new(remove_last_AS_from_projection(p)) + end + end + end + + nil + end - # rescue => e - # binding.pry + # Remove last AS from projection that could contain multiple AS clauses. + # Examples: + # - 'name' + # - 'name AS first_name' + # - 'AVG(accounts.credit_limit AS DECIMAL) AS avg_credit_limit)' + def remove_last_AS_from_projection(projection) + parts = projection.split(/\sAS\s/i) + parts.pop if parts.length > 1 + projection.join(" AS ") end def distinct_One_As_One_Is_So_Not_Fetch(o) core = o.cores.first distinct = Nodes::Distinct === core.set_quantifier - one_as_one = core.projections.all? { |x| x == ActiveRecord::FinderMethods::ONE_AS_ONE } + one_as_one = core.projections.all? { |x| x == ONE_AS_ONE } limit_one = [nil, 0, 1].include? node_value(o.limit) if distinct && one_as_one && limit_one && !o.offset From f09d2192c7a8fae8e42c96950a6a615706b783cf Mon Sep 17 00:00:00 2001 From: Aidan Haran Date: Tue, 1 Apr 2025 15:31:46 +0100 Subject: [PATCH 3/5] Cleanup --- lib/arel/visitors/sqlserver.rb | 2 +- test/cases/order_test_sqlserver.rb | 18 +----------------- 2 files changed, 2 insertions(+), 18 deletions(-) diff --git a/lib/arel/visitors/sqlserver.rb b/lib/arel/visitors/sqlserver.rb index 2724cefa2..f47afb405 100644 --- a/lib/arel/visitors/sqlserver.rb +++ b/lib/arel/visitors/sqlserver.rb @@ -253,7 +253,7 @@ def visit_Arel_Nodes_SelectStatement_SQLServer_Lock(collector, options = {}) end collector end - + def visit_Orders_And_Let_Fetch_Happen(o, collector) make_Fetch_Possible_And_Deterministic o if o.orders.any? diff --git a/test/cases/order_test_sqlserver.rb b/test/cases/order_test_sqlserver.rb index 795cc925d..bd59e586d 100644 --- a/test/cases/order_test_sqlserver.rb +++ b/test/cases/order_test_sqlserver.rb @@ -153,35 +153,21 @@ class OrderTestSQLServer < ActiveRecord::TestCase describe "simple query containing limit" do it "order by primary key if no projections" do - $DEBUG = false - sql = Post.limit(5).to_sql assert_equal "SELECT [posts].* FROM [posts] ORDER BY [posts].[id] ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY", sql - - $DEBUG = false end it "use order provided" do - # $DEBUG = true - sql = Post.select(:legacy_comments_count).order(:tags_count).limit(5).to_sql assert_equal "SELECT [posts].[legacy_comments_count] FROM [posts] ORDER BY [posts].[tags_count] ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY", sql - - # binding.pry - end it "order by first projection if no order provided" do - # $DEBUG = true - sql = Post.select(:legacy_comments_count).limit(5).to_sql assert_equal "SELECT [posts].[legacy_comments_count] FROM [posts] ORDER BY [posts].[legacy_comments_count] ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY", sql - - # binding.pry - end it "order by first projection (when multiple projections) if no order provided" do @@ -200,12 +186,10 @@ class OrderTestSQLServer < ActiveRecord::TestCase assert_equal result, [11, 5, 1] end end - # + it "in the subquery the first projection is used for ordering if none provided" do sql = "SELECT sum(legacy_comments_count), count(*), min(legacy_comments_count) FROM (SELECT [posts].[legacy_comments_count], [posts].[tags_count] FROM [posts] ORDER BY [posts].[legacy_comments_count] ASC OFFSET 0 ROWS FETCH NEXT @0 ROWS ONLY) subquery ORDER BY sum(legacy_comments_count) ASC OFFSET 0 ROWS FETCH NEXT @1 ROWS ONLY" - # binding.pry - assert_queries_match(/#{Regexp.escape(sql)}/) do result = Post.from(Post.limit(5).select(:legacy_comments_count, :tags_count)).pick(Arel.sql("sum(legacy_comments_count), count(*), min(legacy_comments_count)")) assert_equal result, [0, 5, 0] From ba39216e93e862230c63a8c209d7cabe084fb9bd Mon Sep 17 00:00:00 2001 From: Aidan Haran Date: Tue, 1 Apr 2025 17:04:28 +0100 Subject: [PATCH 4/5] Typo --- lib/arel/visitors/sqlserver.rb | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/lib/arel/visitors/sqlserver.rb b/lib/arel/visitors/sqlserver.rb index f47afb405..868befbbc 100644 --- a/lib/arel/visitors/sqlserver.rb +++ b/lib/arel/visitors/sqlserver.rb @@ -343,7 +343,7 @@ def projection_to_order_by_for_fetch(o) def remove_last_AS_from_projection(projection) parts = projection.split(/\sAS\s/i) parts.pop if parts.length > 1 - projection.join(" AS ") + parts.join(" AS ") end def distinct_One_As_One_Is_So_Not_Fetch(o) From 3cf43eadd26f4747627f170c3d65c5ea7135d92d Mon Sep 17 00:00:00 2001 From: Aidan Haran Date: Tue, 1 Apr 2025 19:18:56 +0100 Subject: [PATCH 5/5] Cleanup --- CHANGELOG.md | 2 +- lib/arel/visitors/sqlserver.rb | 11 +++++------ 2 files changed, 6 insertions(+), 7 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 7b7a315aa..a774d2d6e 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -4,7 +4,7 @@ - [#1318](https://github.com/rails-sqlserver/activerecord-sqlserver-adapter/pull/1318) Reverse order of values when upserting - [#1321](https://github.com/rails-sqlserver/activerecord-sqlserver-adapter/pull/1321) Fix SQL statement to calculate `updated_at` when upserting -- []() When using `LIMIT`/`OFFSET` without ordering try to order using projection rather than with the primary key. +- [1322](https://github.com/rails-sqlserver/activerecord-sqlserver-adapter/pull/1322) When using `FETCH` without ordering try to order using projection rather than the primary key. ## v8.0.5 diff --git a/lib/arel/visitors/sqlserver.rb b/lib/arel/visitors/sqlserver.rb index 868befbbc..93e25875c 100644 --- a/lib/arel/visitors/sqlserver.rb +++ b/lib/arel/visitors/sqlserver.rb @@ -302,10 +302,8 @@ def select_statement_lock? @select_statement && @select_statement.lock end - # LIMIT/OFFSET cannot be used without an ORDER. This method adds a deterministic ORDER using following rules: - # 1. If the query has projections, use the first projection as the ORDER BY clause. - # 2. If the query has SQL literal projection, use the first part of the SQL literal as the ORDER BY clause. - # 3. If the query has a table with a primary key, use the primary key as the ORDER BY clause. + # FETCH cannot be used without an order. If an order is not given then try to use the projections for the ordering. + # If no suitable projection are present then fallback to using the primary key of the table. def make_Fetch_Possible_And_Deterministic(o) return if o.limit.nil? && o.offset.nil? return if o.orders.any? @@ -318,6 +316,8 @@ def make_Fetch_Possible_And_Deterministic(o) end end + # Find the first projection or part of projection that can be used for ordering. Cannot use + # projections with '*' or '1 AS one' in them. def projection_to_order_by_for_fetch(o) o.cores.first.projections.each do |projection| case projection @@ -335,8 +335,7 @@ def projection_to_order_by_for_fetch(o) nil end - # Remove last AS from projection that could contain multiple AS clauses. - # Examples: + # Remove last AS from projection. Example projections: # - 'name' # - 'name AS first_name' # - 'AVG(accounts.credit_limit AS DECIMAL) AS avg_credit_limit)'