From 799a45a291e9f2bd94278f565e58874458768079 Mon Sep 17 00:00:00 2001 From: Bianca Nenciu Date: Mon, 26 Aug 2024 04:35:12 +0300 Subject: [PATCH] DEV: Migrate notifications#id to bigint (#28444) The `notifications.id` column is the most probable column to run out of values. This is because it is an `int` column that has only 2147483647 values and many notifications are generated on a regular basis in an active community. This commit migrates the column to `bigint`. These migrations do not use `ALTER TABLE ... COLUMN ... TYPE` in order to avoid the `ACCESS EXCLUSIVE` lock on the entire table. Instead, they create a new `bigint` column, copy the values to the new column and then sets the new column as primary key. Related columns (see `user_badges`, `shelved_notifications`) will be migrated in a follow-up commit. --- app/models/notification.rb | 3 +- ...ter_notifications_id_sequence_to_bigint.rb | 11 +++++ ...0820123402_add_big_int_notifications_id.rb | 38 ++++++++++++++++ ...0820123403_copy_notifications_id_values.rb | 28 ++++++++++++ ...820123404_copy_notifications_id_indexes.rb | 39 +++++++++++++++++ ...820123405_swap_big_int_notifications_id.rb | 43 +++++++++++++++++++ ...123406_drop_old_notification_id_indexes.rb | 33 ++++++++++++++ 7 files changed, 194 insertions(+), 1 deletion(-) create mode 100644 db/migrate/20240820123401_alter_notifications_id_sequence_to_bigint.rb create mode 100644 db/migrate/20240820123402_add_big_int_notifications_id.rb create mode 100644 db/migrate/20240820123403_copy_notifications_id_values.rb create mode 100644 db/migrate/20240820123404_copy_notifications_id_indexes.rb create mode 100644 db/migrate/20240820123405_swap_big_int_notifications_id.rb create mode 100644 db/migrate/20240820123406_drop_old_notification_id_indexes.rb diff --git a/app/models/notification.rb b/app/models/notification.rb index 32ad9bed680..814cc3a6f3d 100644 --- a/app/models/notification.rb +++ b/app/models/notification.rb @@ -407,7 +407,7 @@ end # # Table name: notifications # -# id :integer not null, primary key +# old_id :integer # notification_type :integer not null # user_id :integer not null # data :string(1000) not null @@ -418,6 +418,7 @@ end # post_number :integer # post_action_id :integer # high_priority :boolean default(FALSE), not null +# id :bigint not null, primary key # # Indexes # diff --git a/db/migrate/20240820123401_alter_notifications_id_sequence_to_bigint.rb b/db/migrate/20240820123401_alter_notifications_id_sequence_to_bigint.rb new file mode 100644 index 00000000000..f49bf080b96 --- /dev/null +++ b/db/migrate/20240820123401_alter_notifications_id_sequence_to_bigint.rb @@ -0,0 +1,11 @@ +# frozen_string_literal: true + +class AlterNotificationsIdSequenceToBigint < ActiveRecord::Migration[7.0] + def up + execute "ALTER SEQUENCE notifications_id_seq AS bigint" + end + + def down + raise ActiveRecord::IrreversibleMigration + end +end diff --git a/db/migrate/20240820123402_add_big_int_notifications_id.rb b/db/migrate/20240820123402_add_big_int_notifications_id.rb new file mode 100644 index 00000000000..99ec174bcd1 --- /dev/null +++ b/db/migrate/20240820123402_add_big_int_notifications_id.rb @@ -0,0 +1,38 @@ +# frozen_string_literal: true + +class AddBigIntNotificationsId < ActiveRecord::Migration[7.0] + def up + # Short-circuit if the table has been migrated already + result = + execute( + "SELECT data_type FROM information_schema.columns WHERE table_name = 'notifications' AND column_name = 'id' LIMIT 1", + ) + data_type = result[0]["data_type"] + return if data_type.downcase == "bigint" + + # Create new column + execute "ALTER TABLE notifications ADD COLUMN new_id BIGINT NOT NULL DEFAULT 0" + + # Mirror new `id` values to `new_id` + execute <<~SQL.squish + CREATE FUNCTION mirror_notifications_id() + RETURNS trigger AS + $$ + BEGIN + NEW.new_id = NEW.id; + RETURN NEW; + END; + $$ + LANGUAGE plpgsql + SQL + + execute <<~SQL.squish + CREATE TRIGGER notifications_new_id_trigger BEFORE INSERT ON notifications + FOR EACH ROW EXECUTE PROCEDURE mirror_notifications_id() + SQL + end + + def down + raise ActiveRecord::IrreversibleMigration + end +end diff --git a/db/migrate/20240820123403_copy_notifications_id_values.rb b/db/migrate/20240820123403_copy_notifications_id_values.rb new file mode 100644 index 00000000000..12f1f2f6aac --- /dev/null +++ b/db/migrate/20240820123403_copy_notifications_id_values.rb @@ -0,0 +1,28 @@ +# frozen_string_literal: true + +class CopyNotificationsIdValues < ActiveRecord::Migration[7.0] + disable_ddl_transaction! + + def up + # Short-circuit if the table has been migrated already + result = + execute( + "SELECT data_type FROM information_schema.columns WHERE table_name = 'notifications' AND column_name = 'id' LIMIT 1", + ) + data_type = result[0]["data_type"] + return if data_type.downcase == "bigint" + + min_id, max_id = execute("SELECT MIN(id), MAX(id) FROM notifications")[0].values + batch_size = 10_000 + + (min_id..max_id).step(batch_size) { |start_id| execute <<~SQL } if min_id && max_id + UPDATE notifications + SET new_id = id + WHERE id >= #{start_id} AND id < #{start_id + batch_size} AND new_id != id + SQL + end + + def down + raise ActiveRecord::IrreversibleMigration + end +end diff --git a/db/migrate/20240820123404_copy_notifications_id_indexes.rb b/db/migrate/20240820123404_copy_notifications_id_indexes.rb new file mode 100644 index 00000000000..ea79bb165c8 --- /dev/null +++ b/db/migrate/20240820123404_copy_notifications_id_indexes.rb @@ -0,0 +1,39 @@ +# frozen_string_literal: true + +class CopyNotificationsIdIndexes < ActiveRecord::Migration[7.0] + disable_ddl_transaction! + + def up + # Short-circuit if the table has been migrated already + result = + execute( + "SELECT data_type FROM information_schema.columns WHERE table_name = 'notifications' AND column_name = 'id' LIMIT 1", + ) + data_type = result[0]["data_type"] + return if data_type.downcase == "bigint" + + # Copy existing indexes and suffix them with `_bigint` + results = + execute( + "SELECT indexname, indexdef FROM pg_indexes WHERE tablename = 'notifications' AND indexdef SIMILAR TO '%\\mid\\M%'", + ) + results.each do |res| + indexname, indexdef = res["indexname"], res["indexdef"] + + indexdef = indexdef.gsub(/\b#{indexname}\b/, "#{indexname}_bigint") + indexdef = + indexdef.gsub( + /\bCREATE (UNIQUE )?INDEX\b/, + "CREATE \\1INDEX CONCURRENTLY", + ) if !Rails.env.test? + indexdef = indexdef.gsub(/\bid\b/, "new_id") + + execute "DROP INDEX #{Rails.env.test? ? "" : "CONCURRENTLY"} IF EXISTS #{indexname}_bigint" + execute(indexdef) + end + end + + def down + raise ActiveRecord::IrreversibleMigration + end +end diff --git a/db/migrate/20240820123405_swap_big_int_notifications_id.rb b/db/migrate/20240820123405_swap_big_int_notifications_id.rb new file mode 100644 index 00000000000..45346ab213a --- /dev/null +++ b/db/migrate/20240820123405_swap_big_int_notifications_id.rb @@ -0,0 +1,43 @@ +# frozen_string_literal: true + +class SwapBigIntNotificationsId < ActiveRecord::Migration[7.0] + def up + # Short-circuit if the table has been migrated already + result = + execute( + "SELECT data_type FROM information_schema.columns WHERE table_name = 'notifications' AND column_name = 'id' LIMIT 1", + ) + data_type = result[0]["data_type"] + return if data_type.downcase == "bigint" + + # Necessary to rename and drop columns + Migration::SafeMigrate.disable! + + # Drop trigger and function used to replicate new values + execute "DROP TRIGGER notifications_new_id_trigger ON notifications" + execute "DROP FUNCTION mirror_notifications_id()" + + # Move sequence to new column + execute "ALTER TABLE notifications ALTER COLUMN id DROP DEFAULT" + execute "ALTER TABLE notifications ALTER COLUMN new_id SET DEFAULT nextval('notifications_id_seq'::regclass)" + execute "ALTER SEQUENCE notifications_id_seq OWNED BY notifications.new_id" + + # Swap columns + execute "ALTER TABLE notifications RENAME COLUMN id TO old_id" + execute "ALTER TABLE notifications RENAME COLUMN new_id TO id" + + # Recreate primary key + execute "ALTER TABLE notifications DROP CONSTRAINT notifications_pkey" + execute "ALTER TABLE notifications ADD CONSTRAINT notifications_pkey PRIMARY KEY USING INDEX notifications_pkey_bigint" + + # Keep old column and mark it as read only + execute "ALTER TABLE notifications ALTER COLUMN old_id DROP NOT NULL" + Migration::ColumnDropper.mark_readonly(:notifications, :old_id) + ensure + Migration::SafeMigrate.enable! + end + + def down + raise ActiveRecord::IrreversibleMigration + end +end diff --git a/db/migrate/20240820123406_drop_old_notification_id_indexes.rb b/db/migrate/20240820123406_drop_old_notification_id_indexes.rb new file mode 100644 index 00000000000..eebad27b97e --- /dev/null +++ b/db/migrate/20240820123406_drop_old_notification_id_indexes.rb @@ -0,0 +1,33 @@ +# frozen_string_literal: true + +class DropOldNotificationIdIndexes < ActiveRecord::Migration[7.0] + disable_ddl_transaction! + + def up + # Drop old indexes + results = + execute( + "SELECT indexname, indexdef FROM pg_indexes WHERE tablename = 'notifications' AND indexdef SIMILAR TO '%\\mold_id\\M%'", + ) + results.each do |res| + indexname, indexdef = res["indexname"], res["indexdef"] + execute "DROP INDEX #{Rails.env.test? ? "" : "CONCURRENTLY"} IF EXISTS #{indexname}" + end + + # Remove `_bigint` suffix from indexes + results = + execute( + "SELECT indexname, indexdef FROM pg_indexes WHERE tablename = 'notifications' AND indexdef SIMILAR TO '%\\mid\\M%'", + ) + results.each do |res| + indexname, indexdef = res["indexname"], res["indexdef"] + if indexname.include?("_bigint") + execute "ALTER INDEX #{indexname} RENAME TO #{indexname.gsub(/_bigint$/, "")}" + end + end + end + + def down + raise ActiveRecord::IrreversibleMigration + end +end