@@ -55,6 +55,27 @@ def self.sqlserver_connection(config) #:nodoc:
5555
5656 private
5757
58+ # Add basic support for SQL server locking hints
59+ # In the case of SQL server, the lock value must follow the FROM clause
60+ # Mysql: SELECT * FROM tst where testID = 10 LOCK IN share mode
61+ # SQLServer: SELECT * from tst WITH (HOLDLOCK, ROWLOCK) where testID = 10
62+ def self . construct_finder_sql ( options )
63+ scope = scope ( :find )
64+ sql = "SELECT #{ options [ :select ] || ( scope && scope [ :select ] ) || ( ( options [ :joins ] || ( scope && scope [ :joins ] ) ) && quoted_table_name + '.*' ) || '*' } "
65+ sql << "FROM #{ ( scope && scope [ :from ] ) || options [ :from ] || quoted_table_name } "
66+
67+ add_lock! ( sql , options , scope ) if ActiveRecord ::Base . connection . adapter_name == "SQLServer" && !options [ :lock ] . blank? # SQLServer
68+
69+ add_joins! ( sql , options , scope )
70+ add_conditions! ( sql , options [ :conditions ] , scope )
71+
72+ add_group! ( sql , options [ :group ] , scope )
73+ add_order! ( sql , options [ :order ] , scope )
74+ add_limit! ( sql , options , scope )
75+ add_lock! ( sql , options , scope ) unless ActiveRecord ::Base . connection . adapter_name == "SQLServer" # Not SQLServer
76+ sql
77+ end
78+
5879 # Overwrite the ActiveRecord::Base method for SQL server.
5980 # GROUP BY is necessary for distinct orderings
6081 def self . construct_finder_sql_for_association_limiting ( options , join_dependency )
@@ -179,14 +200,20 @@ def string_to_time(value)
179200 end
180201 end
181202
182- # These methods will only allow the adapter to insert binary data with a length of 7K or less
183- # because of a SQL Server statement length policy.
203+ # To insert into a SQL server binary column, the value must be
204+ # converted to hex characters and prepended with 0x
205+ # Example: INSERT into varbinarytable values (0x0)
206+ # See the output of the stored procedure: 'exec sp_datatype_info'
207+ # and note the literal prefix value of 0x for binary types
184208 def string_to_binary ( value )
185- Base64 . encode64 ( value )
209+ "0x #{ value . unpack ( "H*" ) [ 0 ] } "
186210 end
187211
188212 def binary_to_string ( value )
189- Base64 . decode64 ( value )
213+ # Check if the value actually is hex output from the database
214+ # or an Active Record attribute that was just written. If hex, pack the hex
215+ # characters into a string, otherwise return the value
216+ value =~ /[^[:xdigit:]]/ ? value : [ value ] . pack ( 'H*' )
190217 end
191218
192219 protected
@@ -245,12 +272,21 @@ class SQLServerAdapter < AbstractAdapter
245272 def initialize ( connection , logger , connection_options = nil )
246273 super ( connection , logger )
247274 @connection_options = connection_options
275+ if database_version =~ /(2000|2005) - (\d +)\. /
276+ @database_version_year = $1. to_i
277+ @database_version_major = $2. to_i
278+ else
279+ raise "Currently, only 2000 and 2005 are supported versions"
280+ end
281+
248282 end
249283
250284 def native_database_types
251285 # support for varchar(max) and varbinary(max) for text and binary cols if our version is 9 (2005)
252- txt = database_version_major >= 9 ? "varchar(max)" : "text"
253- bin = database_version_major >= 9 ? "varbinary(max)" : "image"
286+ txt = @database_version_major >= 9 ? "varchar(max)" : "text"
287+
288+ # TODO: Need to verify image column works correctly with 2000 if string_to_binary stores a hex string
289+ bin = @database_version_major >= 9 ? "varbinary(max)" : "image"
254290 {
255291 :primary_key => "int NOT NULL IDENTITY(1, 1) PRIMARY KEY" ,
256292 :string => { :name => "varchar" , :limit => 255 } ,
@@ -276,23 +312,18 @@ def database_version
276312 # "Microsoft SQL Server 2000 - 8.00.2039 (Intel X86) \n\tMay 3 2005 23:18:38 \n\tCopyright (c) 1988-2003 Microsoft Corporation\n\tEnterprise Edition on Windows NT 5.2 (Build 3790: )\n"
277313 # "Microsoft SQL Server 2005 - 9.00.3215.00 (Intel X86) \n\tDec 8 2007 18:51:32 \n\tCopyright (c) 1988-2005 Microsoft Corporation\n\tStandard Edition on Windows NT 5.2 (Build 3790: Service Pack 2)\n"
278314 return select_value ( "SELECT @@version" )
279- end
280-
281- def database_version_year
282- # returns 2000 or 2005
283- return $1. to_i if database_version =~ /(2000|2005) - (\d +)\. /
284- end
285-
286- def database_version_major
287- # returns 8 or 9
288- return $2. to_i if database_version =~ /(2000|2005) - (\d +)\. /
289- end
315+ end
290316
291317 def supports_migrations? #:nodoc:
292318 true
293319 end
294320
295321 def type_to_sql ( type , limit = nil , precision = nil , scale = nil ) #:nodoc:
322+ # Remove limit for data types which do not require it
323+ # Valid: ALTER TABLE sessions ALTER COLUMN [data] varchar(max)
324+ # Invalid: ALTER TABLE sessions ALTER COLUMN [data] varchar(max)(16777215)
325+ limit = nil if %w{ text varchar(max) nvarchar(max) ntext varbinary(max) image } . include? ( native_database_types [ type . to_sym ] [ :name ] )
326+
296327 return super unless type . to_s == 'integer'
297328
298329 if limit . nil?
@@ -468,6 +499,13 @@ def quote(value, column = nil)
468499 case value
469500 when TrueClass then '1'
470501 when FalseClass then '0'
502+
503+ when String , ActiveSupport ::Multibyte ::Chars
504+ value = value . to_s
505+
506+ # for binary columns, don't quote the result of the string to binary
507+ return column . class . string_to_binary ( value ) if column && column . type == :binary && column . class . respond_to? ( :string_to_binary )
508+ super
471509 else
472510 if value . acts_like? ( :time )
473511 "'#{ value . strftime ( "%Y%m%d %H:%M:%S" ) } '"
@@ -485,16 +523,27 @@ def quote_string(string)
485523
486524 def quote_table_name ( name )
487525 name_split_on_dots = name . to_s . split ( '.' )
526+
488527 if name_split_on_dots . length == 3
528+ # name is on the form "foo.bar.baz"
489529 "[#{ name_split_on_dots [ 0 ] } ].[#{ name_split_on_dots [ 1 ] } ].[#{ name_split_on_dots [ 2 ] } ]"
490530 else
491531 super ( name )
492532 end
493533
494534 end
495535
496- def quote_column_name ( name )
497- "[#{ name } ]"
536+ # Quotes the given column identifier.
537+ #
538+ # Examples
539+ #
540+ # quote_column_name('foo') # => '[foo]'
541+ # quote_column_name(:foo) # => '[foo]'
542+ # quote_column_name('foo.bar') # => '[foo].[bar]'
543+ def quote_column_name ( identifier )
544+ identifier . to_s . split ( '.' ) . collect do |name |
545+ "[#{ name } ]"
546+ end . join ( "." )
498547 end
499548
500549 def add_limit_offset! ( sql , options )
@@ -523,26 +572,32 @@ def add_limit_offset!(sql, options)
523572 if ( options [ :limit ] + options [ :offset ] ) >= total_rows
524573 options [ :limit ] = ( total_rows - options [ :offset ] >= 0 ) ? ( total_rows - options [ :offset ] ) : 0
525574 end
575+
576+ # Wrap the SQL query in a bunch of outer SQL queries that emulate proper LIMIT,OFFSET support.
526577 sql . sub! ( /^\s *SELECT(\s +DISTINCT)?/i , "SELECT * FROM (SELECT TOP #{ options [ :limit ] } * FROM (SELECT#{ $1} TOP #{ options [ :limit ] + options [ :offset ] } " )
527578 sql << ") AS tmp1"
579+
528580 if options [ :order ]
529- # don't strip the table name, it is needed later on
530- #options[:order] = options[:order].split(',').map do |field|
531581 order = options [ :order ] . split ( ',' ) . map do |field |
532- parts = field . split ( " " )
533- # tc = column_name etc (not direction of sort)
534- tc = parts [ 0 ]
535- #if sql =~ /\.\[/ and tc =~ /\./ # if column quoting used in query
536- # tc.gsub!(/\./, '\\.\\[')
537- # tc << '\\]'
538- #end
539- if sql =~ /#{ Regexp . escape ( tc ) } AS (t\d _r\d \d ?)/
540- parts [ 0 ] = $1
541- elsif parts [ 0 ] =~ /\w +\. \[ ?(\w +)\] ?/
542- parts [ 0 ] = $1
582+ order_by_column , order_direction = field . split ( " " )
583+ order_by_column = quote_column_name ( order_by_column )
584+
585+ # Investigate the SQL query to figure out if the order_by_column has been renamed.
586+ if sql =~ /#{ Regexp . escape ( order_by_column ) } AS (t\d _r\d \d ?)/
587+ # Fx "[foo].[bar] AS t4_r2" was found in the SQL. Use the column alias (ie 't4_r2') for the subsequent orderings
588+ order_by_column = $1
589+ elsif order_by_column =~ /\w +\. \[ ?(\w +)\] ?/
590+ order_by_column = $1
591+ else
592+ # It doesn't appear that the column name has been renamed as part of the query. Use just the column
593+ # name rather than the full identifier for the outer queries.
594+ order_by_column = order_by_column . split ( '.' ) . last
543595 end
544- parts . join ( ' ' )
596+
597+ # Put the column name and eventual direction back together
598+ [ order_by_column , order_direction ] . join ( ' ' ) . strip
545599 end . join ( ', ' )
600+
546601 sql << " ORDER BY #{ change_order_direction ( order ) } ) AS tmp2 ORDER BY #{ order } "
547602 else
548603 sql << ") AS tmp2"
@@ -578,18 +633,58 @@ def add_order_by_for_association_limiting!(sql, options)
578633 sql << " ORDER BY #{ order . join ( ',' ) } "
579634 end
580635
636+ # Appends a locking clause to an SQL statement.
637+ # This method *modifies* the +sql+ parameter.
638+ # # SELECT * FROM suppliers FOR UPDATE
639+ # add_lock! 'SELECT * FROM suppliers', :lock => true
640+ # add_lock! 'SELECT * FROM suppliers', :lock => ' WITH(HOLDLOCK, ROWLOCK)'
641+ # http://blog.sqlauthority.com/2007/04/27/sql-server-2005-locking-hints-and-examples/
581642 def add_lock! ( sql , options )
582- @logger . info "Warning: SQLServer :lock option '#{ options [ :lock ] . inspect } ' not supported" if @logger && options . has_key? ( :lock )
583- sql
643+ case lock = options [ :lock ]
644+ when true then sql << "WITH(HOLDLOCK, ROWLOCK) "
645+ when String then sql << "#{ lock } "
646+ end
584647 end
585648
586- def recreate_database ( name )
649+ def recreate_database ( name )
650+ # Switch to another database or we'll receive a "Database in use" error message.
651+ existing_database = current_database . to_s
652+ if name . to_s == existing_database
653+ # The master database should be available on all SQL Server instances, use that
654+ execute 'USE master'
655+ end
656+
657+ # Recreate the database
587658 drop_database ( name )
588659 create_database ( name )
660+
661+ # Switch back to the database if we switched away from it above
662+ execute "USE #{ existing_database } " if name . to_s == existing_database
589663 end
590664
665+ def remove_database_connections_and_rollback ( name )
666+ # This should disconnect all other users and rollback any transactions for SQL 2000 and 2005
667+ # http://sqlserver2000.databases.aspfaq.com/how-do-i-drop-a-sql-server-database.html
668+ execute "ALTER DATABASE #{ name } SET SINGLE_USER WITH ROLLBACK IMMEDIATE"
669+ end
670+
591671 def drop_database ( name )
592- execute "DROP DATABASE #{ name } "
672+ retry_count = 0
673+ max_retries = 1
674+ begin
675+ execute "DROP DATABASE #{ name } "
676+ rescue ActiveRecord ::StatementInvalid => err
677+ # Remove existing connections and rollback any transactions if we received the message
678+ # 'Cannot drop the database 'test' because it is currently in use'
679+ if err . message =~ /because it is currently in use/
680+ raise if retry_count >= max_retries
681+ retry_count += 1
682+ remove_database_connections_and_rollback ( name )
683+ retry
684+ else
685+ raise
686+ end
687+ end
593688 end
594689
595690 # Clear the given table and reset the table's id to 1
@@ -758,7 +853,7 @@ def get_table_name(sql)
758853 end
759854
760855 def identity_column ( table_name )
761- @table_columns = { } unless @table_columns
856+ @table_columns || = { }
762857 @table_columns [ table_name ] = columns ( table_name ) if @table_columns [ table_name ] == nil
763858 @table_columns [ table_name ] . each do |col |
764859 return col . name if col . identity
0 commit comments