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
-
#add_timestamps(table_name, **options) ⇒ Object
In SQL Server only the first column added should have the ‘ADD` keyword.
-
#build_change_column_default_definition(table_name, column_name, default_or_changes) ⇒ Object
:nodoc:.
-
#build_change_column_definition(table_name, column_name, type, **options) ⇒ Object
:nodoc:.
- #change_column(table_name, column_name, type, options = {}) ⇒ Object
- #change_column_default(table_name, column_name, default_or_changes) ⇒ Object
- #change_column_null(table_name, column_name, null, default = nil) ⇒ Object
- #change_table_schema(schema_name, table_name) ⇒ Object
- #check_constraints(table_name) ⇒ Object
- #columns(table_name) ⇒ Object
- #columns_for_distinct(columns, orders) ⇒ Object
- #create_schema(schema_name, authorization = nil) ⇒ Object
- #create_schema_dumper(options) ⇒ Object
- #create_table(table_name, **options) ⇒ Object
- #drop_schema(schema_name) ⇒ Object
- #drop_table(*table_names, **options) ⇒ Object
- #extract_foreign_key_action(action, fk_name) ⇒ Object
- #extract_generated_type(field) ⇒ Object
- #foreign_keys(table_name) ⇒ Object
- #index_include_columns(table_name, index_name) ⇒ Object
- #indexes(table_name) ⇒ Object
- #new_column_from_field(_table_name, field, _definitions) ⇒ Object
- #primary_keys(table_name) ⇒ Object
- #primary_keys_select(table_name) ⇒ Object
-
#quoted_include_columns_for_index(column_names) ⇒ Object
:nodoc:.
- #remove_column(table_name, column_name, type = nil, **options) ⇒ Object
- #remove_index!(table_name, index_name) ⇒ Object
- #rename_column(table_name, column_name, new_column_name) ⇒ Object
- #rename_index(table_name, old_name, new_name) ⇒ Object
- #rename_table(table_name, new_name, **options) ⇒ Object
-
#schema_names ⇒ Object
Returns an array of schema names.
- #type_to_sql(type, limit: nil, precision: nil, scale: nil) ⇒ Object
- #update_table_definition(table_name, base) ⇒ Object
Instance Method Details
#add_timestamps(table_name, **options) ⇒ Object
In SQL Server only the first column added should have the ‘ADD` keyword.
381 382 383 384 385 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 381 def (table_name, **) fragments = (table_name, **) 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:
269 270 271 272 273 274 275 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 269 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:
263 264 265 266 267 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 263 def build_change_column_definition(table_name, column_name, type, **) # :nodoc: td = create_table_definition(table_name) cd = td.new_column_definition(column_name, type, **) ChangeColumnDefinition.new(cd, column_name) end |
#change_column(table_name, column_name, type, options = {}) ⇒ Object
185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 185 def change_column(table_name, column_name, type, = {}) sql_commands = [] indexes = [] if type == :datetime # If no precision then default it to 6. [:precision] = 6 unless .key?(:precision) # If there is precision then column must be of type 'datetime2'. type = :datetime2 unless [:precision].nil? end column_object = schema_cache.columns(table_name).find { |c| c.name.to_s == column_name.to_s } without_constraints = .key?(:default) || .key?(:limit) default = if !.key?(:default) && column_object column_object.default else [: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 ![:null].nil? && [:null] == false && ![: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 [:collation].present? alter_command += " NOT NULL" if ![:null].nil? && [: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 sql_commands.each { |c| execute(c) } # Add any removed indexes back indexes.each do |index| create_index_def = CreateIndexDefinition.new(index) execute schema_creation.accept(create_index_def) end clear_cache! end |
#change_column_default(table_name, column_name, default_or_changes) ⇒ Object
233 234 235 236 237 238 239 240 241 242 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 233 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
405 406 407 408 409 410 411 412 413 414 415 416 417 418 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 405 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
431 432 433 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 431 def change_table_schema(schema_name, table_name) execute "ALTER SCHEMA [#{schema_name}] TRANSFER [#{table_name}]" end |
#check_constraints(table_name) ⇒ Object
309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 309 def check_constraints(table_name) sql = " select chk.name AS 'name',\n chk.definition AS 'expression'\n from sys.check_constraints chk\n inner join sys.tables st on chk.parent_object_id = st.object_id\n where\n st.name = '\#{table_name}'\n SQL\n\n chk_info = internal_exec_query(sql, \"SCHEMA\")\n\n chk_info.map do |row|\n options = {\n name: row[\"name\"]\n }\n expression = row[\"expression\"]\n expression = expression[1..-2] if expression.start_with?(\"(\") && expression.end_with?(\")\")\n\n CheckConstraintDefinition.new(table_name, expression, options)\n end\nend\n" |
#columns(table_name) ⇒ Object
88 89 90 91 92 93 94 95 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 88 def columns(table_name) return [] if table_name.blank? definitions = column_definitions(table_name) definitions.map do |field| new_column_from_field(table_name, field, definitions) end end |
#columns_for_distinct(columns, orders) ⇒ Object
387 388 389 390 391 392 393 394 395 396 397 398 399 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 387 def columns_for_distinct(columns, orders) order_columns = orders.reject(&:blank?).map { |s| s = visitor.compile(s) unless s.is_a?(String) s.gsub(/\s+(?:ASC|DESC)\b/i, "") .gsub(/\s+NULLS\s+(?:FIRST|LAST)\b/i, "") } .reject(&:blank?) .reject { |s| columns.include?(s) } order_columns_aliased = order_columns.map.with_index { |column, i| "#{column} AS alias_#{i}" } (order_columns_aliased << super).join(", ") end |
#create_schema(schema_name, authorization = nil) ⇒ Object
424 425 426 427 428 429 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 424 def create_schema(schema_name, = nil) sql = "CREATE SCHEMA [#{schema_name}]" sql += " AUTHORIZATION [#{authorization}]" if execute sql end |
#create_schema_dumper(options) ⇒ Object
420 421 422 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 420 def create_schema_dumper() SQLServer::SchemaDumper.create(self, ) end |
#create_table(table_name, **options) ⇒ Object
7 8 9 10 11 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 7 def create_table(table_name, **) res = super clear_cache! res end |
#drop_schema(schema_name) ⇒ Object
435 436 437 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 435 def drop_schema(schema_name) execute "DROP SCHEMA [#{schema_name}]" end |
#drop_table(*table_names, **options) ⇒ Object
13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 13 def drop_table(*table_names, **) table_names.each do |table_name| # Mimic CASCADE option as best we can. if [: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 [: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
302 303 304 305 306 307 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 302 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 |
#extract_generated_type(field) ⇒ Object
122 123 124 125 126 127 128 129 130 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 122 def extract_generated_type(field) if field[:is_computed] if field[:is_persisted] :stored else :virtual end end end |
#foreign_keys(table_name) ⇒ Object
277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 277 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"] } }.reverse grouped_fk.map do |group| row = group.first = { 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? [:column] = row["FKCOLUMN_NAME"] [:primary_key] = row["PKCOLUMN_NAME"] else [:column] = group.map { |row| row["FKCOLUMN_NAME"] } [:primary_key] = group.map { |row| row["PKCOLUMN_NAME"] } end ForeignKeyDefinition.new(identifier.object, row["PKTABLE_NAME"], ) end end |
#index_include_columns(table_name, index_name) ⇒ Object
68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 68 def index_include_columns(table_name, index_name) sql = " SELECT\n ic.index_id,\n c.name AS column_name\n FROM\n sys.indexes i\n JOIN\n sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id\n JOIN\n sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id\n WHERE\n i.object_id = OBJECT_ID('\#{table_name}')\n AND i.name = '\#{index_name}'\n AND ic.is_included_column = 1;\n SQL\n\n select_all(sql, \"SCHEMA\").map { |row| row[\"column_name\"] }\nend\n" |
#indexes(table_name) ⇒ Object
34 35 36 37 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 66 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 34 def indexes(table_name) data = begin select("EXEC sp_helpindex #{quote(table_name)}", "SCHEMA") rescue [] end 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") include_columns = index_include_columns(table_name, name) 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, include: include_columns.presence) end end end |
#new_column_from_field(_table_name, field, _definitions) ⇒ Object
97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 97 def new_column_from_field(_table_name, field, _definitions) = field.slice(:ordinal_position, :is_primary, :is_identity, :table_name) = (field[:type], ) generated_type = extract_generated_type(field) default_function = if generated_type.present? field[:computed_formula] else field[:default_function] end SQLServer::Column.new( field[:name], lookup_cast_type(field[:type]), field[:default_value], , field[:null], default_function, collation: field[:collation], comment: nil, generated_type: generated_type, ** ) end |
#primary_keys(table_name) ⇒ Object
132 133 134 135 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 132 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
137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 137 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 = #{if identifier.schema.blank? "schema_name()" else (prepared_statements ? "@1" : quote(identifier.schema)) end} 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 |
#quoted_include_columns_for_index(column_names) ⇒ Object
:nodoc:
452 453 454 455 456 457 458 459 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 452 def quoted_include_columns_for_index(column_names) # :nodoc: return quote_column_name(column_names) if column_names.is_a?(Symbol) quoted_columns = column_names.each_with_object({}) do |name, result| result[name.to_sym] = quote_column_name(name).dup end (quoted_columns).values.join(", ") end |
#remove_column(table_name, column_name, type = nil, **options) ⇒ Object
175 176 177 178 179 180 181 182 183 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 175 def remove_column(table_name, column_name, type = nil, **) 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 [: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
259 260 261 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 259 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
244 245 246 247 248 249 250 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 244 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
252 253 254 255 256 257 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 252 def rename_index(table_name, old_name, new_name) raise ArgumentError, "Index name '#{new_name}' on table '#{table_name}' is too long (#{new_name.length} characters); 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
167 168 169 170 171 172 173 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 167 def rename_table(table_name, new_name, **) validate_table_length!(new_name) unless [:_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, **) end |
#schema_names ⇒ Object
Returns an array of schema names.
440 441 442 443 444 445 446 447 448 449 450 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 440 def schema_names sql = " SELECT name\n FROM sys.schemas\n WHERE\n name NOT LIKE 'db_%' AND\n name NOT IN ('INFORMATION_SCHEMA', 'sys', 'guest')\n SQL\n\n query_values(sql, \"SCHEMA\")\nend\n".squish |
#type_to_sql(type, limit: nil, precision: nil, scale: nil) ⇒ Object
332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 332 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.dup 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
401 402 403 |
# File 'lib/active_record/connection_adapters/sqlserver/schema_statements.rb', line 401 def update_table_definition(table_name, base) SQLServer::Table.new(table_name, base) end |