Skip to content

Commit

Permalink
Browse files Browse the repository at this point in the history
Merge pull request #60 from arkadiyk/master
Better support for MSSQL
  • Loading branch information
tenderlove committed Jun 24, 2011
2 parents 645afa0 + 3da816a commit ec86dea
Show file tree
Hide file tree
Showing 2 changed files with 106 additions and 17 deletions.
68 changes: 59 additions & 9 deletions lib/arel/visitors/mssql.rb
Expand Up @@ -3,21 +3,71 @@ module Visitors
class MSSQL < Arel::Visitors::ToSql class MSSQL < Arel::Visitors::ToSql
private private


def build_subselect key, o # `top` wouldn't really work here. I.e. User.select("distinct first_name").limit(10) would generate
stmt = super # "select top 10 distinct first_name from users", which is invalid query! it should be
core = stmt.cores.first # "select distinct top 10 first_name from users"
core.top = Nodes::Top.new(o.limit.expr) if o.limit def visit_Arel_Nodes_Top o
stmt ""
end end


def visit_Arel_Nodes_Limit o def visit_Arel_Nodes_SelectStatement o
"" if !o.limit && !o.offset
return super o
end

select_order_by = "ORDER BY #{o.orders.map { |x| visit x }.join(', ')}" unless o.orders.empty?

is_select_count = false
sql = o.cores.map { |x|
core_order_by = select_order_by || determine_order_by(x)
if select_count? x
x.projections = [row_num_literal(core_order_by)]
is_select_count = true
else
x.projections << row_num_literal(core_order_by)
end

visit_Arel_Nodes_SelectCore x
}.join

sql = "SELECT _t.* FROM (#{sql}) as _t WHERE #{get_offset_limit_clause(o)}"
# fixme count distinct wouldn't work with limit or offset
sql = "SELECT COUNT(1) as count_id FROM (#{sql}) AS subquery" if is_select_count
sql
end end


def visit_Arel_Nodes_Top o def get_offset_limit_clause o
"TOP #{visit o.expr}" first_row = o.offset ? o.offset.expr.to_i + 1 : 1
last_row = o.limit ? o.limit.expr.to_i - 1 + first_row : nil
if last_row
" _row_num BETWEEN #{first_row} AND #{last_row}"
else
" _row_num >= #{first_row}"
end
end end


def determine_order_by x
unless x.groups.empty?
"ORDER BY #{x.groups.map { |g| visit g }.join ', ' }"
else
"ORDER BY #{find_left_table_pk(x.froms)}"
end
end

def row_num_literal order_by
Nodes::SqlLiteral.new("ROW_NUMBER() OVER (#{order_by}) as _row_num")
end

def select_count? x
x.projections.length == 1 && Arel::Nodes::Count === x.projections.first
end

# fixme raise exception of there is no pk?
# fixme!! Table.primary_key will be depricated. What is the replacement??
def find_left_table_pk o
return visit o.primary_key if o.instance_of? Arel::Table
find_left_table_pk o.left if o.kind_of? Arel::Nodes::Join
end
end end
end end
end end
55 changes: 47 additions & 8 deletions test/visitors/test_mssql.rb
Expand Up @@ -5,21 +5,60 @@ module Visitors
describe 'the mssql visitor' do describe 'the mssql visitor' do
before do before do
@visitor = MSSQL.new Table.engine @visitor = MSSQL.new Table.engine
@table = Arel::Table.new "users"
end end


it 'uses TOP to limit results' do it 'should not modify query if no offset or limit' do
stmt = Nodes::SelectStatement.new stmt = Nodes::SelectStatement.new
stmt.cores.last.top = Nodes::Top.new(1)
sql = @visitor.accept(stmt) sql = @visitor.accept(stmt)
sql.must_be_like "SELECT TOP 1" sql.must_be_like "SELECT"
end end


it 'uses TOP in updates with a limit' do it 'should go over table PK if no .order() or .group()' do
stmt = Nodes::UpdateStatement.new stmt = Nodes::SelectStatement.new
stmt.limit = Nodes::Limit.new(1) stmt.cores.first.from = @table
stmt.key = 'id' stmt.limit = Nodes::Limit.new(10)
sql = @visitor.accept(stmt)
sql.must_be_like "SELECT _t.* FROM (SELECT ROW_NUMBER() OVER (ORDER BY \"users\".\"id\") as _row_num FROM \"users\" ) as _t WHERE _row_num BETWEEN 1 AND 10"
end

it 'should go over query ORDER BY if .order()' do
stmt = Nodes::SelectStatement.new
stmt.limit = Nodes::Limit.new(10)
stmt.orders << Nodes::SqlLiteral.new('order_by')
sql = @visitor.accept(stmt)
sql.must_be_like "SELECT _t.* FROM (SELECT ROW_NUMBER() OVER (ORDER BY order_by) as _row_num) as _t WHERE _row_num BETWEEN 1 AND 10"
end

it 'should go over query GROUP BY if no .order() and there is .group()' do
stmt = Nodes::SelectStatement.new
stmt.cores.first.groups << Nodes::SqlLiteral.new('group_by')
stmt.limit = Nodes::Limit.new(10)
sql = @visitor.accept(stmt)
sql.must_be_like "SELECT _t.* FROM (SELECT ROW_NUMBER() OVER (ORDER BY group_by) as _row_num GROUP BY group_by) as _t WHERE _row_num BETWEEN 1 AND 10"
end

it 'should use BETWEEN if both .limit() and .offset' do
stmt = Nodes::SelectStatement.new
stmt.limit = Nodes::Limit.new(10)
stmt.offset = Nodes::Offset.new(20)
sql = @visitor.accept(stmt)
sql.must_be_like "SELECT _t.* FROM (SELECT ROW_NUMBER() OVER (ORDER BY ) as _row_num) as _t WHERE _row_num BETWEEN 21 AND 30"
end

it 'should use >= if only .offset' do
stmt = Nodes::SelectStatement.new
stmt.offset = Nodes::Offset.new(20)
sql = @visitor.accept(stmt)
sql.must_be_like "SELECT _t.* FROM (SELECT ROW_NUMBER() OVER (ORDER BY ) as _row_num) as _t WHERE _row_num >= 21"
end

it 'should generate subquery for .count' do
stmt = Nodes::SelectStatement.new
stmt.limit = Nodes::Limit.new(10)
stmt.cores.first.projections << Nodes::Count.new('*')
sql = @visitor.accept(stmt) sql = @visitor.accept(stmt)
sql.must_be_like "UPDATE NULL WHERE 'id' IN (SELECT TOP 1 'id' )" sql.must_be_like "SELECT COUNT(1) as count_id FROM (SELECT _t.* FROM (SELECT ROW_NUMBER() OVER (ORDER BY ) as _row_num) as _t WHERE _row_num BETWEEN 1 AND 10) AS subquery"
end end


end end
Expand Down

0 comments on commit ec86dea

Please sign in to comment.