|
| 1 | +module ActiveRecord |
| 2 | + module ConnectionAdapters |
| 3 | + module Sqlserver |
| 4 | + module DatabaseStatements |
| 5 | + |
| 6 | + def select_rows(sql, name = nil) |
| 7 | + raw_select(sql,name).first.last |
| 8 | + end |
| 9 | + |
| 10 | + def execute(sql, name = nil, skip_logging = false) |
| 11 | + if table_name = query_requires_identity_insert?(sql) |
| 12 | + with_identity_insert_enabled(table_name) { do_execute(sql,name) } |
| 13 | + else |
| 14 | + do_execute(sql,name) |
| 15 | + end |
| 16 | + end |
| 17 | + |
| 18 | + def outside_transaction? |
| 19 | + info_schema_query { select_value("SELECT @@TRANCOUNT") == 0 } |
| 20 | + end |
| 21 | + |
| 22 | + def begin_db_transaction |
| 23 | + do_execute "BEGIN TRANSACTION" |
| 24 | + end |
| 25 | + |
| 26 | + def commit_db_transaction |
| 27 | + do_execute "COMMIT TRANSACTION" |
| 28 | + end |
| 29 | + |
| 30 | + def rollback_db_transaction |
| 31 | + do_execute "ROLLBACK TRANSACTION" rescue nil |
| 32 | + end |
| 33 | + |
| 34 | + def create_savepoint |
| 35 | + do_execute "SAVE TRANSACTION #{current_savepoint_name}" |
| 36 | + end |
| 37 | + |
| 38 | + def release_savepoint |
| 39 | + end |
| 40 | + |
| 41 | + def rollback_to_savepoint |
| 42 | + do_execute "ROLLBACK TRANSACTION #{current_savepoint_name}" |
| 43 | + end |
| 44 | + |
| 45 | + def add_limit_offset!(sql, options) |
| 46 | + # Validate and/or convert integers for :limit and :offets options. |
| 47 | + if options[:offset] |
| 48 | + raise ArgumentError, "offset should have a limit" unless options[:limit] |
| 49 | + unless options[:offset].kind_of?(Integer) |
| 50 | + if options[:offset] =~ /^\d+$/ |
| 51 | + options[:offset] = options[:offset].to_i |
| 52 | + else |
| 53 | + raise ArgumentError, "offset should be an integer" |
| 54 | + end |
| 55 | + end |
| 56 | + end |
| 57 | + if options[:limit] && !(options[:limit].kind_of?(Integer)) |
| 58 | + if options[:limit] =~ /^\d+$/ |
| 59 | + options[:limit] = options[:limit].to_i |
| 60 | + else |
| 61 | + raise ArgumentError, "limit should be an integer" |
| 62 | + end |
| 63 | + end |
| 64 | + # The business of adding limit/offset |
| 65 | + if options[:limit] and options[:offset] |
| 66 | + tally_sql = "SELECT count(*) as TotalRows from (#{sql.sub(/\bSELECT(\s+DISTINCT)?\b/i, "SELECT#{$1} TOP 1000000000")}) tally" |
| 67 | + add_lock! tally_sql, options |
| 68 | + total_rows = select_value(tally_sql).to_i |
| 69 | + if (options[:limit] + options[:offset]) >= total_rows |
| 70 | + options[:limit] = (total_rows - options[:offset] >= 0) ? (total_rows - options[:offset]) : 0 |
| 71 | + end |
| 72 | + # Make sure we do not need a special limit/offset for association limiting. http://gist.github.com/25118 |
| 73 | + add_limit_offset_for_association_limiting!(sql,options) and return if sql_for_association_limiting?(sql) |
| 74 | + # Wrap the SQL query in a bunch of outer SQL queries that emulate proper LIMIT,OFFSET support. |
| 75 | + sql.sub!(/^\s*SELECT(\s+DISTINCT)?/i, "SELECT * FROM (SELECT TOP #{options[:limit]} * FROM (SELECT#{$1} TOP #{options[:limit] + options[:offset]}") |
| 76 | + sql << ") AS tmp1" |
| 77 | + if options[:order] |
| 78 | + order = options[:order].split(',').map do |field| |
| 79 | + order_by_column, order_direction = field.split(" ") |
| 80 | + order_by_column = quote_column_name(order_by_column) |
| 81 | + # Investigate the SQL query to figure out if the order_by_column has been renamed. |
| 82 | + if sql =~ /#{Regexp.escape(order_by_column)} AS (t\d+_r\d+)/ |
| 83 | + # Fx "[foo].[bar] AS t4_r2" was found in the SQL. Use the column alias (ie 't4_r2') for the subsequent orderings |
| 84 | + order_by_column = $1 |
| 85 | + elsif order_by_column =~ /\w+\.\[?(\w+)\]?/ |
| 86 | + order_by_column = $1 |
| 87 | + else |
| 88 | + # It doesn't appear that the column name has been renamed as part of the query. Use just the column |
| 89 | + # name rather than the full identifier for the outer queries. |
| 90 | + order_by_column = order_by_column.split('.').last |
| 91 | + end |
| 92 | + # Put the column name and eventual direction back together |
| 93 | + [order_by_column, order_direction].join(' ').strip |
| 94 | + end.join(', ') |
| 95 | + sql << " ORDER BY #{change_order_direction(order)}) AS tmp2 ORDER BY #{order}" |
| 96 | + else |
| 97 | + sql << ") AS tmp2" |
| 98 | + end |
| 99 | + elsif options[:limit] && sql !~ /^\s*SELECT (@@|COUNT\()/i |
| 100 | + if md = sql.match(/^(\s*SELECT)(\s+DISTINCT)?(.*)/im) |
| 101 | + sql.replace "#{md[1]}#{md[2]} TOP #{options[:limit]}#{md[3]}" |
| 102 | + else |
| 103 | + # Account for building SQL fragments without SELECT yet. See #update_all and #limited_update_conditions. |
| 104 | + sql.replace "TOP #{options[:limit]} #{sql}" |
| 105 | + end |
| 106 | + end |
| 107 | + end |
| 108 | + |
| 109 | + def empty_insert_statement(table_name) |
| 110 | + "INSERT INTO #{quote_table_name(table_name)} DEFAULT VALUES" |
| 111 | + end |
| 112 | + |
| 113 | + def case_sensitive_equality_operator |
| 114 | + "COLLATE Latin1_General_CS_AS =" |
| 115 | + end |
| 116 | + |
| 117 | + def limited_update_conditions(where_sql, quoted_table_name, quoted_primary_key) |
| 118 | + match_data = where_sql.match(/^(.*?[\]\) ])WHERE[\[\( ]/) |
| 119 | + limit = match_data[1] |
| 120 | + where_sql.sub!(limit,'') |
| 121 | + "WHERE #{quoted_primary_key} IN (SELECT #{limit} #{quoted_primary_key} FROM #{quoted_table_name} #{where_sql})" |
| 122 | + end |
| 123 | + |
| 124 | + # === SQLServer Specific ======================================== # |
| 125 | + |
| 126 | + def execute_procedure(proc_name, *variables) |
| 127 | + vars = variables.map{ |v| quote(v) }.join(', ') |
| 128 | + sql = "EXEC #{proc_name} #{vars}".strip |
| 129 | + select(sql,'Execute Procedure',true).inject([]) do |results,row| |
| 130 | + if row.kind_of?(Array) |
| 131 | + results << row.inject([]) { |rs,r| rs << r.with_indifferent_access } |
| 132 | + else |
| 133 | + results << row.with_indifferent_access |
| 134 | + end |
| 135 | + end |
| 136 | + end |
| 137 | + |
| 138 | + def use_database(database=nil) |
| 139 | + database ||= @connection_options[:database] |
| 140 | + do_execute "USE #{quote_table_name(database)}" unless database.blank? |
| 141 | + end |
| 142 | + |
| 143 | + def user_options |
| 144 | + info_schema_query do |
| 145 | + select_rows("dbcc useroptions").inject(HashWithIndifferentAccess.new) do |values,row| |
| 146 | + set_option = row[0].gsub(/\s+/,'_') |
| 147 | + user_value = row[1] |
| 148 | + values[set_option] = user_value |
| 149 | + values |
| 150 | + end |
| 151 | + end |
| 152 | + end |
| 153 | + |
| 154 | + def run_with_isolation_level(isolation_level) |
| 155 | + raise ArgumentError, "Invalid isolation level, #{isolation_level}. Supported levels include #{valid_isolation_levels.to_sentence}." if !valid_isolation_levels.include?(isolation_level.upcase) |
| 156 | + initial_isolation_level = user_options[:isolation_level] || "READ COMMITTED" |
| 157 | + do_execute "SET TRANSACTION ISOLATION LEVEL #{isolation_level}" |
| 158 | + begin |
| 159 | + yield |
| 160 | + ensure |
| 161 | + do_execute "SET TRANSACTION ISOLATION LEVEL #{initial_isolation_level}" |
| 162 | + end if block_given? |
| 163 | + end |
| 164 | + |
| 165 | + |
| 166 | + protected |
| 167 | + |
| 168 | + def select(sql, name = nil, ignore_special_columns = false) |
| 169 | + repair_special_columns(sql) unless ignore_special_columns |
| 170 | + fields_and_row_sets = raw_select(sql,name) |
| 171 | + final_result_set = fields_and_row_sets.inject([]) do |rs,fields_and_rows| |
| 172 | + fields, rows = fields_and_rows |
| 173 | + rs << zip_fields_and_rows(fields,rows) |
| 174 | + end |
| 175 | + final_result_set.many? ? final_result_set : final_result_set.first |
| 176 | + end |
| 177 | + |
| 178 | + def insert_sql(sql, name = nil, pk = nil, id_value = nil, sequence_name = nil) |
| 179 | + super || select_value("SELECT SCOPE_IDENTITY() AS Ident") |
| 180 | + end |
| 181 | + |
| 182 | + def update_sql(sql, name = nil) |
| 183 | + execute(sql, name) |
| 184 | + select_value('SELECT @@ROWCOUNT AS AffectedRows') |
| 185 | + end |
| 186 | + |
| 187 | + # === SQLServer Specific ======================================== # |
| 188 | + |
| 189 | + def valid_isolation_levels |
| 190 | + ["READ COMMITTED", "READ UNCOMMITTED", "REPEATABLE READ", "SERIALIZABLE", "SNAPSHOT"] |
| 191 | + end |
| 192 | + |
| 193 | + def zip_fields_and_rows(fields, rows) |
| 194 | + rows.inject([]) do |results,row| |
| 195 | + row_hash = {} |
| 196 | + fields.each_with_index do |f, i| |
| 197 | + row_hash[f] = row[i] |
| 198 | + end |
| 199 | + results << row_hash |
| 200 | + end |
| 201 | + end |
| 202 | + |
| 203 | + def info_schema_query |
| 204 | + log_info_schema_queries ? yield : ActiveRecord::Base.silence{ yield } |
| 205 | + end |
| 206 | + |
| 207 | + def do_execute(sql,name=nil) |
| 208 | + log(sql, name || 'EXECUTE') do |
| 209 | + with_auto_reconnect { raw_connection_do(sql) } |
| 210 | + end |
| 211 | + end |
| 212 | + |
| 213 | + def raw_select(sql, name = nil) |
| 214 | + fields_and_row_sets = [] |
| 215 | + log(sql,name) do |
| 216 | + begin |
| 217 | + handle = raw_connection_run(sql) |
| 218 | + loop do |
| 219 | + fields_and_rows = case connection_mode |
| 220 | + when :odbc |
| 221 | + handle_to_fields_and_rows_odbc(handle) |
| 222 | + when :adonet |
| 223 | + handle_to_fields_and_rows_adonet(handle) |
| 224 | + end |
| 225 | + fields_and_row_sets << fields_and_rows |
| 226 | + break unless handle_more_results?(handle) |
| 227 | + end |
| 228 | + ensure |
| 229 | + finish_statement_handle(handle) |
| 230 | + end |
| 231 | + end |
| 232 | + fields_and_row_sets |
| 233 | + end |
| 234 | + |
| 235 | + def handle_more_results?(handle) |
| 236 | + case connection_mode |
| 237 | + when :odbc |
| 238 | + handle.more_results |
| 239 | + when :adonet |
| 240 | + handle.next_result |
| 241 | + end |
| 242 | + end |
| 243 | + |
| 244 | + def handle_to_fields_and_rows_odbc(handle) |
| 245 | + fields = handle.columns(true).map { |c| c.name } |
| 246 | + results = handle.inject([]) do |rows,row| |
| 247 | + rows << row.inject([]) { |values,value| values << value } |
| 248 | + end |
| 249 | + rows = results.inject([]) do |rows,row| |
| 250 | + row.each_with_index do |value, i| |
| 251 | + if value.is_a? ODBC::TimeStamp |
| 252 | + row[i] = value.to_sqlserver_string |
| 253 | + end |
| 254 | + end |
| 255 | + rows << row |
| 256 | + end |
| 257 | + [fields,rows] |
| 258 | + end |
| 259 | + |
| 260 | + def handle_to_fields_and_rows_adonet(handle) |
| 261 | + if handle.has_rows |
| 262 | + fields = [] |
| 263 | + rows = [] |
| 264 | + fields_named = false |
| 265 | + while handle.read |
| 266 | + row = [] |
| 267 | + handle.visible_field_count.times do |row_index| |
| 268 | + value = handle.get_value(row_index) |
| 269 | + value = if value.is_a? System::String |
| 270 | + value.to_s |
| 271 | + elsif value.is_a? System::DBNull |
| 272 | + nil |
| 273 | + elsif value.is_a? System::DateTime |
| 274 | + value.to_string("yyyy-MM-dd HH:MM:ss.fff").to_s |
| 275 | + else |
| 276 | + value |
| 277 | + end |
| 278 | + row << value |
| 279 | + fields << handle.get_name(row_index).to_s unless fields_named |
| 280 | + end |
| 281 | + rows << row |
| 282 | + fields_named = true |
| 283 | + end |
| 284 | + else |
| 285 | + fields, rows = [], [] |
| 286 | + end |
| 287 | + [fields,rows] |
| 288 | + end |
| 289 | + |
| 290 | + def add_lock!(sql, options) |
| 291 | + # http://blog.sqlauthority.com/2007/04/27/sql-server-2005-locking-hints-and-examples/ |
| 292 | + return unless options[:lock] |
| 293 | + lock_type = options[:lock] == true ? 'WITH(HOLDLOCK, ROWLOCK)' : options[:lock] |
| 294 | + sql.gsub! %r|LEFT OUTER JOIN\s+(.*?)\s+ON|im, "LEFT OUTER JOIN \\1 #{lock_type} ON" |
| 295 | + sql.gsub! %r{FROM\s([\w\[\]\.]+)}im, "FROM \\1 #{lock_type}" |
| 296 | + end |
| 297 | + |
| 298 | + def add_limit_offset_for_association_limiting!(sql, options) |
| 299 | + sql.replace %| |
| 300 | + SET NOCOUNT ON |
| 301 | + DECLARE @row_number TABLE (row int identity(1,1), id int) |
| 302 | + INSERT INTO @row_number (id) |
| 303 | + #{sql} |
| 304 | + SET NOCOUNT OFF |
| 305 | + SELECT id FROM ( |
| 306 | + SELECT TOP #{options[:limit]} * FROM ( |
| 307 | + SELECT TOP #{options[:limit] + options[:offset]} * FROM @row_number ORDER BY row |
| 308 | + ) AS tmp1 ORDER BY row DESC |
| 309 | + ) AS tmp2 ORDER BY row |
| 310 | + |.gsub(/[ \t\r\n]+/,' ') |
| 311 | + end |
| 312 | + |
| 313 | + end |
| 314 | + end |
| 315 | + end |
| 316 | +end |
0 commit comments