♻️ Update relational model (#1472)

This commit is contained in:
Luke Vella 2024-12-28 10:48:52 +01:00 committed by GitHub
parent f7b0e7b820
commit f764ea9846
No known key found for this signature in database
GPG key ID: B5690EEEBB952194
6 changed files with 219 additions and 165 deletions

View file

@ -0,0 +1,139 @@
-- Clean up polls
DELETE FROM polls
WHERE user_id IS NOT NULL
AND NOT EXISTS (SELECT 1 FROM users u WHERE u.id = polls.user_id);
-- Clean up participants
DELETE FROM participants pa
WHERE NOT EXISTS (
SELECT 1 FROM polls p
WHERE p.id = pa.poll_id
);
DELETE FROM participants
WHERE user_id IS NOT NULL
AND NOT EXISTS (SELECT 1 FROM users u WHERE u.id = participants.user_id);
-- Clean up options
DELETE FROM options o
WHERE NOT EXISTS (
SELECT 1 FROM polls p
WHERE p.id = o.poll_id
);
-- Clean up votes
DELETE FROM votes v
WHERE NOT EXISTS (
SELECT 1 FROM polls p
WHERE p.id = v.poll_id
);
DELETE FROM votes v
WHERE NOT EXISTS (
SELECT 1 FROM participants p
WHERE p.poll_id = v.poll_id
AND p.id = v.participant_id
);
DELETE FROM votes v
WHERE NOT EXISTS (
SELECT 1 FROM options o
WHERE o.poll_id = v.poll_id
AND o.id = v.option_id
);
-- Clean up comments
DELETE FROM comments c
WHERE NOT EXISTS (
SELECT 1 FROM polls p
WHERE p.id = c.poll_id
);
DELETE FROM comments
WHERE user_id IS NOT NULL
AND NOT EXISTS (SELECT 1 FROM users u WHERE u.id = comments.user_id);
-- Clean up watchers
DELETE FROM watchers w
WHERE NOT EXISTS (
SELECT 1 FROM polls p
WHERE p.id = w.poll_id
);
DELETE FROM watchers
WHERE user_id IS NOT NULL
AND NOT EXISTS (SELECT 1 FROM users u WHERE u.id = watchers.user_id);
-- Clean up events
DELETE FROM events
WHERE user_id IS NOT NULL
AND NOT EXISTS (SELECT 1 FROM users u WHERE u.id = events.user_id);
-- Handle subscription updates
UPDATE users
SET subscription_id = NULL
WHERE subscription_id IS NOT NULL
AND NOT EXISTS (SELECT 1 FROM subscriptions s WHERE s.id = users.subscription_id);
-- DropIndex
DROP INDEX "accounts_user_id_idx";
-- DropIndex
DROP INDEX "comments_user_id_idx";
-- DropIndex
DROP INDEX "polls_guest_id_idx";
-- DropIndex
DROP INDEX "polls_user_id_idx";
-- DropIndex
DROP INDEX "watchers_user_id_idx";
-- CreateIndex
CREATE INDEX "polls_guest_id_idx" ON "polls"("guest_id");
-- AddForeignKey
ALTER TABLE "accounts" ADD CONSTRAINT "accounts_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE CASCADE 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 CASCADE 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 CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "watchers" ADD CONSTRAINT "watchers_poll_id_fkey" FOREIGN KEY ("poll_id") REFERENCES "polls"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "watchers" ADD CONSTRAINT "watchers_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "participants" ADD CONSTRAINT "participants_poll_id_fkey" FOREIGN KEY ("poll_id") REFERENCES "polls"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "participants" ADD CONSTRAINT "participants_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE SET NULL ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "options" ADD CONSTRAINT "options_poll_id_fkey" FOREIGN KEY ("poll_id") REFERENCES "polls"("id") ON DELETE CASCADE 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 "votes" ADD CONSTRAINT "votes_option_id_fkey" FOREIGN KEY ("option_id") REFERENCES "options"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "votes" ADD CONSTRAINT "votes_poll_id_fkey" FOREIGN KEY ("poll_id") REFERENCES "polls"("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 CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "comments" ADD CONSTRAINT "comments_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE CASCADE ON UPDATE CASCADE;

View file

@ -1,8 +1,7 @@
datasource db {
provider = "postgresql"
url = env("DATABASE_URL")
directUrl = env("DIRECT_DATABASE_URL")
relationMode = "prisma"
provider = "postgresql"
url = env("DATABASE_URL")
directUrl = env("DIRECT_DATABASE_URL")
}
generator client {
@ -31,10 +30,9 @@ model Account {
id_token String? @db.Text
session_state String?
user User @relation(fields: [userId], references: [id])
user User @relation(fields: [userId], references: [id], onDelete: Cascade)
@@unique([provider, providerAccountId])
@@index([userId], type: Hash)
@@map("accounts")
}
@ -57,8 +55,10 @@ model User {
polls Poll[]
watcher Watcher[]
events Event[]
subscription Subscription? @relation(fields: [subscriptionId], references: [id])
accounts Account[]
participants Participant[]
subscription Subscription? @relation(fields: [subscriptionId], references: [id], onDelete: SetNull)
@@map("users")
}
@ -117,52 +117,52 @@ enum PollStatus {
}
model Poll {
id String @id @unique @map("id")
createdAt DateTime @default(now()) @map("created_at")
updatedAt DateTime @updatedAt @map("updated_at")
id String @id @unique @map("id")
createdAt DateTime @default(now()) @map("created_at")
updatedAt DateTime @updatedAt @map("updated_at")
deadline DateTime?
title String
description String?
location String?
userId String? @map("user_id")
guestId String? @map("guest_id")
timeZone String? @map("time_zone")
closed Boolean @default(false) // @deprecated
status PollStatus @default(live)
deleted Boolean @default(false)
deletedAt DateTime? @map("deleted_at")
touchedAt DateTime @default(now()) @map("touched_at")
participantUrlId String @unique @map("participant_url_id")
adminUrlId String @unique @map("admin_url_id")
eventId String? @unique @map("event_id")
hideParticipants Boolean @default(false) @map("hide_participants")
hideScores Boolean @default(false) @map("hide_scores")
disableComments Boolean @default(false) @map("disable_comments")
requireParticipantEmail Boolean @default(false) @map("require_participant_email")
userId String? @map("user_id")
guestId String? @map("guest_id")
timeZone String? @map("time_zone")
closed Boolean @default(false) // @deprecated
status PollStatus @default(live)
deleted Boolean @default(false)
deletedAt DateTime? @map("deleted_at")
touchedAt DateTime @default(now()) @map("touched_at")
participantUrlId String @unique @map("participant_url_id")
adminUrlId String @unique @map("admin_url_id")
eventId String? @unique @map("event_id")
hideParticipants Boolean @default(false) @map("hide_participants")
hideScores Boolean @default(false) @map("hide_scores")
disableComments Boolean @default(false) @map("disable_comments")
requireParticipantEmail Boolean @default(false) @map("require_participant_email")
user User? @relation(fields: [userId], references: [id])
event Event? @relation(fields: [eventId], references: [id])
options Option[]
participants Participant[]
watchers Watcher[]
comments Comment[]
user User? @relation(fields: [userId], references: [id], onDelete: Cascade)
event Event? @relation(fields: [eventId], references: [id], onDelete: SetNull)
options Option[]
participants Participant[]
watchers Watcher[]
comments Comment[]
votes Vote[]
@@index([userId], type: Hash)
@@index([guestId], type: Hash)
@@index([guestId])
@@map("polls")
}
model Event {
id String @id @default(cuid())
userId String @map("user_id")
user User @relation(fields: [userId], references: [id])
user User @relation(fields: [userId], references: [id], onDelete: Cascade)
optionId String @map("option_id")
title String
start DateTime @db.Timestamp(0)
duration Int @default(0) @map("duration_minutes")
createdAt DateTime @default(now()) @map("created_at")
poll Poll?
poll Poll?
@@index([userId], type: Hash)
@@map("events")
@ -171,12 +171,12 @@ model Event {
model Watcher {
id Int @id @default(autoincrement())
userId String @map("user_id")
user User @relation(fields: [userId], references: [id])
pollId String @map("poll_id")
createdAt DateTime @default(now()) @map("created_at")
poll Poll @relation(fields: [pollId], references: [id])
@@index([userId], type: Hash)
poll Poll @relation(fields: [pollId], references: [id], onDelete: Cascade)
user User @relation(fields: [userId], references: [id], onDelete: Cascade)
@@index([pollId], type: Hash)
@@map("watchers")
}
@ -187,28 +187,34 @@ model Participant {
email String?
userId String? @map("user_id")
guestId String? @map("guest_id")
poll Poll @relation(fields: [pollId], references: [id])
pollId String @map("poll_id")
votes Vote[]
locale String?
createdAt DateTime @default(now()) @map("created_at")
updatedAt DateTime? @updatedAt @map("updated_at")
deleted Boolean @default(false)
deletedAt DateTime? @map("deleted_at")
@@index([pollId], type: Hash)
votes Vote[]
poll Poll @relation(fields: [pollId], references: [id], onDelete: Cascade)
user User? @relation(fields: [userId], references: [id], onDelete: SetNull)
@@index([guestId], type: Hash)
@@index([pollId], type: Hash)
@@map("participants")
}
model Option {
id String @id @default(cuid())
startTime DateTime @db.Timestamp(0) @map("start_time")
startTime DateTime @map("start_time") @db.Timestamp(0)
duration Int @default(0) @map("duration_minutes")
pollId String @map("poll_id")
poll Poll @relation(fields: [pollId], references: [id])
createdAt DateTime @default(now()) @map("created_at")
votes Vote[]
poll Poll @relation(fields: [pollId], references: [id], onDelete: Cascade)
@@index([pollId], type: Hash)
@@map("options")
}
@ -222,34 +228,37 @@ enum VoteType {
}
model Vote {
id String @id @default(cuid())
participant Participant @relation(fields: [participantId], references: [id], onDelete: Cascade)
participantId String @map("participant_id")
optionId String @map("option_id")
pollId String @map("poll_id")
type VoteType @default(yes)
createdAt DateTime @default(now()) @map("created_at")
updatedAt DateTime? @updatedAt @map("updated_at")
id String @id @default(cuid())
participantId String @map("participant_id")
optionId String @map("option_id")
pollId String @map("poll_id")
type VoteType @default(yes)
createdAt DateTime @default(now()) @map("created_at")
updatedAt DateTime? @updatedAt @map("updated_at")
participant Participant @relation(fields: [participantId], references: [id], onDelete: Cascade)
option Option @relation(fields: [optionId], references: [id], onDelete: Cascade)
poll Poll @relation(fields: [pollId], references: [id], onDelete: Cascade)
@@index([pollId], type: Hash)
@@index([participantId], type: Hash)
@@index([optionId], type: Hash)
@@index([pollId], type: Hash)
@@map("votes")
}
model Comment {
id String @id @default(cuid())
content String
poll Poll @relation(fields: [pollId], references: [id])
pollId String @map("poll_id")
authorName String @map("author_name")
user User? @relation(fields: [userId], references: [id])
userId String? @map("user_id")
guestId String? @map("guest_id")
createdAt DateTime @default(now()) @map("created_at")
updatedAt DateTime? @updatedAt @map("updated_at")
@@index([userId], type: Hash)
poll Poll @relation(fields: [pollId], references: [id], onDelete: Cascade)
user User? @relation(fields: [userId], references: [id], onDelete: Cascade)
@@index([guestId], type: Hash)
@@index([pollId], type: Hash)
@@map("comments")