DEV: Migrate notifications#id and related columns to bigint (#28584)

* 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.

* DEV: Fix bigint notifications id migration to deal with public schema (#28538)

Follow up to 799a45a291

* DEV: Migrate shelved_notifications#notification_id to bigint (#28549)

DEV: Migrate shelved_notifications#notification_id to bigint

The `notifications.id` has been migrated to `bigint` in previous commit
799a45a291.

* DEV: Fix annotations (#28569)

Follow-up to ec8ba5a0b9

* DEV: Migrate user_badges#notification_id to bigint (#28546)

The `notifications.id` has been migrated to bigint in previous commit
799a45a291. This commit migrates one of
the related columns, `user_badges.notification_id`, to `bigint`.

* DEV: Migrate `User#seen_notification_id` to `bigint` (#28572)

`Notification#id` was migrated to `bigint` in 799a45a291

* DEV: Migrate `Chat::NotificationMention#notification_id` to `bigint` (#28571)

`Notification#id` was migrated to `bigint` in 799a45a291

---------

Co-authored-by: Alan Guo Xiang Tan <gxtan1990@gmail.com>
This commit is contained in:
Bianca Nenciu 2024-08-29 18:06:55 +03:00 committed by GitHub
parent c4ece1a7b7
commit 15f036bafa
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
26 changed files with 564 additions and 7 deletions

View File

@ -1,6 +1,10 @@
# frozen_string_literal: true
class Notification < ActiveRecord::Base
self.ignored_columns = [
:old_id, # TODO: Remove when column is dropped. At this point, the migration to drop the column has not been writted.
]
attr_accessor :acting_user
attr_accessor :acting_username
@ -407,7 +411,6 @@ end
#
# Table name: notifications
#
# id :integer not null, primary key
# notification_type :integer not null
# user_id :integer not null
# data :string(1000) not null
@ -418,6 +421,7 @@ end
# post_number :integer
# post_action_id :integer
# high_priority :boolean default(FALSE), not null
# id :bigint not null, primary key
#
# Indexes
#

View File

@ -1,6 +1,10 @@
# frozen_string_literal: true
class ShelvedNotification < ActiveRecord::Base
self.ignored_columns = [
:old_notification_id, # TODO: Remove when column is dropped. At this point, the migration to drop the column has not been writted.
]
belongs_to :notification
def process
@ -13,7 +17,7 @@ end
# Table name: shelved_notifications
#
# id :bigint not null, primary key
# notification_id :integer not null
# notification_id :bigint not null
#
# Indexes
#

View File

@ -1,6 +1,10 @@
# frozen_string_literal: true
class User < ActiveRecord::Base
self.ignored_columns = [
:old_seen_notification_id, # TODO: Remove when column is dropped. At this point, the migration to drop the column has not been written.
]
include Searchable
include Roleable
include HasCustomFields
@ -2223,7 +2227,6 @@ end
# created_at :datetime not null
# updated_at :datetime not null
# name :string
# seen_notification_id :integer default(0), not null
# last_posted_at :datetime
# password_hash :string(64)
# salt :string(32)
@ -2259,6 +2262,7 @@ end
# last_seen_reviewable_id :integer
# password_algorithm :string(64)
# required_fields_version :integer
# seen_notification_id :bigint default(0), not null
#
# Indexes
#

View File

@ -1,6 +1,10 @@
# frozen_string_literal: true
class UserBadge < ActiveRecord::Base
self.ignored_columns = [
:old_notification_id, # TODO: Remove when column is dropped. At this point, the migration to drop the column has not been writted.
]
belongs_to :badge
belongs_to :user
belongs_to :granted_by, class_name: "User"
@ -120,11 +124,11 @@ end
# granted_at :datetime not null
# granted_by_id :integer not null
# post_id :integer
# notification_id :integer
# seq :integer default(0), not null
# featured_rank :integer
# created_at :datetime not null
# is_favorite :boolean
# notification_id :bigint
#
# Indexes
#

View File

@ -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

View File

@ -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

View File

@ -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

View File

@ -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%' AND schemaname = 'public'",
)
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

View File

@ -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

View File

@ -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%' AND schemaname = 'public'",
)
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

View File

@ -0,0 +1,30 @@
# frozen_string_literal: true
class AddBigIntShelvedNotificationsNotificationId < ActiveRecord::Migration[7.0]
def up
# Create new column
execute "ALTER TABLE shelved_notifications ADD COLUMN new_notification_id BIGINT NOT NULL DEFAULT 0"
# Mirror new `notification_id` values to `new_notification_id`
execute <<~SQL.squish
CREATE FUNCTION mirror_user_badges_notification_id()
RETURNS trigger AS
$$
BEGIN
NEW.new_notification_id = NEW.notification_id;
RETURN NEW;
END;
$$
LANGUAGE plpgsql
SQL
execute <<~SQL.squish
CREATE TRIGGER user_badges_new_notification_id_trigger BEFORE INSERT ON shelved_notifications
FOR EACH ROW EXECUTE PROCEDURE mirror_user_badges_notification_id()
SQL
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,20 @@
# frozen_string_literal: true
class CopyShelvedNotificationsNotificationIdValues < ActiveRecord::Migration[7.0]
disable_ddl_transaction!
def up
min_id, max_id = execute("SELECT MIN(id), MAX(id) FROM shelved_notifications")[0].values
batch_size = 10_000
(min_id..max_id).step(batch_size) { |start_id| execute <<~SQL.squish } if min_id && max_id
UPDATE shelved_notifications
SET new_notification_id = notification_id
WHERE id >= #{start_id} AND id < #{start_id + batch_size} AND notification_id != new_notification_id
SQL
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,14 @@
# frozen_string_literal: true
class CopyShelvedNotificationsNotificationIdIndexes < ActiveRecord::Migration[7.0]
disable_ddl_transaction!
def up
execute "DROP INDEX #{Rails.env.test? ? "" : "CONCURRENTLY"} IF EXISTS index_shelved_notifications_on_new_notification_id"
execute "CREATE INDEX #{Rails.env.test? ? "" : "CONCURRENTLY"} index_shelved_notifications_on_new_notification_id ON shelved_notifications (new_notification_id)"
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,32 @@
# frozen_string_literal: true
class SwapBigIntShelvedNotificationsNotificationId < ActiveRecord::Migration[7.0]
def up
# Necessary to rename columns and drop triggers/functions
Migration::SafeMigrate.disable!
# Drop trigger and function used to replicate new values
execute "DROP TRIGGER user_badges_new_notification_id_trigger ON shelved_notifications"
execute "DROP FUNCTION mirror_user_badges_notification_id()"
execute "ALTER TABLE shelved_notifications ALTER COLUMN new_notification_id DROP DEFAULT"
# Swap columns
execute "ALTER TABLE shelved_notifications RENAME COLUMN notification_id TO old_notification_id"
execute "ALTER TABLE shelved_notifications RENAME COLUMN new_notification_id TO notification_id"
# Keep old column and mark it as read only
execute "ALTER TABLE shelved_notifications ALTER COLUMN old_notification_id DROP NOT NULL"
Migration::ColumnDropper.mark_readonly(:shelved_notifications, :old_notification_id)
# Rename indexes
execute "DROP INDEX IF EXISTS index_shelved_notifications_on_notification_id"
execute "ALTER INDEX index_shelved_notifications_on_new_notification_id RENAME TO index_shelved_notifications_on_notification_id"
ensure
Migration::SafeMigrate.enable!
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,30 @@
# frozen_string_literal: true
class AddBigIntUserBadgesNotificationId < ActiveRecord::Migration[7.0]
def up
# Create new column
execute "ALTER TABLE user_badges ADD COLUMN new_notification_id BIGINT"
# Mirror new `notification_id` values to `new_notification_id`
execute <<~SQL.squish
CREATE FUNCTION mirror_user_badges_notification_id()
RETURNS trigger AS
$$
BEGIN
NEW.new_notification_id = NEW.notification_id;
RETURN NEW;
END;
$$
LANGUAGE plpgsql
SQL
execute <<~SQL.squish
CREATE TRIGGER user_badges_new_notification_id_trigger BEFORE INSERT ON user_badges
FOR EACH ROW EXECUTE PROCEDURE mirror_user_badges_notification_id()
SQL
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,20 @@
# frozen_string_literal: true
class CopyUserBadgesNotificationIdValues < ActiveRecord::Migration[7.0]
disable_ddl_transaction!
def up
min_id, max_id = execute("SELECT MIN(id), MAX(id) FROM user_badges")[0].values
batch_size = 10_000
(min_id..max_id).step(batch_size) { |start_id| execute <<~SQL.squish } if min_id && max_id
UPDATE user_badges
SET new_notification_id = notification_id
WHERE id >= #{start_id} AND id < #{start_id + batch_size} AND notification_id IS NOT NULL AND new_notification_id IS NULL
SQL
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,25 @@
# frozen_string_literal: true
class SwapBigIntUserBadgesNotificationId < ActiveRecord::Migration[7.0]
def up
# Necessary to rename and drop columns
Migration::SafeMigrate.disable!
# Drop trigger and function used to replicate new values
execute "DROP TRIGGER user_badges_new_notification_id_trigger ON user_badges"
execute "DROP FUNCTION mirror_user_badges_notification_id()"
# Swap columns
execute "ALTER TABLE user_badges RENAME COLUMN notification_id TO old_notification_id"
execute "ALTER TABLE user_badges RENAME COLUMN new_notification_id TO notification_id"
# Keep old column and mark it as read only
Migration::ColumnDropper.mark_readonly(:user_badges, :old_notification_id)
ensure
Migration::SafeMigrate.enable!
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,29 @@
# frozen_string_literal: true
class AddNewSeenNotificationIdToUsers < ActiveRecord::Migration[7.1]
def up
# Create new column
execute "ALTER TABLE users ADD COLUMN new_seen_notification_id BIGINT NOT NULL DEFAULT(0)"
# Mirror new `seen_notification_id` values to `new_seen_notification_id`
execute <<~SQL.squish
CREATE FUNCTION mirror_users_seen_notification_id()
RETURNS trigger AS
$$
BEGIN
NEW.new_seen_notification_id = NEW.seen_notification_id;
RETURN NEW;
END;
$$
LANGUAGE plpgsql
SQL
execute <<~SQL.squish
CREATE TRIGGER users_seen_notification_id_trigger BEFORE INSERT OR UPDATE ON users
FOR EACH ROW EXECUTE PROCEDURE mirror_users_seen_notification_id()
SQL
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,19 @@
# frozen_string_literal: true
class CopyUsersSeenNotificationIdValues < ActiveRecord::Migration[7.1]
disable_ddl_transaction!
def up
min_id, max_id = execute("SELECT MIN(id), MAX(id) FROM users")[0].values
batch_size = 10_000
(min_id..max_id).step(batch_size) { |start_id| execute <<~SQL.squish } if min_id && max_id
UPDATE users
SET new_seen_notification_id = seen_notification_id
WHERE id >= #{start_id} AND id < #{start_id + batch_size} AND new_seen_notification_id != seen_notification_id
SQL
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,26 @@
# frozen_string_literal: true
class SwapSeenNotificationIdWithSeenNotificationIdOnUsers < ActiveRecord::Migration[7.1]
def up
# Necessary to rename and drop columns
Migration::SafeMigrate.disable!
# Drop trigger and function used to replicate new values
execute "DROP TRIGGER users_seen_notification_id_trigger ON users"
execute "DROP FUNCTION mirror_users_seen_notification_id()"
# Swap columns
execute "ALTER TABLE users RENAME COLUMN seen_notification_id TO old_seen_notification_id"
execute "ALTER TABLE users RENAME COLUMN new_seen_notification_id TO seen_notification_id"
execute "ALTER TABLE users ALTER COLUMN old_seen_notification_id DROP NOT NULL"
execute "ALTER TABLE users ALTER COLUMN old_seen_notification_id DROP DEFAULT"
# Keep old column and mark it as read only
Migration::ColumnDropper.mark_readonly(:users, :old_seen_notification_id)
ensure
Migration::SafeMigrate.enable!
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -259,7 +259,12 @@ task "db:migrate" => %w[
ActiveRecord::Tasks::DatabaseTasks.migrate
SeedFu.quiet = true
SeedFu.seed(SeedHelper.paths, SeedHelper.filter)
begin
SeedFu.seed(SeedHelper.paths, SeedHelper.filter)
rescue => error
error.backtrace.each { |l| puts l }
end
Rake::Task["db:schema:cache:dump"].invoke if Rails.env.development? && !ENV["RAILS_DB"]

View File

@ -4,6 +4,10 @@ module Chat
class MentionNotification < ActiveRecord::Base
self.table_name = "chat_mention_notifications"
self.ignored_columns = [
:old_notification_id, # TODO remove once this column is removed. Migration to drop the column has not been written.
]
belongs_to :chat_mention, class_name: "Chat::Mention"
belongs_to :notification, dependent: :destroy
end
@ -13,8 +17,8 @@ end
#
# Table name: chat_mention_notifications
#
# chat_mention_id :integer not null
# notification_id :integer not null
# chat_mention_id :integer not null
# notification_id :bigint not null
#
# Indexes
#

View File

@ -0,0 +1,29 @@
# frozen_string_literal: true
class AddNewNotificationIdToChatMentionNotifications < ActiveRecord::Migration[7.1]
def up
# Create new column
execute "ALTER TABLE chat_mention_notifications ADD COLUMN new_notification_id BIGINT NOT NULL DEFAULT(0)"
# Mirror new `notification_id` values to `new_notification_id`
execute(<<~SQL)
CREATE FUNCTION mirror_chat_mention_notifications_notification_id()
RETURNS trigger AS
$$
BEGIN
NEW.new_notification_id = NEW.notification_id;
RETURN NEW;
END;
$$
LANGUAGE plpgsql
SQL
execute(<<~SQL)
CREATE TRIGGER chat_mention_notifications_new_notification_id_trigger BEFORE INSERT ON chat_mention_notifications
FOR EACH ROW EXECUTE PROCEDURE mirror_chat_mention_notifications_notification_id()
SQL
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,22 @@
# frozen_string_literal: true
class CopyChatMentionNotificationsNotificationIdValues < ActiveRecord::Migration[7.1]
disable_ddl_transaction!
def up
min_id, max_id =
execute("SELECT MIN(notification_id), MAX(notification_id) FROM chat_mention_notifications")[
0
].values
batch_size = 10_000
(min_id..max_id).step(batch_size) { |start_id| execute <<~SQL.squish } if min_id && max_id
UPDATE chat_mention_notifications
SET new_notification_id = notification_id
WHERE notification_id >= #{start_id} AND notification_id < #{start_id + batch_size} AND new_notification_id != notification_id
SQL
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,13 @@
# frozen_string_literal: true
class CopyChatMentionNotificationsNotificationIdIndexes < ActiveRecord::Migration[7.1]
disable_ddl_transaction!
def up
execute "DROP INDEX #{Rails.env.test? ? "" : "CONCURRENTLY "} IF EXISTS index_chat_mention_notifications_on_new_notification_id"
execute "CREATE UNIQUE INDEX #{Rails.env.test? ? "" : "CONCURRENTLY "} index_chat_mention_notifications_on_new_notification_id ON chat_mention_notifications (new_notification_id)"
end
def down
raise ActiveRecord::IrreversibleMigration
end
end

View File

@ -0,0 +1,31 @@
# frozen_string_literal: true
class SwapBigintChatMentionNotificationsNotificationId < ActiveRecord::Migration[7.1]
def up
# Necessary to rename and drop trigger/function
Migration::SafeMigrate.disable!
# Drop trigger and function used to replicate new values
execute "DROP TRIGGER chat_mention_notifications_new_notification_id_trigger ON chat_mention_notifications"
execute "DROP FUNCTION mirror_chat_mention_notifications_notification_id()"
# Swap columns
execute "ALTER TABLE chat_mention_notifications RENAME COLUMN notification_id TO old_notification_id"
execute "ALTER TABLE chat_mention_notifications RENAME COLUMN new_notification_id TO notification_id"
# Drop old indexes
execute "DROP INDEX index_chat_mention_notifications_on_notification_id"
execute "ALTER INDEX index_chat_mention_notifications_on_new_notification_id RENAME TO index_chat_mention_notifications_on_notification_id"
execute "ALTER TABLE chat_mention_notifications ALTER COLUMN old_notification_id DROP NOT NULL"
execute "ALTER TABLE chat_mention_notifications ALTER COLUMN notification_id DROP DEFAULT"
# Keep old column and mark it as read only
Migration::ColumnDropper.mark_readonly(:chat_mention_notifications, :old_notification_id)
ensure
Migration::SafeMigrate.enable!
end
def down
raise ActiveRecord::IrreversibleMigration
end
end