Permalink
Browse files

Add Dataset#cross_apply and Dataset#outer_apply on Microsoft SQL Server

These are join methods, but unlike traditional JOINs, these allow
you to reference other tables already in the dataset (useful
mostly with table returning functions).
  • Loading branch information...
1 parent 5871c4a commit 6928688678d5b7f73adde31a46857afd20fcf752 @jeremyevans committed Mar 26, 2013
Showing with 47 additions and 0 deletions.
  1. +2 −0 CHANGELOG
  2. +24 −0 lib/sequel/adapters/shared/mssql.rb
  3. +21 −0 spec/adapters/mssql_spec.rb
View
2 CHANGELOG
@@ -1,5 +1,7 @@
=== HEAD
+* Add Dataset#cross_apply and Dataset#outer_apply on Microsoft SQL Server (jeremyevans)
+
* Speed up threaded connection pools when :connection_handling=>:queue is used (jeremyevans)
* Allow external connection pool classes to be loaded automatically (jeremyevans)
View
24 lib/sequel/adapters/shared/mssql.rb
@@ -435,6 +435,8 @@ module DatasetMethods
CASE_INSENSITIVE_COLLATION = 'Latin1_General_CI_AS'.freeze
DEFAULT_TIMESTAMP_FORMAT = "'%Y-%m-%dT%H:%M:%S%N%z'".freeze
FORMAT_DATE = "'%Y%m%d'".freeze
+ CROSS_APPLY = 'CROSS APPLY'.freeze
+ OUTER_APPLY = 'OUTER APPLY'.freeze
Sequel::Dataset.def_mutation_method(:disable_insert_output, :output, :module=>self)
@@ -485,6 +487,11 @@ def constant_sql_append(sql, constant)
end
end
+ # Uses CROSS APPLY to join the given table into the current dataset.
+ def cross_apply(table)
+ join_table(:cross_apply, table)
+ end
+
# Disable the use of INSERT OUTPUT
def disable_insert_output
clone(:disable_insert_output=>true)
@@ -546,6 +553,11 @@ def nolock
lock_style(:dirty)
end
+ # Uses OUTER APPLY to join the given table into the current dataset.
+ def outer_apply(table)
+ join_table(:outer_apply, table)
+ end
+
# Include an OUTPUT clause in the eventual INSERT, UPDATE, or DELETE query.
#
# The first argument is the table to output into, and the second argument
@@ -729,6 +741,18 @@ def insert_output_sql(sql)
end
end
+ # Handle CROSS APPLY and OUTER APPLY JOIN types
+ def join_type_sql(join_type)
+ case join_type
+ when :cross_apply
+ CROSS_APPLY
+ when :outer_apply
+ OUTER_APPLY
+ else
+ super
+ end
+ end
+
# MSSQL uses a literal hexidecimal number for blob strings
def literal_blob_append(sql, v)
sql << HEX_START << v.unpack(HSTAR).first
View
21 spec/adapters/mssql_spec.rb
@@ -55,6 +55,27 @@ def logger.method_missing(m, msg)
end
end
+describe "MSSQL" do
+ before(:all) do
+ @db = MSSQL_DB
+ @db.create_table!(:test3){Integer :v3}
+ @db.create_table!(:test4){Integer :v4}
+ @db[:test3].import([:v3], [[1], [2]])
+ @db[:test4].import([:v4], [[1], [3]])
+ end
+ after(:all) do
+ @db.drop_table?(:test3, :test4)
+ end
+
+ specify "should should support CROSS APPLY" do
+ @db[:test3].cross_apply(@db[:test4].where(:test3__v3=>:test4__v4)).select_order_map([:v3, :v4]).should == [[1,1]]
+ end
+
+ specify "should should support OUTER APPLY" do
+ @db[:test3].outer_apply(@db[:test4].where(:test3__v3=>:test4__v4)).select_order_map([:v3, :v4]).should == [[1,1], [2, nil]]
+ end
+end
+
# This spec is currently disabled as the SQL Server 2008 R2 Express doesn't support
# full text searching. Even if full text searching is supported,
# you may need to create a full text catalog on the database first via:

3 comments on commit 6928688

@jeltz

The SQL standard version of CROSS APPLY and OUTER APPLY is called LATERAL. Would it be interesting to have a method which generates CROSS APPLY/OUTER APPLY or LATERAL depending on database engine?

@jeremyevans

I plan to add support for LATERAL at some point in the future. If it's possible to automatically translate LATERAL into CROSS/OUTER APPLY with 100% accuracy, then I'll do that on MSSQL. I haven't done the necessary research yet to see if that is possible, and haven't decided on an API for LATERAL yet.

@jeltz

They look very similar in all examples I have seen but the devil is in the details. Keep up the good work!

Please sign in to comment.