mirror of
https://github.com/lukevella/rallly.git
synced 2025-06-12 07:31:54 +02:00
🗃️ Update db relation mode to use foreign keys
This commit is contained in:
parent
78b4ce3eb9
commit
40861f67fc
6 changed files with 163 additions and 16 deletions
|
@ -0,0 +1,3 @@
|
|||
-- AlterTable
|
||||
ALTER TABLE "users" ALTER COLUMN "name" DROP NOT NULL,
|
||||
ALTER COLUMN "email" DROP NOT NULL;
|
|
@ -0,0 +1,2 @@
|
|||
-- AlterTable
|
||||
ALTER TABLE "users" ADD COLUMN "is_guest" BOOLEAN NOT NULL DEFAULT false;
|
|
@ -0,0 +1,49 @@
|
|||
DO $$
|
||||
DECLARE
|
||||
batch_size INTEGER := 10000;
|
||||
total_rows INTEGER;
|
||||
offset_count INTEGER := 0;
|
||||
BEGIN
|
||||
-- First create a temporary table with all distinct user_ids
|
||||
CREATE TEMP TABLE missing_users AS
|
||||
WITH all_users AS (
|
||||
SELECT user_id FROM polls
|
||||
UNION
|
||||
SELECT user_id FROM comments WHERE user_id IS NOT NULL
|
||||
UNION
|
||||
SELECT user_id FROM participants WHERE user_id IS NOT NULL
|
||||
)
|
||||
SELECT DISTINCT user_id
|
||||
FROM all_users a
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM users u WHERE u.id = a.user_id
|
||||
);
|
||||
|
||||
-- Get the count
|
||||
SELECT COUNT(*) INTO total_rows FROM missing_users;
|
||||
|
||||
RAISE NOTICE 'Starting migration of % missing users', total_rows;
|
||||
|
||||
-- Process in batches
|
||||
WHILE offset_count < total_rows LOOP
|
||||
INSERT INTO users (id, is_guest, created_at)
|
||||
SELECT user_id as id, true as is_guest, NOW() as created_at
|
||||
FROM missing_users
|
||||
OFFSET offset_count
|
||||
LIMIT batch_size
|
||||
ON CONFLICT (id) DO NOTHING;
|
||||
|
||||
offset_count := offset_count + batch_size;
|
||||
|
||||
IF offset_count % 50000 = 0 THEN
|
||||
RAISE NOTICE 'Processed up to row %', offset_count;
|
||||
END IF;
|
||||
|
||||
COMMIT;
|
||||
END LOOP;
|
||||
|
||||
-- Clean up
|
||||
DROP TABLE missing_users;
|
||||
|
||||
RAISE NOTICE 'Migration complete. Processed % rows', offset_count;
|
||||
END $$;
|
|
@ -0,0 +1,34 @@
|
|||
-- Delete votes that reference non-existent polls
|
||||
DELETE FROM votes v
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM polls p
|
||||
WHERE p.id = v.poll_id
|
||||
);
|
||||
|
||||
-- Delete comments that reference non-existent polls
|
||||
DELETE FROM comments c
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM polls p
|
||||
WHERE p.id = c.poll_id
|
||||
);
|
||||
|
||||
-- Delete participants that reference non-existent polls
|
||||
DELETE FROM participants p
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM polls poll
|
||||
WHERE poll.id = p.poll_id
|
||||
);
|
||||
|
||||
-- Delete options that reference non-existent polls
|
||||
DELETE FROM options o
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM polls p
|
||||
WHERE p.id = o.poll_id
|
||||
);
|
||||
|
||||
-- Delete watchers that reference non-existent polls
|
||||
DELETE FROM watchers w
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM polls p
|
||||
WHERE p.id = w.poll_id
|
||||
);
|
|
@ -0,0 +1,71 @@
|
|||
-- DropIndex
|
||||
DROP INDEX "accounts_user_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "comments_poll_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "comments_user_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "events_user_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "options_poll_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "participants_poll_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "polls_user_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "votes_option_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "votes_participant_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "votes_poll_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "watchers_poll_id_idx";
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX "watchers_user_id_idx";
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "accounts" ADD CONSTRAINT "accounts_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "users" ADD CONSTRAINT "users_subscription_id_fkey" FOREIGN KEY ("subscription_id") REFERENCES "subscriptions"("id") ON DELETE SET NULL ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "polls" ADD CONSTRAINT "polls_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "polls" ADD CONSTRAINT "polls_event_id_fkey" FOREIGN KEY ("event_id") REFERENCES "events"("id") ON DELETE SET NULL ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "events" ADD CONSTRAINT "events_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "watchers" ADD CONSTRAINT "watchers_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "watchers" ADD CONSTRAINT "watchers_poll_id_fkey" FOREIGN KEY ("poll_id") REFERENCES "polls"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "participants" ADD CONSTRAINT "participants_poll_id_fkey" FOREIGN KEY ("poll_id") REFERENCES "polls"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "options" ADD CONSTRAINT "options_poll_id_fkey" FOREIGN KEY ("poll_id") REFERENCES "polls"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "votes" ADD CONSTRAINT "votes_participant_id_fkey" FOREIGN KEY ("participant_id") REFERENCES "participants"("id") ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "comments" ADD CONSTRAINT "comments_poll_id_fkey" FOREIGN KEY ("poll_id") REFERENCES "polls"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
||||
|
||||
-- AddForeignKey
|
||||
ALTER TABLE "comments" ADD CONSTRAINT "comments_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE SET NULL ON UPDATE CASCADE;
|
Loading…
Add table
Add a link
Reference in a new issue