migration_helpers.rb 34 KB

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