From 3e390caffe3dafe098f7070116b37654782eee09 Mon Sep 17 00:00:00 2001 From: Luna Date: Mon, 20 Sep 2021 23:07:31 -0300 Subject: [PATCH] add migration to maintain data consistency on members the tables that should refer to members aren't doing so because they were declared before the members table itself. this leads to data inconsistency as members leave or get kicked or get banned from a guild, and the relevant rows on those tables ARE NOT removed as well. --- litecord/blueprints/invites.py | 2 + manage/cmd/migration/scripts/0_base.sql | 9 +++ .../scripts/13_fix_member_foreign_key.sql | 60 +++++++++++++++++++ 3 files changed, 71 insertions(+) create mode 100644 manage/cmd/migration/scripts/13_fix_member_foreign_key.sql diff --git a/litecord/blueprints/invites.py b/litecord/blueprints/invites.py index aa7dc99..a1ca0f8 100644 --- a/litecord/blueprints/invites.py +++ b/litecord/blueprints/invites.py @@ -109,6 +109,8 @@ async def _inv_check_age(inv: dict): if inv["max_age"] == 0: return + # TODO: also verify when max_uses is 0 + now = datetime.datetime.utcnow() delta_sec = (now - inv["created_at"]).total_seconds() diff --git a/manage/cmd/migration/scripts/0_base.sql b/manage/cmd/migration/scripts/0_base.sql index 857402e..873bded 100644 --- a/manage/cmd/migration/scripts/0_base.sql +++ b/manage/cmd/migration/scripts/0_base.sql @@ -414,6 +414,9 @@ CREATE TABLE IF NOT EXISTS guild_voice_channels ( CREATE TABLE IF NOT EXISTS guild_settings ( + -- NOTE: migration 13 fixes table constraints to point to + -- members instead of users this prevents descynrhonization + -- on a member leave/kick/ban user_id bigint REFERENCES users (id) ON DELETE CASCADE, guild_id bigint REFERENCES guilds (id) ON DELETE CASCADE, @@ -578,6 +581,9 @@ CREATE TABLE IF NOT EXISTS channel_overwrites ( -- makes us able to remove the channel overwrites of -- a role when its deleted (same for users, etc). target_role bigint REFERENCES roles (id) ON DELETE CASCADE, + -- NOTE: migration 13 fixes table constraints to point to + -- members instead of users this prevents descynrhonization + -- on a member leave/kick/ban target_user bigint REFERENCES users (id) ON DELETE CASCADE, -- since those are permission bit sets @@ -605,6 +611,9 @@ CREATE TABLE IF NOT EXISTS guild_whitelists ( /* Represents a role a member has. */ CREATE TABLE IF NOT EXISTS member_roles ( + -- NOTE: migration 13 fixes table constraints to point to + -- members instead of users this prevents descynrhonization + -- on a member leave/kick/ban user_id bigint REFERENCES users (id) ON DELETE CASCADE, guild_id bigint REFERENCES guilds (id) ON DELETE CASCADE, role_id bigint REFERENCES roles (id) ON DELETE CASCADE, diff --git a/manage/cmd/migration/scripts/13_fix_member_foreign_key.sql b/manage/cmd/migration/scripts/13_fix_member_foreign_key.sql new file mode 100644 index 0000000..614daaa --- /dev/null +++ b/manage/cmd/migration/scripts/13_fix_member_foreign_key.sql @@ -0,0 +1,60 @@ +BEGIN TRANSACTION; + +DELETE +FROM guild_settings +WHERE NOT EXISTS( + SELECT members.user_id + FROM members + WHERE members.user_id = guild_settings.user_id + AND members.guild_id = guild_settings.guild_id +); + +ALTER TABLE guild_settings + DROP CONSTRAINT IF EXISTS guild_settings_user_id_fkey, + DROP CONSTRAINT IF EXISTS guild_settings_guild_id_fkey, + ADD CONSTRAINT guild_settings_user_id_guild_id_fkey + FOREIGN KEY (user_id, guild_id) + REFERENCES members (user_id, guild_id) + ON DELETE CASCADE; + +DELETE +FROM member_roles +WHERE NOT EXISTS( + SELECT members.user_id + FROM members + WHERE members.user_id = member_roles.user_id + AND members.guild_id = member_roles.guild_id +); + +ALTER TABLE member_roles + DROP CONSTRAINT IF EXISTS member_roles_user_id_fkey, + DROP CONSTRAINT IF EXISTS member_roles_guild_id_fkey, + ADD CONSTRAINT member_roles_user_id_guild_id_fkey + FOREIGN KEY (user_id, guild_id) + REFERENCES members (user_id, guild_id) + ON DELETE CASCADE; + +-- To make channel_overwrites aware of guilds, we need to backfill the column +-- with data from the guild_channels table. after that, we can make a proper +-- foreign key to the members table! + +ALTER TABLE channel_overwrites + ADD COLUMN guild_id bigint DEFAULT NULL; + +UPDATE channel_overwrites + SET guild_id = guild_channels.guild_id + FROM guild_channels + WHERE guild_channels.id = channel_overwrites.channel_id; + +ALTER TABLE channel_overwrites + ALTER COLUMN guild_id DROP DEFAULT, + ALTER COLUMN guild_id SET NOT NULL; + +ALTER TABLE channel_overwrites + DROP CONSTRAINT IF EXISTS channel_overwrites_target_user_fkey, + ADD CONSTRAINT channel_overwrites_target_user_guild_id_fkey + FOREIGN KEY (target_user, guild_id) + REFERENCES members (user_id, guild_id) + ON DELETE CASCADE; + +COMMIT;