Module: ActiveRecord::ConnectionAdapters::SQLServer::SchemaStatements

Included in:
ActiveRecord::ConnectionAdapters::SQLServerAdapter
Defined in:
lib/active_record/connection_adapters/sqlserver/schema_statements.rb

Instance Method Summary collapse

Instance Method Details

#add_timestamps(table_name, **options) ⇒ Object

In SQL Server only the first column added should have the ‘ADD` keyword.



342
343
344
345
346
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 342

def add_timestamps(table_name, **options)
  fragments = add_timestamps_for_alter(table_name, **options)
  fragments[1..].each { |fragment| fragment.sub!('ADD ', '') }
  execute "ALTER TABLE #{quote_table_name(table_name)} #{fragments.join(', ')}"
end

#build_change_column_default_definition(table_name, column_name, default_or_changes) ⇒ Object

:nodoc:



230
231
232
233
234
235
236
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 230

def build_change_column_default_definition(table_name, column_name, default_or_changes) # :nodoc:
  column = column_for(table_name, column_name)
  return unless column

  default = extract_new_default_value(default_or_changes)
  ChangeColumnDefaultDefinition.new(column, default)
end

#build_change_column_definition(table_name, column_name, type, **options) ⇒ Object

:nodoc:



224
225
226
227
228
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 224

def build_change_column_definition(table_name, column_name, type, **options) # :nodoc:
  td = create_table_definition(table_name)
  cd = td.new_column_definition(column_name, type, **options)
  ChangeColumnDefinition.new(cd, column_name)
end

#change_column(table_name, column_name, type, options = {}) ⇒ Object



148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 148

def change_column(table_name, column_name, type, options = {})
  sql_commands = []
  indexes = []

  if type == :datetime
    # If no precision then default it to 6.
    options[:precision] = 6 unless options.key?(:precision)

    # If there is precision then column must be of type 'datetime2'.
    type = :datetime2 unless options[:precision].nil?
  end

  column_object = schema_cache.columns(table_name).find { |c| c.name.to_s == column_name.to_s }
  without_constraints = options.key?(:default) || options.key?(:limit)
  default = if !options.key?(:default) && column_object
              column_object.default
            else
              options[:default]
            end

  if without_constraints || (column_object && column_object.type != type.to_sym)
    remove_default_constraint(table_name, column_name)
    indexes = indexes(table_name).select { |index| index.columns.include?(column_name.to_s) }
    remove_indexes(table_name, column_name)
  end

  sql_commands << "UPDATE #{quote_table_name(table_name)} SET #{quote_column_name(column_name)}=#{quote_default_expression(options[:default], column_object)} WHERE #{quote_column_name(column_name)} IS NULL" if !options[:null].nil? && options[:null] == false && !options[:default].nil?
  alter_command = "ALTER TABLE #{quote_table_name(table_name)} ALTER COLUMN #{quote_column_name(column_name)} #{type_to_sql(type, limit: options[:limit], precision: options[:precision], scale: options[:scale])}"
  alter_command += " COLLATE #{options[:collation]}" if options[:collation].present?
  alter_command += " NOT NULL" if !options[:null].nil? && options[:null] == false
  sql_commands << alter_command

  if without_constraints
    default = quote_default_expression(default, column_object || column_for(table_name, column_name))
    sql_commands << "ALTER TABLE #{quote_table_name(table_name)} ADD CONSTRAINT #{default_constraint_name(table_name, column_name)} DEFAULT #{default} FOR #{quote_column_name(column_name)}"
  end

  # Add any removed indexes back
  indexes.each do |index|
    sql_commands << "CREATE INDEX #{quote_table_name(index.name)} ON #{quote_table_name(table_name)} (#{index.columns.map { |c| quote_column_name(c) }.join(', ')})"
  end

  sql_commands.each { |c| execute(c) }
  clear_cache!
end

#change_column_default(table_name, column_name, default_or_changes) ⇒ Object



194
195
196
197
198
199
200
201
202
203
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 194

def change_column_default(table_name, column_name, default_or_changes)
  clear_cache!
  column = column_for(table_name, column_name)
  return unless column

  remove_default_constraint(table_name, column_name)
  default = extract_new_default_value(default_or_changes)
  execute "ALTER TABLE #{quote_table_name(table_name)} ADD CONSTRAINT #{default_constraint_name(table_name, column_name)} DEFAULT #{quote_default_expression(default, column)} FOR #{quote_column_name(column_name)}"
  clear_cache!
end

#change_column_null(table_name, column_name, null, default = nil) ⇒ Object



362
363
364
365
366
367
368
369
370
371
372
373
374
375
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 362

def change_column_null(table_name, column_name, null, default = nil)
  validate_change_column_null_argument!(null)

  table_id = SQLServer::Utils.extract_identifiers(table_name)
  column_id = SQLServer::Utils.extract_identifiers(column_name)
  column = column_for(table_name, column_name)
  if !null.nil? && null == false && !default.nil?
    execute("UPDATE #{table_id} SET #{column_id}=#{quote(default)} WHERE #{column_id} IS NULL")
  end
  sql = "ALTER TABLE #{table_id} ALTER COLUMN #{column_id} #{type_to_sql column.type, limit: column.limit, precision: column.precision, scale: column.scale}"
  sql += " NOT NULL" if !null.nil? && null == false

  execute sql
end

#change_table_schema(schema_name, table_name) ⇒ Object



388
389
390
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 388

def change_table_schema(schema_name, table_name)
  execute "ALTER SCHEMA [#{schema_name}] TRANSFER [#{table_name}]"
end

#check_constraints(table_name) ⇒ Object



270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 270

def check_constraints(table_name)
  sql = <<~SQL
    select chk.name AS 'name',
           chk.definition AS 'expression'
    from sys.check_constraints chk
    inner join sys.tables st on chk.parent_object_id = st.object_id
    where
    st.name = '#{table_name}'
  SQL

  chk_info = internal_exec_query(sql, "SCHEMA")

  chk_info.map do |row|
    options = {
      name: row["name"]
    }
    expression = row["expression"]
    expression = expression[1..-2] if expression.start_with?("(") && expression.end_with?(")")

    CheckConstraintDefinition.new(table_name, expression, options)
  end
end

#columns(table_name) ⇒ Object



67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 67

def columns(table_name)
  return [] if table_name.blank?

  column_definitions(table_name).map do |ci|
    sqlserver_options = ci.slice :ordinal_position, :is_primary, :is_identity, :table_name
     =  ci[:type], sqlserver_options
    new_column(
      ci[:name],
      ci[:default_value],
      ,
      ci[:null],
      ci[:default_function],
      ci[:collation],
      nil,
      sqlserver_options
    )
  end
end

#columns_for_distinct(columns, orders) ⇒ Object



348
349
350
351
352
353
354
355
356
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 348

def columns_for_distinct(columns, orders)
  order_columns = orders.reject(&:blank?).map { |s|
                    s = s.to_sql unless s.is_a?(String)
                    s.gsub(/\s+(?:ASC|DESC)\b/i, "")
                     .gsub(/\s+NULLS\s+(?:FIRST|LAST)\b/i, "")
                  }.reject(&:blank?).map.with_index { |column, i| "#{column} AS alias_#{i}" }

  (order_columns << super).join(", ")
end

#create_schema(schema_name, authorization = nil) ⇒ Object



381
382
383
384
385
386
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 381

def create_schema(schema_name, authorization = nil)
  sql = "CREATE SCHEMA [#{schema_name}]"
  sql += " AUTHORIZATION [#{authorization}]" if authorization

  execute sql
end

#create_schema_dumper(options) ⇒ Object



377
378
379
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 377

def create_schema_dumper(options)
  SQLServer::SchemaDumper.create(self, options)
end

#create_table(table_name, **options) ⇒ Object



11
12
13
14
15
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 11

def create_table(table_name, **options)
  res = super
  clear_cache!
  res
end

#drop_schema(schema_name) ⇒ Object



392
393
394
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 392

def drop_schema(schema_name)
  execute "DROP SCHEMA [#{schema_name}]"
end

#drop_table(*table_names, **options) ⇒ Object



17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 17

def drop_table(*table_names, **options)
  table_names.each do |table_name|
    # Mimic CASCADE option as best we can.
    if options[:force] == :cascade
      execute_procedure(:sp_fkeys, pktable_name: table_name).each do |fkdata|
        fktable = fkdata["FKTABLE_NAME"]
        fkcolmn = fkdata["FKCOLUMN_NAME"]
        pktable = fkdata["PKTABLE_NAME"]
        pkcolmn = fkdata["PKCOLUMN_NAME"]
        remove_foreign_key fktable, name: fkdata["FK_NAME"]
        execute "DELETE FROM #{quote_table_name(fktable)} WHERE #{quote_column_name(fkcolmn)} IN ( SELECT #{quote_column_name(pkcolmn)} FROM #{quote_table_name(pktable)} )"
      end
    end
    if options[:if_exists] && version_year < 2016
      execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = #{quote(table_name)}) DROP TABLE #{quote_table_name(table_name)}", "SCHEMA"
    else
      super
    end
  end
end

#extract_foreign_key_action(action, fk_name) ⇒ Object



263
264
265
266
267
268
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 263

def extract_foreign_key_action(action, fk_name)
  case select_value("SELECT #{action}_referential_action_desc FROM sys.foreign_keys WHERE name = '#{fk_name}'")
  when "CASCADE" then :cascade
  when "SET_NULL" then :nullify
  end
end

#foreign_keys(table_name) ⇒ Object



238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 238

def foreign_keys(table_name)
  identifier = SQLServer::Utils.extract_identifiers(table_name)
  fk_info = execute_procedure :sp_fkeys, nil, identifier.schema, nil, identifier.object, identifier.schema

  grouped_fk = fk_info.group_by { |row| row["FK_NAME"] }.values.each { |group| group.sort_by! { |row| row["KEY_SEQ"] } }
  grouped_fk.map do |group|
    row = group.first
    options = {
      name: row["FK_NAME"],
      on_update: extract_foreign_key_action("update", row["FK_NAME"]),
      on_delete: extract_foreign_key_action("delete", row["FK_NAME"])
    }

    if group.one?
      options[:column] = row["FKCOLUMN_NAME"]
      options[:primary_key] = row["PKCOLUMN_NAME"]
    else
      options[:column] = group.map { |row| row["FKCOLUMN_NAME"] }
      options[:primary_key] = group.map { |row| row["PKCOLUMN_NAME"] }
    end

    ForeignKeyDefinition.new(identifier.object, row["PKTABLE_NAME"], options)
  end
end

#indexes(table_name) ⇒ Object



38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 38

def indexes(table_name)
  data = select("EXEC sp_helpindex #{quote(table_name)}", "SCHEMA") rescue []

  data.reduce([]) do |indexes, index|
    if index['index_description'].match?(/primary key/)
      indexes
    else
      name    = index['index_name']
      unique  = index['index_description'].match?(/unique/)
      where   = select_value("SELECT [filter_definition] FROM sys.indexes WHERE name = #{quote(name)}", "SCHEMA")
      orders  = {}
      columns = []

      index['index_keys'].split(",").each do |column|
        column.strip!

        if column.end_with?("(-)")
          column.gsub! "(-)", ""
          orders[column] = :desc
        end

        columns << column
      end

      indexes << IndexDefinition.new(table_name, name, unique, columns, where: where, orders: orders)
    end
  end
end

#native_database_typesObject



7
8
9
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 7

def native_database_types
  @native_database_types ||= initialize_native_database_types.freeze
end

#new_column(name, default, sql_type_metadata, null, default_function = nil, collation = nil, comment = nil, sqlserver_options = {}) ⇒ Object



86
87
88
89
90
91
92
93
94
95
96
97
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 86

def new_column(name, default, , null, default_function = nil, collation = nil, comment = nil, sqlserver_options = {})
  SQLServer::Column.new(
    name,
    default,
    ,
    null,
    default_function,
    collation: collation,
    comment: comment,
    **sqlserver_options
  )
end

#primary_keys(table_name) ⇒ Object



99
100
101
102
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 99

def primary_keys(table_name)
  primaries = primary_keys_select(table_name)
  primaries.present? ? primaries : identity_columns(table_name).map(&:name)
end

#primary_keys_select(table_name) ⇒ Object



104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 104

def primary_keys_select(table_name)
  identifier = database_prefix_identifier(table_name)
  database = identifier.fully_qualified_database_quoted
  sql = %{
    SELECT #{lowercase_schema_reflection_sql('KCU.COLUMN_NAME')} AS [name]
    FROM #{database}.INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS KCU
    LEFT OUTER JOIN #{database}.INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS TC
      ON KCU.CONSTRAINT_NAME = TC.CONSTRAINT_NAME
      AND KCU.CONSTRAINT_NAME = TC.CONSTRAINT_NAME
      AND KCU.CONSTRAINT_CATALOG = TC.CONSTRAINT_CATALOG
      AND KCU.CONSTRAINT_SCHEMA = TC.CONSTRAINT_SCHEMA
      AND TC.CONSTRAINT_TYPE = N'PRIMARY KEY'
    WHERE KCU.TABLE_NAME = #{prepared_statements ? '@0' : quote(identifier.object)}
    AND KCU.TABLE_SCHEMA = #{identifier.schema.blank? ? 'schema_name()' : (prepared_statements ? '@1' : quote(identifier.schema))}
    AND TC.CONSTRAINT_TYPE = N'PRIMARY KEY'
    ORDER BY KCU.ORDINAL_POSITION ASC
  }.gsub(/[[:space:]]/, " ")

  binds = []
  nv128 = SQLServer::Type::UnicodeVarchar.new limit: 128
  binds << Relation::QueryAttribute.new("TABLE_NAME", identifier.object, nv128)
  binds << Relation::QueryAttribute.new("TABLE_SCHEMA", identifier.schema, nv128) unless identifier.schema.blank?

  internal_exec_query(sql, "SCHEMA", binds).map { |row| row["name"] }
end

#remove_column(table_name, column_name, type = nil, **options) ⇒ Object

Raises:

  • (ArgumentError)


138
139
140
141
142
143
144
145
146
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 138

def remove_column(table_name, column_name, type = nil, **options)
  raise ArgumentError.new("You must specify at least one column name.  Example: remove_column(:people, :first_name)") if column_name.is_a? Array
  return if options[:if_exists] == true && !column_exists?(table_name, column_name)

  remove_check_constraints(table_name, column_name)
  remove_default_constraint(table_name, column_name)
  remove_indexes(table_name, column_name)
  execute "ALTER TABLE #{quote_table_name(table_name)} DROP COLUMN #{quote_column_name(column_name)}"
end

#remove_index!(table_name, index_name) ⇒ Object



220
221
222
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 220

def remove_index!(table_name, index_name)
  execute "DROP INDEX #{quote_column_name(index_name)} ON #{quote_table_name(table_name)}"
end

#rename_column(table_name, column_name, new_column_name) ⇒ Object



205
206
207
208
209
210
211
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 205

def rename_column(table_name, column_name, new_column_name)
  clear_cache!
  identifier = SQLServer::Utils.extract_identifiers("#{table_name}.#{column_name}")
  execute_procedure :sp_rename, identifier.quoted, new_column_name, "COLUMN"
  rename_column_indexes(table_name, column_name, new_column_name)
  clear_cache!
end

#rename_index(table_name, old_name, new_name) ⇒ Object

Raises:

  • (ArgumentError)


213
214
215
216
217
218
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 213

def rename_index(table_name, old_name, new_name)
  raise ArgumentError, "Index name '#{new_name}' on table '#{table_name}' is too long; the limit is #{index_name_length} characters" if new_name.length > index_name_length

  identifier = SQLServer::Utils.extract_identifiers("#{table_name}.#{old_name}")
  execute_procedure :sp_rename, identifier.quoted, new_name, "INDEX"
end

#rename_table(table_name, new_name, **options) ⇒ Object



130
131
132
133
134
135
136
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 130

def rename_table(table_name, new_name, **options)
  validate_table_length!(new_name) unless options[:_uses_legacy_table_name]
  schema_cache.clear_data_source_cache!(table_name.to_s)
  schema_cache.clear_data_source_cache!(new_name.to_s)
  execute "EXEC sp_rename '#{table_name}', '#{new_name}'"
  rename_table_indexes(table_name, new_name, **options)
end

#schema_namesObject

Returns an array of schema names.



397
398
399
400
401
402
403
404
405
406
407
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 397

def schema_names
  sql = <<~SQL.squish
   SELECT name
    FROM sys.schemas
    WHERE
    name NOT LIKE 'db_%' AND
    name NOT IN ('INFORMATION_SCHEMA', 'sys', 'guest')
  SQL

  query_values(sql, "SCHEMA")
end

#type_to_sql(type, limit: nil, precision: nil, scale: nil) ⇒ Object



293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 293

def type_to_sql(type, limit: nil, precision: nil, scale: nil, **)
  type_limitable = %w(string integer float char nchar varchar nvarchar binary_basic).include?(type.to_s)
  limit = nil unless type_limitable

  case type.to_s
  when "integer"
    case limit
    when 1          then  "tinyint"
    when 2          then  "smallint"
    when 3..4, nil  then  "integer"
    when 5..8       then  "bigint"
    else raise(ActiveRecordError, "No integer type has byte size #{limit}. Use a numeric with precision 0 instead.")
    end
  when "time" # https://learn.microsoft.com/en-us/sql/t-sql/data-types/time-transact-sql
    column_type_sql = type.to_s
    if precision
      if (0..7) === precision
        column_type_sql << "(#{precision})"
      else
        raise(ActiveRecordError, "The time type has precision of #{precision}. The allowed range of precision is from 0 to 7")
      end
    end
    column_type_sql
  when "datetime2"
    column_type_sql = super
    if precision
      if (0..7) === precision
        column_type_sql << "(#{precision})"
      else
        raise(ActiveRecordError, "The datetime2 type has precision of #{precision}. The allowed range of precision is from 0 to 7")
      end
    end
    column_type_sql
  when "datetimeoffset"
    column_type_sql = super
    if precision
      if (0..7) === precision
        column_type_sql << "(#{precision})"
      else
        raise(ActiveRecordError, "The datetimeoffset type has precision of #{precision}. The allowed range of precision is from 0 to 7")
      end
    end
    column_type_sql
  else
    super
  end
end

#update_table_definition(table_name, base) ⇒ Object



358
359
360
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 358

def update_table_definition(table_name, base)
  SQLServer::Table.new(table_name, base)
end