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.
This commit is contained in:
Luna 2021-09-20 23:07:31 -03:00
parent 4cae4e240d
commit 3e390caffe
3 changed files with 71 additions and 0 deletions

View File

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

View File

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

View File

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