From 3d3faf8dde9309307aa3818609f5706e5f8bbc8a Mon Sep 17 00:00:00 2001 From: Aidan Haran Date: Mon, 6 Apr 2020 15:46:49 +0100 Subject: [PATCH] Subqueries cannot include ordering unless TOP/LIMIT also specified --- lib/arel/visitors/sqlserver.rb | 18 ++++++++++++++ test/cases/in_clause_test_sqlserver.rb | 34 ++++++++++++++++++++++++++ 2 files changed, 52 insertions(+) create mode 100644 test/cases/in_clause_test_sqlserver.rb diff --git a/lib/arel/visitors/sqlserver.rb b/lib/arel/visitors/sqlserver.rb index c5f2d6913..29dd5daba 100644 --- a/lib/arel/visitors/sqlserver.rb +++ b/lib/arel/visitors/sqlserver.rb @@ -127,6 +127,19 @@ def visit_Arel_Nodes_OuterJoin o, collector visit o.right, collector end + # Need to remove ordering from subqueries unless TOP/OFFSET also used. Otherwise, SQLServer + # returns error "The ORDER BY clause is invalid in views, inline functions, derived tables, + # subqueries, and common table expressions, unless TOP, OFFSET or FOR XML is also specified." + def collect_in_clause(left, right, collector) + if Array === right + right.each { |node| remove_invalid_ordering_from_in_clause(node) } + else + remove_invalid_ordering_from_in_clause(right) + end + + super + end + # SQLServer ToSql/Visitor (Additions) def visit_Arel_Nodes_SelectStatement_SQLServer_Lock collector, options = {} @@ -219,6 +232,11 @@ def remote_server_table_name o ).quoted end + def remove_invalid_ordering_from_in_clause(node) + return unless Arel::Nodes::SelectStatement === node + + node.orders = [] unless node.offset || node.limit + end end end end diff --git a/test/cases/in_clause_test_sqlserver.rb b/test/cases/in_clause_test_sqlserver.rb new file mode 100644 index 000000000..6ec295130 --- /dev/null +++ b/test/cases/in_clause_test_sqlserver.rb @@ -0,0 +1,34 @@ +require 'cases/helper_sqlserver' +require 'models/post' +require 'models/author' + +class InClauseTestSQLServer < ActiveRecord::TestCase + fixtures :posts, :authors + + it 'removes ordering from subqueries' do + authors_subquery = Author.where(name: ['David', 'Mary', 'Bob']).order(:name) + posts = Post.where(author: authors_subquery) + + assert_includes authors_subquery.to_sql, "ORDER BY [authors].[name]" + assert_not_includes posts.to_sql, "ORDER BY [authors].[name]" + assert_equal 10, posts.length + end + + it 'does not remove ordering from subquery that includes a limit' do + authors_subquery = Author.where(name: ['David', 'Mary', 'Bob']).order(:name).limit(2) + posts = Post.where(author: authors_subquery) + + assert_includes authors_subquery.to_sql, "ORDER BY [authors].[name]" + assert_includes posts.to_sql, "ORDER BY [authors].[name]" + assert_equal 7, posts.length + end + + it 'does not remove ordering from subquery that includes an offset' do + authors_subquery = Author.where(name: ['David', 'Mary', 'Bob']).order(:name).offset(1) + posts = Post.where(author: authors_subquery) + + assert_includes authors_subquery.to_sql, "ORDER BY [authors].[name]" + assert_includes posts.to_sql, "ORDER BY [authors].[name]" + assert_equal 8, posts.length + end +end