migration_helpers.rb 36 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977978979980981982983984985986987988989990991992993
  1. # frozen_string_literal: true
  2. # This file is copied almost entirely from GitLab, which has done a large
  3. # amount of work to ensure that migrations can happen with minimal downtime.
  4. # Many thanks to those engineers.
  5. # Changes have been made to remove dependencies on other GitLab files and to
  6. # shorten temporary column names.
  7. # Documentation on using these functions (and why one might do so):
  8. # https://gitlab.com/gitlab-org/gitlab-ce/blob/master/doc/development/what_requires_downtime.md
  9. # The file itself:
  10. # https://gitlab.com/gitlab-org/gitlab-ce/blob/master/lib/gitlab/database/migration_helpers.rb
  11. # It is licensed as follows:
  12. # Copyright (c) 2011-2017 GitLab B.V.
  13. # Permission is hereby granted, free of charge, to any person obtaining a copy
  14. # of this software and associated documentation files (the "Software"), to deal
  15. # in the Software without restriction, including without limitation the rights
  16. # to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
  17. # copies of the Software, and to permit persons to whom the Software is
  18. # furnished to do so, subject to the following conditions:
  19. # The above copyright notice and this permission notice shall be included in
  20. # all copies or substantial portions of the Software.
  21. # THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
  22. # IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
  23. # FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
  24. # AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
  25. # LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
  26. # OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN
  27. # THE SOFTWARE.
  28. # This is bad form, but there are enough differences that it's impractical to do
  29. # otherwise:
  30. # rubocop:disable all
  31. module Mastodon
  32. module MigrationHelpers
  33. class CorruptionError < StandardError
  34. attr_reader :index_name
  35. def initialize(index_name)
  36. @index_name = index_name
  37. super "The index `#{index_name}` seems to be corrupted, it contains duplicate rows. " \
  38. 'For information on how to fix this, see our documentation: ' \
  39. 'https://docs.joinmastodon.org/admin/troubleshooting/index-corruption/'
  40. end
  41. def cause
  42. nil
  43. end
  44. def backtrace
  45. []
  46. end
  47. end
  48. # Model that can be used for querying permissions of a SQL user.
  49. class Grant < ActiveRecord::Base
  50. self.table_name = 'information_schema.role_table_grants'
  51. def self.scope_to_current_user
  52. where('grantee = user')
  53. end
  54. # Returns true if the current user can create and execute triggers on the
  55. # given table.
  56. def self.create_and_execute_trigger?(table)
  57. priv = where(privilege_type: 'TRIGGER', table_name: table)
  58. priv.scope_to_current_user.any?
  59. end
  60. end
  61. BACKGROUND_MIGRATION_BATCH_SIZE = 1000 # Number of rows to process per job
  62. BACKGROUND_MIGRATION_JOB_BUFFER_SIZE = 1000 # Number of jobs to bulk queue at a time
  63. # Gets an estimated number of rows for a table
  64. def estimate_rows_in_table(table_name)
  65. exec_query('SELECT reltuples FROM pg_class WHERE relname = ' +
  66. "'#{table_name}'").to_a.first['reltuples']
  67. end
  68. # Adds `created_at` and `updated_at` columns with timezone information.
  69. #
  70. # This method is an improved version of Rails' built-in method `add_timestamps`.
  71. #
  72. # Available options are:
  73. # default - The default value for the column.
  74. # null - When set to `true` the column will allow NULL values.
  75. # The default is to not allow NULL values.
  76. def add_timestamps_with_timezone(table_name, **options)
  77. options[:null] = false if options[:null].nil?
  78. [:created_at, :updated_at].each do |column_name|
  79. if options[:default] && transaction_open?
  80. raise '`add_timestamps_with_timezone` with default value cannot be run inside a transaction. ' \
  81. 'You can disable transactions by calling `disable_ddl_transaction!` ' \
  82. 'in the body of your migration class'
  83. end
  84. # If default value is presented, use `add_column_with_default` method instead.
  85. if options[:default]
  86. add_column_with_default(
  87. table_name,
  88. column_name,
  89. :datetime_with_timezone,
  90. default: options[:default],
  91. allow_null: options[:null]
  92. )
  93. else
  94. add_column(table_name, column_name, :datetime_with_timezone, **options)
  95. end
  96. end
  97. end
  98. # Creates a new index, concurrently when supported
  99. #
  100. # On PostgreSQL this method creates an index concurrently, on MySQL this
  101. # creates a regular index.
  102. #
  103. # Example:
  104. #
  105. # add_concurrent_index :users, :some_column
  106. #
  107. # See Rails' `add_index` for more info on the available arguments.
  108. def add_concurrent_index(table_name, column_name, **options)
  109. if transaction_open?
  110. raise 'add_concurrent_index can not be run inside a transaction, ' \
  111. 'you can disable transactions by calling disable_ddl_transaction! ' \
  112. 'in the body of your migration class'
  113. end
  114. options = options.merge({ algorithm: :concurrently })
  115. disable_statement_timeout
  116. add_index(table_name, column_name, **options)
  117. end
  118. # Removes an existed index, concurrently when supported
  119. #
  120. # On PostgreSQL this method removes an index concurrently.
  121. #
  122. # Example:
  123. #
  124. # remove_concurrent_index :users, :some_column
  125. #
  126. # See Rails' `remove_index` for more info on the available arguments.
  127. def remove_concurrent_index(table_name, column_name, **options)
  128. if transaction_open?
  129. raise 'remove_concurrent_index can not be run inside a transaction, ' \
  130. 'you can disable transactions by calling disable_ddl_transaction! ' \
  131. 'in the body of your migration class'
  132. end
  133. if supports_drop_index_concurrently?
  134. options = options.merge({ algorithm: :concurrently })
  135. disable_statement_timeout
  136. end
  137. remove_index(table_name, **options.merge({ column: column_name }))
  138. end
  139. # Removes an existing index, concurrently when supported
  140. #
  141. # On PostgreSQL this method removes an index concurrently.
  142. #
  143. # Example:
  144. #
  145. # remove_concurrent_index :users, "index_X_by_Y"
  146. #
  147. # See Rails' `remove_index` for more info on the available arguments.
  148. def remove_concurrent_index_by_name(table_name, index_name, **options)
  149. if transaction_open?
  150. raise 'remove_concurrent_index_by_name can not be run inside a transaction, ' \
  151. 'you can disable transactions by calling disable_ddl_transaction! ' \
  152. 'in the body of your migration class'
  153. end
  154. if supports_drop_index_concurrently?
  155. options = options.merge({ algorithm: :concurrently })
  156. disable_statement_timeout
  157. end
  158. remove_index(table_name, **options.merge({ name: index_name }))
  159. end
  160. # Only available on Postgresql >= 9.2
  161. def supports_drop_index_concurrently?
  162. version = select_one("SELECT current_setting('server_version_num') AS v")['v'].to_i
  163. version >= 90_200
  164. end
  165. # Only available on Postgresql >= 11
  166. def supports_add_column_with_default?
  167. version = select_one("SELECT current_setting('server_version_num') AS v")['v'].to_i
  168. version >= 11_000
  169. end
  170. # Adds a foreign key with only minimal locking on the tables involved.
  171. #
  172. # This method only requires minimal locking when using PostgreSQL. When
  173. # using MySQL this method will use Rails' default `add_foreign_key`.
  174. #
  175. # source - The source table containing the foreign key.
  176. # target - The target table the key points to.
  177. # column - The name of the column to create the foreign key on.
  178. # on_delete - The action to perform when associated data is removed,
  179. # defaults to "CASCADE".
  180. def add_concurrent_foreign_key(source, target, column:, on_delete: :cascade, target_col: 'id')
  181. # Transactions would result in ALTER TABLE locks being held for the
  182. # duration of the transaction, defeating the purpose of this method.
  183. if transaction_open?
  184. raise 'add_concurrent_foreign_key can not be run inside a transaction'
  185. end
  186. # While MySQL does allow disabling of foreign keys it has no equivalent
  187. # of PostgreSQL's "VALIDATE CONSTRAINT". As a result we'll just fall
  188. # back to the normal foreign key procedure.
  189. on_delete = 'SET NULL' if on_delete == :nullify
  190. disable_statement_timeout
  191. key_name = concurrent_foreign_key_name(source, column, target_col)
  192. # Using NOT VALID allows us to create a key without immediately
  193. # validating it. This means we keep the ALTER TABLE lock only for a
  194. # short period of time. The key _is_ enforced for any newly created
  195. # data.
  196. execute <<-EOF.strip_heredoc
  197. ALTER TABLE #{source}
  198. ADD CONSTRAINT #{key_name}
  199. FOREIGN KEY (#{column})
  200. REFERENCES #{target} (#{target_col})
  201. #{on_delete ? "ON DELETE #{on_delete.upcase}" : ''}
  202. NOT VALID;
  203. EOF
  204. # Validate the existing constraint. This can potentially take a very
  205. # long time to complete, but fortunately does not lock the source table
  206. # while running.
  207. execute("ALTER TABLE #{source} VALIDATE CONSTRAINT #{key_name};")
  208. end
  209. # Returns the name for a concurrent foreign key.
  210. #
  211. # PostgreSQL constraint names have a limit of 63 bytes. The logic used
  212. # here is based on Rails' foreign_key_name() method, which unfortunately
  213. # is private so we can't rely on it directly.
  214. def concurrent_foreign_key_name(table, column, target_col)
  215. "fk_#{Digest::SHA256.hexdigest("#{table}_#{column}_#{target_col}_fk").first(10)}"
  216. end
  217. # Long-running migrations may take more than the timeout allowed by
  218. # the database. Disable the session's statement timeout to ensure
  219. # migrations don't get killed prematurely. (PostgreSQL only)
  220. def disable_statement_timeout
  221. execute('SET statement_timeout TO 0')
  222. end
  223. # Updates the value of a column in batches.
  224. #
  225. # This method updates the table in batches of 5% of the total row count.
  226. # This method will continue updating rows until no rows remain.
  227. #
  228. # When given a block this method will yield two values to the block:
  229. #
  230. # 1. An instance of `Arel::Table` for the table that is being updated.
  231. # 2. The query to run as an Arel object.
  232. #
  233. # By supplying a block one can add extra conditions to the queries being
  234. # executed. Note that the same block is used for _all_ queries.
  235. #
  236. # Example:
  237. #
  238. # update_column_in_batches(:projects, :foo, 10) do |table, query|
  239. # query.where(table[:some_column].eq('hello'))
  240. # end
  241. #
  242. # This would result in this method updating only rows where
  243. # `projects.some_column` equals "hello".
  244. #
  245. # table - The name of the table.
  246. # column - The name of the column to update.
  247. # value - The value for the column.
  248. #
  249. # Rubocop's Metrics/AbcSize metric is disabled for this method as Rubocop
  250. # determines this method to be too complex while there's no way to make it
  251. # less "complex" without introducing extra methods (which actually will
  252. # make things _more_ complex).
  253. def update_column_in_batches(table_name, column, value)
  254. if transaction_open?
  255. raise 'update_column_in_batches can not be run inside a transaction, ' \
  256. 'you can disable transactions by calling disable_ddl_transaction! ' \
  257. 'in the body of your migration class'
  258. end
  259. table = Arel::Table.new(table_name)
  260. total = estimate_rows_in_table(table_name).to_i
  261. if total < 1
  262. count_arel = table.project(Arel.star.count.as('count'))
  263. count_arel = yield table, count_arel if block_given?
  264. total = exec_query(count_arel.to_sql).to_ary.first['count'].to_i
  265. return if total == 0
  266. end
  267. # Update in batches of 5% until we run out of any rows to update.
  268. batch_size = ((total / 100.0) * 5.0).ceil
  269. max_size = 1000
  270. # The upper limit is 1000 to ensure we don't lock too many rows. For
  271. # example, for "merge_requests" even 1% of the table is around 35 000
  272. # rows for GitLab.com.
  273. batch_size = max_size if batch_size > max_size
  274. start_arel = table.project(table[:id]).order(table[:id].asc).take(1)
  275. start_arel = yield table, start_arel if block_given?
  276. first_row = exec_query(start_arel.to_sql).to_ary.first
  277. # In case there are no rows but we didn't catch it in the estimated size:
  278. return unless first_row
  279. start_id = first_row['id'].to_i
  280. say "Migrating #{table_name}.#{column} (~#{total.to_i} rows)"
  281. started_time = Time.zone.now
  282. last_time = Time.zone.now
  283. migrated = 0
  284. loop do
  285. stop_row = nil
  286. suppress_messages do
  287. stop_arel = table.project(table[:id])
  288. .where(table[:id].gteq(start_id))
  289. .order(table[:id].asc)
  290. .take(1)
  291. .skip(batch_size)
  292. stop_arel = yield table, stop_arel if block_given?
  293. stop_row = exec_query(stop_arel.to_sql).to_ary.first
  294. update_arel = Arel::UpdateManager.new
  295. .table(table)
  296. .set([[table[column], value]])
  297. .where(table[:id].gteq(start_id))
  298. if stop_row
  299. stop_id = stop_row['id'].to_i
  300. start_id = stop_id
  301. update_arel = update_arel.where(table[:id].lt(stop_id))
  302. end
  303. update_arel = yield table, update_arel if block_given?
  304. execute(update_arel.to_sql)
  305. end
  306. migrated += batch_size
  307. if Time.zone.now - last_time > 1
  308. status = "Migrated #{migrated} rows"
  309. percentage = 100.0 * migrated / total
  310. status += " (~#{sprintf('%.2f', percentage)}%, "
  311. remaining_time = (100.0 - percentage) * (Time.zone.now - started_time) / percentage
  312. status += "#{(remaining_time / 60).to_i}:"
  313. status += sprintf('%02d', remaining_time.to_i % 60)
  314. status += ' remaining, '
  315. # Tell users not to interrupt if we're almost done.
  316. if remaining_time > 10
  317. status += 'safe to interrupt'
  318. else
  319. status += 'DO NOT interrupt'
  320. end
  321. status += ')'
  322. say status, true
  323. last_time = Time.zone.now
  324. end
  325. # There are no more rows left to update.
  326. break unless stop_row
  327. end
  328. end
  329. # Adds a column with a default value without locking an entire table.
  330. #
  331. # This method runs the following steps:
  332. #
  333. # 1. Add the column with a default value of NULL.
  334. # 2. Change the default value of the column to the specified value.
  335. # 3. Update all existing rows in batches.
  336. # 4. Set a `NOT NULL` constraint on the column if desired (the default).
  337. #
  338. # These steps ensure a column can be added to a large and commonly used
  339. # table without locking the entire table for the duration of the table
  340. # modification.
  341. #
  342. # table - The name of the table to update.
  343. # column - The name of the column to add.
  344. # type - The column type (e.g. `:integer`).
  345. # default - The default value for the column.
  346. # limit - Sets a column limit. For example, for :integer, the default is
  347. # 4-bytes. Set `limit: 8` to allow 8-byte integers.
  348. # allow_null - When set to `true` the column will allow NULL values, the
  349. # default is to not allow NULL values.
  350. #
  351. # This method can also take a block which is passed directly to the
  352. # `update_column_in_batches` method.
  353. def add_column_with_default(table, column, type, default:, limit: nil, allow_null: false, &block)
  354. if supports_add_column_with_default?
  355. add_column(table, column, type, default: default, limit: limit, null: allow_null)
  356. return
  357. end
  358. if transaction_open?
  359. raise 'add_column_with_default can not be run inside a transaction, ' \
  360. 'you can disable transactions by calling disable_ddl_transaction! ' \
  361. 'in the body of your migration class'
  362. end
  363. disable_statement_timeout
  364. transaction do
  365. if limit
  366. add_column(table, column, type, default: nil, limit: limit)
  367. else
  368. add_column(table, column, type, default: nil)
  369. end
  370. # Changing the default before the update ensures any newly inserted
  371. # rows already use the proper default value.
  372. change_column_default(table, column, default)
  373. end
  374. begin
  375. update_column_in_batches(table, column, default, &block)
  376. change_column_null(table, column, false) unless allow_null
  377. # We want to rescue _all_ exceptions here, even those that don't inherit
  378. # from StandardError.
  379. rescue Exception => error # rubocop: disable all
  380. remove_column(table, column)
  381. raise error
  382. end
  383. end
  384. # Renames a column without requiring downtime.
  385. #
  386. # Concurrent renames work by using database triggers to ensure both the
  387. # old and new column are in sync. However, this method will _not_ remove
  388. # the triggers or the old column automatically; this needs to be done
  389. # manually in a post-deployment migration. This can be done using the
  390. # method `cleanup_concurrent_column_rename`.
  391. #
  392. # table - The name of the database table containing the column.
  393. # old - The old column name.
  394. # new - The new column name.
  395. # type - The type of the new column. If no type is given the old column's
  396. # type is used.
  397. def rename_column_concurrently(table, old, new, type: nil)
  398. if transaction_open?
  399. raise 'rename_column_concurrently can not be run inside a transaction'
  400. end
  401. check_trigger_permissions!(table)
  402. trigger_name = rename_trigger_name(table, old, new)
  403. # If we were in the middle of update_column_in_batches, we should remove
  404. # the old column and start over, as we have no idea where we were.
  405. if column_for(table, new)
  406. remove_rename_triggers_for_postgresql(table, trigger_name)
  407. remove_column(table, new)
  408. end
  409. old_col = column_for(table, old)
  410. new_type = type || old_col.type
  411. col_opts = {
  412. precision: old_col.precision,
  413. scale: old_col.scale,
  414. }
  415. # We may be trying to reset the limit on an integer column type, so let
  416. # Rails handle that.
  417. unless [:bigint, :integer].include?(new_type)
  418. col_opts[:limit] = old_col.limit
  419. end
  420. add_column(table, new, new_type, **col_opts)
  421. # We set the default value _after_ adding the column so we don't end up
  422. # updating any existing data with the default value. This isn't
  423. # necessary since we copy over old values further down.
  424. change_column_default(table, new, old_col.default) if old_col.default
  425. quoted_table = quote_table_name(table)
  426. quoted_old = quote_column_name(old)
  427. quoted_new = quote_column_name(new)
  428. install_rename_triggers_for_postgresql(trigger_name, quoted_table,
  429. quoted_old, quoted_new)
  430. update_column_in_batches(table, new, Arel::Table.new(table)[old])
  431. change_column_null(table, new, false) unless old_col.null
  432. copy_indexes(table, old, new)
  433. copy_foreign_keys(table, old, new)
  434. end
  435. # Changes the type of a column concurrently.
  436. #
  437. # table - The table containing the column.
  438. # column - The name of the column to change.
  439. # new_type - The new column type.
  440. def change_column_type_concurrently(table, column, new_type)
  441. temp_column = rename_column_name(column)
  442. rename_column_concurrently(table, column, temp_column, type: new_type)
  443. # Primary keys don't necessarily have an associated index.
  444. if ActiveRecord::Base.get_primary_key(table) == column.to_s
  445. old_pk_index_name = "index_#{table}_on_#{column}"
  446. new_pk_index_name = "index_#{table}_on_#{column}_cm"
  447. unless indexes_for(table, column).find{|i| i.name == old_pk_index_name}
  448. add_concurrent_index(table, [temp_column],
  449. unique: true,
  450. name: new_pk_index_name
  451. )
  452. end
  453. end
  454. end
  455. # Performs cleanup of a concurrent type change.
  456. #
  457. # table - The table containing the column.
  458. # column - The name of the column to change.
  459. # new_type - The new column type.
  460. def cleanup_concurrent_column_type_change(table, column)
  461. temp_column = rename_column_name(column)
  462. # Wait for the indices to be built
  463. indexes_for(table, column).each do |index|
  464. expected_name = index.name + '_cm'
  465. puts "Waiting for index #{expected_name}"
  466. sleep 1 until indexes_for(table, temp_column).find {|i| i.name == expected_name }
  467. end
  468. was_primary = (ActiveRecord::Base.get_primary_key(table) == column.to_s)
  469. old_default_fn = column_for(table, column).default_function
  470. old_fks = []
  471. if was_primary
  472. # Get any foreign keys pointing at this column we need to recreate, and
  473. # remove the old ones.
  474. # Based on code from:
  475. # http://errorbank.blogspot.com/2011/03/list-all-foreign-keys-references-for.html
  476. old_fks_res = execute <<-EOF.strip_heredoc
  477. select m.relname as src_table,
  478. (select a.attname
  479. from pg_attribute a
  480. where a.attrelid = m.oid
  481. and a.attnum = o.conkey[1]
  482. and a.attisdropped = false) as src_col,
  483. o.conname as name,
  484. o.confdeltype as on_delete
  485. from pg_constraint o
  486. left join pg_class f on f.oid = o.confrelid
  487. left join pg_class c on c.oid = o.conrelid
  488. left join pg_class m on m.oid = o.conrelid
  489. where o.contype = 'f'
  490. and o.conrelid in (
  491. select oid from pg_class c where c.relkind = 'r')
  492. and f.relname = '#{table}';
  493. EOF
  494. old_fks = old_fks_res.to_a
  495. old_fks.each do |old_fk|
  496. add_concurrent_foreign_key(
  497. old_fk['src_table'],
  498. table,
  499. column: old_fk['src_col'],
  500. target_col: temp_column,
  501. on_delete: extract_foreign_key_action(old_fk['on_delete'])
  502. )
  503. remove_foreign_key(old_fk['src_table'], name: old_fk['name'])
  504. end
  505. end
  506. # If there was a sequence owned by the old column, make it owned by the
  507. # new column, as it will otherwise be deleted when we get rid of the
  508. # old column.
  509. if (seq_match = /^nextval\('([^']*)'(::text|::regclass)?\)/.match(old_default_fn))
  510. seq_name = seq_match[1]
  511. execute("ALTER SEQUENCE #{seq_name} OWNED BY #{table}.#{temp_column}")
  512. end
  513. transaction do
  514. # This has to be performed in a transaction as otherwise we might have
  515. # inconsistent data.
  516. cleanup_concurrent_column_rename(table, column, temp_column)
  517. rename_column(table, temp_column, column)
  518. # If there was an old default function, we didn't copy it. Do that now
  519. # in the transaction, so we don't miss anything.
  520. change_column_default(table, column, -> { old_default_fn }) if old_default_fn
  521. end
  522. # Rename any indices back to what they should be.
  523. indexes_for(table, column).each do |index|
  524. next unless index.name.end_with?('_cm')
  525. real_index_name = index.name.sub(/_cm$/, '')
  526. rename_index(table, index.name, real_index_name)
  527. end
  528. # Rename any foreign keys back to names based on the real column.
  529. foreign_keys_for(table, column).each do |fk|
  530. old_fk_name = concurrent_foreign_key_name(fk.from_table, temp_column, 'id')
  531. new_fk_name = concurrent_foreign_key_name(fk.from_table, column, 'id')
  532. execute("ALTER TABLE #{fk.from_table} RENAME CONSTRAINT " +
  533. "#{old_fk_name} TO #{new_fk_name}")
  534. end
  535. # Rename any foreign keys from other tables to names based on the real
  536. # column.
  537. old_fks.each do |old_fk|
  538. old_fk_name = concurrent_foreign_key_name(old_fk['src_table'],
  539. old_fk['src_col'], temp_column)
  540. new_fk_name = concurrent_foreign_key_name(old_fk['src_table'],
  541. old_fk['src_col'], column)
  542. execute("ALTER TABLE #{old_fk['src_table']} RENAME CONSTRAINT " +
  543. "#{old_fk_name} TO #{new_fk_name}")
  544. end
  545. # If the old column was a primary key, mark the new one as a primary key.
  546. if was_primary
  547. execute("ALTER TABLE #{table} ADD PRIMARY KEY USING INDEX " +
  548. "index_#{table}_on_#{column}")
  549. end
  550. end
  551. # Cleans up a concurrent column name.
  552. #
  553. # This method takes care of removing previously installed triggers as well
  554. # as removing the old column.
  555. #
  556. # table - The name of the database table.
  557. # old - The name of the old column.
  558. # new - The name of the new column.
  559. def cleanup_concurrent_column_rename(table, old, new)
  560. trigger_name = rename_trigger_name(table, old, new)
  561. check_trigger_permissions!(table)
  562. remove_rename_triggers_for_postgresql(table, trigger_name)
  563. remove_column(table, old)
  564. end
  565. # Performs a concurrent column rename when using PostgreSQL.
  566. def install_rename_triggers_for_postgresql(trigger, table, old, new)
  567. execute <<-EOF.strip_heredoc
  568. CREATE OR REPLACE FUNCTION #{trigger}()
  569. RETURNS trigger AS
  570. $BODY$
  571. BEGIN
  572. NEW.#{new} := NEW.#{old};
  573. RETURN NEW;
  574. END;
  575. $BODY$
  576. LANGUAGE 'plpgsql'
  577. VOLATILE
  578. EOF
  579. execute <<-EOF.strip_heredoc
  580. CREATE TRIGGER #{trigger}
  581. BEFORE INSERT OR UPDATE
  582. ON #{table}
  583. FOR EACH ROW
  584. EXECUTE PROCEDURE #{trigger}()
  585. EOF
  586. end
  587. # Installs the triggers necessary to perform a concurrent column rename on
  588. # MySQL.
  589. def install_rename_triggers_for_mysql(trigger, table, old, new)
  590. execute <<-EOF.strip_heredoc
  591. CREATE TRIGGER #{trigger}_insert
  592. BEFORE INSERT
  593. ON #{table}
  594. FOR EACH ROW
  595. SET NEW.#{new} = NEW.#{old}
  596. EOF
  597. execute <<-EOF.strip_heredoc
  598. CREATE TRIGGER #{trigger}_update
  599. BEFORE UPDATE
  600. ON #{table}
  601. FOR EACH ROW
  602. SET NEW.#{new} = NEW.#{old}
  603. EOF
  604. end
  605. # Removes the triggers used for renaming a PostgreSQL column concurrently.
  606. def remove_rename_triggers_for_postgresql(table, trigger)
  607. execute("DROP TRIGGER IF EXISTS #{trigger} ON #{table}")
  608. execute("DROP FUNCTION IF EXISTS #{trigger}()")
  609. end
  610. # Removes the triggers used for renaming a MySQL column concurrently.
  611. def remove_rename_triggers_for_mysql(trigger)
  612. execute("DROP TRIGGER IF EXISTS #{trigger}_insert")
  613. execute("DROP TRIGGER IF EXISTS #{trigger}_update")
  614. end
  615. # Returns the (base) name to use for triggers when renaming columns.
  616. def rename_trigger_name(table, old, new)
  617. 'trigger_' + Digest::SHA256.hexdigest("#{table}_#{old}_#{new}").first(12)
  618. end
  619. # Returns the name to use for temporary rename columns.
  620. def rename_column_name(base)
  621. base.to_s + '_cm'
  622. end
  623. # Returns an Array containing the indexes for the given column
  624. def indexes_for(table, column)
  625. column = column.to_s
  626. indexes(table).select { |index| index.columns.include?(column) }
  627. end
  628. # Returns an Array containing the foreign keys for the given column.
  629. def foreign_keys_for(table, column)
  630. column = column.to_s
  631. foreign_keys(table).select { |fk| fk.column == column }
  632. end
  633. # Copies all indexes for the old column to a new column.
  634. #
  635. # table - The table containing the columns and indexes.
  636. # old - The old column.
  637. # new - The new column.
  638. def copy_indexes(table, old, new)
  639. old = old.to_s
  640. new = new.to_s
  641. indexes_for(table, old).each do |index|
  642. new_columns = index.columns.map do |column|
  643. column == old ? new : column
  644. end
  645. # This is necessary as we can't properly rename indexes such as
  646. # "ci_taggings_idx".
  647. name = index.name + '_cm'
  648. # If the order contained the old column, map it to the new one.
  649. order = index.orders
  650. if order.key?(old)
  651. order[new] = order.delete(old)
  652. end
  653. options = {
  654. unique: index.unique,
  655. name: name,
  656. length: index.lengths,
  657. order: order
  658. }
  659. # These options are not supported by MySQL, so we only add them if
  660. # they were previously set.
  661. options[:using] = index.using if index.using
  662. options[:where] = index.where if index.where
  663. add_concurrent_index(table, new_columns, **options)
  664. end
  665. end
  666. # Copies all foreign keys for the old column to the new column.
  667. #
  668. # table - The table containing the columns and indexes.
  669. # old - The old column.
  670. # new - The new column.
  671. def copy_foreign_keys(table, old, new)
  672. foreign_keys_for(table, old).each do |fk|
  673. add_concurrent_foreign_key(fk.from_table,
  674. fk.to_table,
  675. column: new,
  676. on_delete: fk.on_delete)
  677. end
  678. end
  679. # Returns the column for the given table and column name.
  680. def column_for(table, name)
  681. name = name.to_s
  682. columns(table).find { |column| column.name == name }
  683. end
  684. # Update the configuration of an index by creating a new one and then
  685. # removing the old one
  686. def update_index(table_name, index_name, columns, **index_options)
  687. if index_name_exists?(table_name, "#{index_name}_new") && index_name_exists?(table_name, index_name)
  688. remove_index table_name, name: "#{index_name}_new"
  689. elsif index_name_exists?(table_name, "#{index_name}_new")
  690. # Very unlikely case where the script has been interrupted during/after removal but before renaming
  691. rename_index table_name, "#{index_name}_new", index_name
  692. end
  693. begin
  694. add_index table_name, columns, **index_options.merge(name: "#{index_name}_new", algorithm: :concurrently)
  695. rescue ActiveRecord::RecordNotUnique
  696. remove_index table_name, name: "#{index_name}_new"
  697. raise CorruptionError.new(index_name)
  698. end
  699. remove_index table_name, name: index_name if index_name_exists?(table_name, index_name)
  700. rename_index table_name, "#{index_name}_new", index_name
  701. end
  702. # This will replace the first occurrence of a string in a column with
  703. # the replacement
  704. # On postgresql we can use `regexp_replace` for that.
  705. # On mysql we find the location of the pattern, and overwrite it
  706. # with the replacement
  707. def replace_sql(column, pattern, replacement)
  708. quoted_pattern = Arel::Nodes::Quoted.new(pattern.to_s)
  709. quoted_replacement = Arel::Nodes::Quoted.new(replacement.to_s)
  710. replace = Arel::Nodes::NamedFunction
  711. .new("regexp_replace", [column, quoted_pattern, quoted_replacement])
  712. Arel::Nodes::SqlLiteral.new(replace.to_sql)
  713. end
  714. def remove_foreign_key_without_error(*args)
  715. remove_foreign_key(*args)
  716. rescue ArgumentError
  717. end
  718. def sidekiq_queue_migrate(queue_from, to:)
  719. while sidekiq_queue_length(queue_from) > 0
  720. Sidekiq.redis do |conn|
  721. conn.rpoplpush "queue:#{queue_from}", "queue:#{to}"
  722. end
  723. end
  724. end
  725. def sidekiq_queue_length(queue_name)
  726. Sidekiq.redis do |conn|
  727. conn.llen("queue:#{queue_name}")
  728. end
  729. end
  730. def check_trigger_permissions!(table)
  731. unless Grant.create_and_execute_trigger?(table)
  732. dbname = ActiveRecord::Base.configurations[Rails.env]['database']
  733. user = ActiveRecord::Base.configurations[Rails.env]['username'] || ENV['USER']
  734. raise <<-EOF
  735. Your database user is not allowed to create, drop, or execute triggers on the
  736. table #{table}.
  737. If you are using PostgreSQL you can solve this by logging in to the Mastodon
  738. database (#{dbname}) using a super user and running:
  739. ALTER USER #{user} WITH SUPERUSER
  740. The query will grant the user super user permissions, ensuring you don't run
  741. into similar problems in the future (e.g. when new tables are created).
  742. EOF
  743. end
  744. end
  745. # Bulk queues background migration jobs for an entire table, batched by ID range.
  746. # "Bulk" meaning many jobs will be pushed at a time for efficiency.
  747. # If you need a delay interval per job, then use `queue_background_migration_jobs_by_range_at_intervals`.
  748. #
  749. # model_class - The table being iterated over
  750. # job_class_name - The background migration job class as a string
  751. # batch_size - The maximum number of rows per job
  752. #
  753. # Example:
  754. #
  755. # class Route < ActiveRecord::Base
  756. # include EachBatch
  757. # self.table_name = 'routes'
  758. # end
  759. #
  760. # bulk_queue_background_migration_jobs_by_range(Route, 'ProcessRoutes')
  761. #
  762. # Where the model_class includes EachBatch, and the background migration exists:
  763. #
  764. # class Gitlab::BackgroundMigration::ProcessRoutes
  765. # def perform(start_id, end_id)
  766. # # do something
  767. # end
  768. # end
  769. def bulk_queue_background_migration_jobs_by_range(model_class, job_class_name, batch_size: BACKGROUND_MIGRATION_BATCH_SIZE)
  770. raise "#{model_class} does not have an ID to use for batch ranges" unless model_class.column_names.include?('id')
  771. jobs = []
  772. model_class.each_batch(of: batch_size) do |relation|
  773. start_id, end_id = relation.pluck('MIN(id), MAX(id)').first
  774. if jobs.length >= BACKGROUND_MIGRATION_JOB_BUFFER_SIZE
  775. # Note: This code path generally only helps with many millions of rows
  776. # We push multiple jobs at a time to reduce the time spent in
  777. # Sidekiq/Redis operations. We're using this buffer based approach so we
  778. # don't need to run additional queries for every range.
  779. BackgroundMigrationWorker.perform_bulk(jobs)
  780. jobs.clear
  781. end
  782. jobs << [job_class_name, [start_id, end_id]]
  783. end
  784. BackgroundMigrationWorker.perform_bulk(jobs) unless jobs.empty?
  785. end
  786. # Queues background migration jobs for an entire table, batched by ID range.
  787. # Each job is scheduled with a `delay_interval` in between.
  788. # If you use a small interval, then some jobs may run at the same time.
  789. #
  790. # model_class - The table being iterated over
  791. # job_class_name - The background migration job class as a string
  792. # delay_interval - The duration between each job's scheduled time (must respond to `to_f`)
  793. # batch_size - The maximum number of rows per job
  794. #
  795. # Example:
  796. #
  797. # class Route < ActiveRecord::Base
  798. # include EachBatch
  799. # self.table_name = 'routes'
  800. # end
  801. #
  802. # queue_background_migration_jobs_by_range_at_intervals(Route, 'ProcessRoutes', 1.minute)
  803. #
  804. # Where the model_class includes EachBatch, and the background migration exists:
  805. #
  806. # class Gitlab::BackgroundMigration::ProcessRoutes
  807. # def perform(start_id, end_id)
  808. # # do something
  809. # end
  810. # end
  811. def queue_background_migration_jobs_by_range_at_intervals(model_class, job_class_name, delay_interval, batch_size: BACKGROUND_MIGRATION_BATCH_SIZE)
  812. raise "#{model_class} does not have an ID to use for batch ranges" unless model_class.column_names.include?('id')
  813. model_class.each_batch(of: batch_size) do |relation, index|
  814. start_id, end_id = relation.pluck('MIN(id), MAX(id)').first
  815. # `BackgroundMigrationWorker.bulk_perform_in` schedules all jobs for
  816. # the same time, which is not helpful in most cases where we wish to
  817. # spread the work over time.
  818. BackgroundMigrationWorker.perform_in(delay_interval * index, job_class_name, [start_id, end_id])
  819. end
  820. end
  821. private
  822. # https://github.com/rails/rails/blob/v5.2.0/activerecord/lib/active_record/connection_adapters/postgresql/schema_statements.rb#L678-L684
  823. def extract_foreign_key_action(specifier)
  824. case specifier
  825. when 'c'; :cascade
  826. when 'n'; :nullify
  827. when 'r'; :restrict
  828. end
  829. end
  830. end
  831. end
  832. # rubocop:enable all