Skip to content

Commit bc3d2f5

Browse files
committed
Adding limit/offset to association limiting SQL fragments. Details: http://gist.github.com/25118
1 parent 06e98aa commit bc3d2f5

File tree

2 files changed

+50
-1
lines changed

2 files changed

+50
-1
lines changed

lib/active_record/connection_adapters/sqlserver_adapter.rb

Lines changed: 25 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -305,12 +305,14 @@ def add_limit_offset!(sql, options)
305305
raise ArgumentError, "limit should be an integer"
306306
end
307307
end
308-
# The buisiness of adding limit/offset
308+
# The business of adding limit/offset
309309
if options[:limit] and options[:offset]
310310
total_rows = select_value("SELECT count(*) as TotalRows from (#{sql.gsub(/\bSELECT(\s+DISTINCT)?\b/i, "SELECT#{$1} TOP 1000000000")}) tally").to_i
311311
if (options[:limit] + options[:offset]) >= total_rows
312312
options[:limit] = (total_rows - options[:offset] >= 0) ? (total_rows - options[:offset]) : 0
313313
end
314+
# Make sure we do not need a special limit/offset for association limiting. http://gist.github.com/25118
315+
add_limit_offset_for_association_limiting!(sql,options) and return if sql_for_association_limiting?(sql)
314316
# Wrap the SQL query in a bunch of outer SQL queries that emulate proper LIMIT,OFFSET support.
315317
sql.sub!(/^\s*SELECT(\s+DISTINCT)?/i, "SELECT * FROM (SELECT TOP #{options[:limit]} * FROM (SELECT#{$1} TOP #{options[:limit] + options[:offset]}")
316318
sql << ") AS tmp1"
@@ -629,6 +631,21 @@ def handle_as_array(handle)
629631
array
630632
end
631633

634+
def add_limit_offset_for_association_limiting!(sql, options)
635+
sql.replace %|
636+
SET NOCOUNT ON
637+
DECLARE @row_number TABLE (row int identity(1,1), id int)
638+
INSERT INTO @row_number (id)
639+
#{sql}
640+
SET NOCOUNT OFF
641+
SELECT id FROM (
642+
SELECT TOP #{options[:limit]} * FROM (
643+
SELECT TOP #{options[:limit] + options[:offset]} * FROM @row_number ORDER BY row
644+
) AS tmp1 ORDER BY row DESC
645+
) AS tmp2 ORDER BY row
646+
|.gsub(/[ \t\r\n]+/,' ')
647+
end
648+
632649
# SCHEMA STATEMENTS ========================================#
633650

634651
def remove_check_constraints(table_name, column_name)
@@ -730,6 +747,13 @@ def order_to_min_set(order)
730747
end.join(', ')
731748
end
732749

750+
def sql_for_association_limiting?(sql)
751+
if md = sql.match(/^\s*SELECT(.*)FROM.*GROUP BY.*ORDER BY.*/im)
752+
select_froms = md[1].split(',')
753+
select_froms.size == 1 && !select_froms.first.include?('*')
754+
end
755+
end
756+
733757
def remove_sqlserver_columns_cache_for(table_name)
734758
cache_key = unqualify_table_name(table_name)
735759
@sqlserver_columns_cache[cache_key] = nil

test/cases/adapter_test_sqlserver.rb

Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -107,6 +107,27 @@ def setup
107107
assert !@connection.send(:insert_sql?,'SELECT...')
108108
end
109109

110+
context 'for #sql_for_association_limiting?' do
111+
112+
should 'return false for simple selects with no GROUP BY and ORDER BY' do
113+
assert !sql_for_association_limiting?("SELECT * FROM [posts]")
114+
end
115+
116+
should 'return true to single SELECT, ideally a table/primarykey, that also has a GROUP BY and ORDER BY' do
117+
assert sql_for_association_limiting?("SELECT [posts].id FROM...GROUP BY [posts].id ORDER BY MIN(posts.id)")
118+
end
119+
120+
should 'return false to single * wildcard SELECT that also has a GROUP BY and ORDER BY' do
121+
assert !sql_for_association_limiting?("SELECT * FROM...GROUP BY [posts].id ORDER BY MIN(posts.id)")
122+
end
123+
124+
should 'return false to multiple columns in the select even when GROUP BY and ORDER BY are present' do
125+
sql = "SELECT [accounts].credit_limit, firm_id FROM...GROUP BY firm_id ORDER BY firm_id"
126+
assert !sql_for_association_limiting?(sql)
127+
end
128+
129+
end
130+
110131
context 'for #get_table_name' do
111132

112133
should 'return quoted table name from basic INSERT, UPDATE and SELECT statements' do
@@ -334,6 +355,10 @@ def setup
334355

335356
private
336357

358+
def sql_for_association_limiting?(sql)
359+
@connection.send :sql_for_association_limiting?, sql
360+
end
361+
337362
def orders_and_dirs_set(order)
338363
@connection.send :orders_and_dirs_set, order
339364
end

0 commit comments

Comments
 (0)