@@ -7,6 +7,8 @@ class SQLServer < Arel::Visitors::ToSql
77 def visit_Arel_Nodes_SelectStatement ( o , a )
88 if complex_count_sql? ( o )
99 visit_Arel_Nodes_SelectStatementForComplexCount ( o , a )
10+ elsif distinct_non_present_orders? ( o , a )
11+ visit_Arel_Nodes_SelectStatementDistinctNonPresentOrders ( o , a )
1012 elsif o . offset
1113 visit_Arel_Nodes_SelectStatementWithOffset ( o , a )
1214 else
@@ -47,6 +49,76 @@ def visit_Arel_Nodes_Bin(o, a)
4749
4850 # SQLServer ToSql/Visitor (Additions)
4951
52+ # This constructs a query using DENSE_RANK() and ROW_NUMBER() to allow
53+ # ordering a DISTINCT set of data by columns in another table that are
54+ # not part of what we actually want to be DISTINCT. Without this, it is
55+ # possible for the DISTINCT qualifier combined with TOP to return fewer
56+ # rows than were requested.
57+ def visit_Arel_Nodes_SelectStatementDistinctNonPresentOrders ( o , a )
58+ core = o . cores . first
59+ projections = core . projections
60+ groups = core . groups
61+ orders = o . orders . uniq
62+
63+ select_frags = projections . map do |x |
64+ frag = projection_to_sql_remove_distinct ( x , core , a )
65+ # Remove the table specifier
66+ frag . gsub! ( /^[^\. ]*\. / , '' )
67+ # If there is an alias, remove everything but
68+ frag . gsub ( /^.*\s AS\s +/i , '' )
69+ end
70+
71+ if o . offset
72+ select_frags << 'ROW_NUMBER() OVER (ORDER BY __order) AS __offset'
73+ else
74+ select_frags << '__order'
75+ end
76+
77+ projection_list = projections . map { |x | projection_to_sql_remove_distinct ( x , core , a ) } . join ( ', ' )
78+
79+ sql = [
80+ ( 'SELECT' ) ,
81+ ( visit ( core . set_quantifier , a ) if core . set_quantifier and !o . offset ) ,
82+ ( visit ( o . limit , a ) if o . limit and !o . offset ) ,
83+ ( select_frags . join ( ', ' ) ) ,
84+ ( 'FROM (' ) ,
85+ ( 'SELECT' ) ,
86+ (
87+ [
88+ ( projection_list ) ,
89+ ( ', DENSE_RANK() OVER (' ) ,
90+ ( "ORDER BY #{ orders . map { |x | visit ( x , a ) } . join ( ', ' ) } " if !orders . empty? ) ,
91+ ( ') AS __order' ) ,
92+ ( ', ROW_NUMBER() OVER (' ) ,
93+ ( "PARTITION BY #{ projection_list } " if !orders . empty? ) ,
94+ ( " ORDER BY #{ orders . map { |x | visit ( x , a ) } . join ( ', ' ) } " if !orders . empty? ) ,
95+ ( ') AS __joined_row_num' )
96+ ] . join ( '' )
97+ ) ,
98+ ( source_with_lock_for_select_statement ( o , a ) ) ,
99+ ( "WHERE #{ core . wheres . map { |x | visit ( x , a ) } . join ' AND ' } " unless core . wheres . empty? ) ,
100+ ( "GROUP BY #{ groups . map { |x | visit ( x , a ) } . join ', ' } " unless groups . empty? ) ,
101+ ( visit ( core . having , a ) if core . having ) ,
102+ ( ') AS __sq' ) ,
103+ ( 'WHERE __joined_row_num = 1' ) ,
104+ ( 'ORDER BY __order' unless o . offset )
105+ ] . compact . join ( ' ' )
106+
107+ if o . offset
108+ sql = [
109+ ( 'SELECT' ) ,
110+ ( visit ( core . set_quantifier , a ) if core . set_quantifier ) ,
111+ ( visit ( o . limit , a ) if o . limit ) ,
112+ ( '*' ) ,
113+ ( 'FROM (' + sql + ') AS __osq' ) ,
114+ ( "WHERE __offset > #{ visit ( o . offset . expr , a ) } " ) ,
115+ ( 'ORDER BY __offset' )
116+ ] . join ( ' ' )
117+ end
118+
119+ sql
120+ end
121+
50122 def visit_Arel_Nodes_SelectStatementWithOutOffset ( o , a , windowed = false )
51123 find_and_fix_uncorrelated_joins_in_select_statement ( o )
52124 core = o . cores . first
@@ -123,6 +195,18 @@ def visit_Arel_Nodes_SelectStatementForComplexCount(o, a)
123195
124196 # SQLServer Helpers
125197
198+ def projection_to_sql_remove_distinct ( x , core , a )
199+ frag = Arel . sql ( visit ( x , a ) )
200+ # In Rails 4.0.0, DISTINCT was in a projection, whereas with 4.0.1
201+ # it is now stored in the set_quantifier. This moves it to the correct
202+ # place so the code works on both 4.0.0 and 4.0.1.
203+ if frag =~ /^\s *DISTINCT\s +/i
204+ core . set_quantifier = Arel ::Nodes ::Distinct . new ( )
205+ frag . gsub! ( /\s *DISTINCT\s +/ , '' )
206+ end
207+ frag
208+ end
209+
126210 def source_with_lock_for_select_statement ( o , a )
127211 core = o . cores . first
128212 source = "FROM #{ visit ( core . source , a ) . strip } " if core . source
@@ -166,6 +250,68 @@ def single_distinct_select_statement?(o)
166250 p1 . respond_to? ( :include? ) && p1 . include? ( 'DISTINCT' ) )
167251 end
168252
253+ # Determine if the SELECT statement is asking for DISTINCT results,
254+ # but is using columns not part of the SELECT list in the ORDER BY.
255+ # This is necessary because SQL Server requires all ORDER BY entries
256+ # be in the SELECT list with DISTINCT. However, these ordering columns
257+ # can cause duplicate rows, which affect when using a limit.
258+ def distinct_non_present_orders? ( o , a )
259+ projections = o . cores . first . projections
260+
261+ sq = o . cores . first . set_quantifier
262+ p1 = projections . first
263+
264+ found_distinct = sq and sq . class . to_s =~ /Distinct/
265+ if ( p1 . respond_to? ( :distinct ) && p1 . distinct ) || ( p1 . respond_to? ( :include? ) && p1 . include? ( 'DISTINCT' ) )
266+ found_distinct = true
267+ end
268+
269+ return false if !found_distinct or o . orders . uniq . empty?
270+
271+ tables_all_columns = [ ]
272+ expressions = projections . map do |p |
273+ visit ( p , a ) . split ( ',' ) . map do |x |
274+ x . strip!
275+ # Rails 4.0.0 included DISTINCT in the first projection
276+ x . gsub! ( /\s *DISTINCT\s +/ , '' )
277+ # Aliased column names
278+ x . gsub! ( /\s +AS\s +\w +/i , '' )
279+ # Identifier quoting
280+ x . gsub! ( /\[ |\] / , '' )
281+ star_match = /^(\w +)\. \* $/ . match ( x )
282+ if star_match
283+ tables_all_columns << star_match [ 1 ]
284+ end
285+ x . strip . downcase
286+ end . join ( ', ' )
287+ end
288+
289+ # Make sure each order by is in the select list, otherwise there needs
290+ # to be a subquery with row_numbe()
291+ o . orders . uniq . each do |order |
292+ order = visit ( order , a )
293+ order . strip!
294+
295+ order . gsub! ( /\s +(asc|desc)/i , '' )
296+ # Identifier quoting
297+ order . gsub! ( /\[ |\] / , '' )
298+
299+ order . strip!
300+ order . downcase!
301+
302+ # If we selected all columns from a table, the order is ok
303+ table_match = /^(\w +)\. \w +$/ . match ( order )
304+ next if table_match and tables_all_columns . include? ( table_match [ 1 ] )
305+
306+ next if expressions . include? ( order )
307+
308+ return true
309+ end
310+
311+ # We didn't find anything in the order by no being selected
312+ false
313+ end
314+
169315 def windowed_single_distinct_select_statement? ( o )
170316 o . limit &&
171317 o . offset &&
0 commit comments