Add scheduled events schema (#1679)

This commit is contained in:
Luke Vella 2025-04-22 14:28:15 +01:00 committed by GitHub
parent 22f32f9314
commit 56bd684c55
No known key found for this signature in database
GPG key ID: B5690EEEBB952194
35 changed files with 1412 additions and 659 deletions

View file

@ -0,0 +1,87 @@
-- CreateEnum
CREATE TYPE "scheduled_event_status" AS ENUM ('confirmed', 'canceled', 'unconfirmed');
-- CreateEnum
CREATE TYPE "scheduled_event_invite_status" AS ENUM ('pending', 'accepted', 'declined', 'tentative');
-- CreateTable
CREATE TABLE "scheduled_events" (
"id" TEXT NOT NULL,
"user_id" TEXT NOT NULL,
"title" TEXT NOT NULL,
"description" TEXT,
"location" TEXT,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
"status" "scheduled_event_status" NOT NULL DEFAULT 'confirmed',
"time_zone" TEXT,
"start" TIMESTAMP(3) NOT NULL,
"end" TIMESTAMP(3) NOT NULL,
"all_day" BOOLEAN NOT NULL DEFAULT false,
"deleted_at" TIMESTAMP(3),
CONSTRAINT "scheduled_events_pkey" PRIMARY KEY ("id")
);
-- CreateTable
CREATE TABLE "rescheduled_event_dates" (
"id" TEXT NOT NULL,
"scheduled_event_id" TEXT NOT NULL,
"start" TIMESTAMP(3) NOT NULL,
"end" TIMESTAMP(3) NOT NULL,
"all_day" BOOLEAN NOT NULL DEFAULT false,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT "rescheduled_event_dates_pkey" PRIMARY KEY ("id")
);
-- CreateTable
CREATE TABLE "scheduled_event_invites" (
"id" TEXT NOT NULL,
"scheduled_event_id" TEXT NOT NULL,
"invitee_name" TEXT NOT NULL,
"invitee_email" TEXT NOT NULL,
"invitee_id" TEXT,
"invitee_time_zone" TEXT,
"status" "scheduled_event_invite_status" NOT NULL DEFAULT 'pending',
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
CONSTRAINT "scheduled_event_invites_pkey" PRIMARY KEY ("id")
);
-- CreateIndex
CREATE INDEX "rescheduled_event_dates_scheduled_event_id_idx" ON "rescheduled_event_dates"("scheduled_event_id");
-- CreateIndex
CREATE INDEX "scheduled_event_invites_scheduled_event_id_idx" ON "scheduled_event_invites"("scheduled_event_id");
-- CreateIndex
CREATE INDEX "scheduled_event_invites_invitee_id_idx" ON "scheduled_event_invites"("invitee_id");
-- CreateIndex
CREATE INDEX "scheduled_event_invites_invitee_email_idx" ON "scheduled_event_invites"("invitee_email");
-- CreateIndex
CREATE UNIQUE INDEX "scheduled_event_invites_scheduled_event_id_invitee_email_key" ON "scheduled_event_invites"("scheduled_event_id", "invitee_email");
-- CreateIndex
CREATE UNIQUE INDEX "scheduled_event_invites_scheduled_event_id_invitee_id_key" ON "scheduled_event_invites"("scheduled_event_id", "invitee_id");
-- AddForeignKey
ALTER TABLE "scheduled_events" ADD CONSTRAINT "scheduled_events_user_id_fkey" FOREIGN KEY ("user_id") REFERENCES "users"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "rescheduled_event_dates" ADD CONSTRAINT "rescheduled_event_dates_scheduled_event_id_fkey" FOREIGN KEY ("scheduled_event_id") REFERENCES "scheduled_events"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "scheduled_event_invites" ADD CONSTRAINT "scheduled_event_invites_scheduled_event_id_fkey" FOREIGN KEY ("scheduled_event_id") REFERENCES "scheduled_events"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "scheduled_event_invites" ADD CONSTRAINT "scheduled_event_invites_invitee_id_fkey" FOREIGN KEY ("invitee_id") REFERENCES "users"("id") ON DELETE SET NULL ON UPDATE CASCADE;
-- AlterTable
ALTER TABLE "polls" ADD COLUMN "scheduled_event_id" TEXT;
-- AddForeignKey
ALTER TABLE "polls" ADD CONSTRAINT "polls_scheduled_event_id_fkey" FOREIGN KEY ("scheduled_event_id") REFERENCES "scheduled_events"("id") ON DELETE SET NULL ON UPDATE CASCADE;

View file

@ -0,0 +1,52 @@
-- Step 1: Insert data from Event into ScheduledEvent
-- Reuse Event ID for ScheduledEvent ID
-- Calculate 'end': For all-day (duration 0), end is start + 1 day. Otherwise, calculate based on duration.
-- Set 'all_day' based on 'duration_minutes'
-- Fetch 'location' and 'time_zone' from the related Poll using event_id
-- Set defaults for other fields
INSERT INTO "scheduled_events" (
"id",
"user_id",
"title",
"description",
"location",
"created_at",
"updated_at",
"status",
"time_zone",
"start",
"end",
"all_day",
"deleted_at"
)
SELECT
e."id", -- Reuse Event ID
e."user_id",
e."title",
NULL, -- Default description
p."location", -- Get location from the related Poll
e."created_at",
NOW(), -- Set updated_at to current time
'confirmed'::"scheduled_event_status", -- Default status 'confirmed'
p."time_zone", -- Get timeZone from the related Poll
e."start",
-- Calculate 'end': If duration is 0 (all-day), set end to start + 1 day. Otherwise, calculate based on duration.
CASE
WHEN e."duration_minutes" = 0 THEN e."start" + interval '1 day'
ELSE e."start" + (e."duration_minutes" * interval '1 minute')
END,
-- Set 'all_day': TRUE if duration is 0, FALSE otherwise
CASE
WHEN e."duration_minutes" = 0 THEN TRUE
ELSE FALSE
END,
NULL -- Default deletedAt to NULL
FROM
"events" e
LEFT JOIN "polls" p ON e."id" = p."event_id";
-- Step 2: Update the polls table to link to the new scheduled_event_id
-- Set scheduled_event_id = event_id where event_id was previously set
-- Only update if the corresponding ScheduledEvent was successfully created in Step 1
UPDATE "polls" p
SET "scheduled_event_id" = p."event_id"
WHERE p."event_id" IS NOT NULL;

View file

@ -0,0 +1,88 @@
-- migrate_event_votes_to_invites.sql V7
-- Migrate participants with emails from polls linked to events with a selected winning option (event.optionId)
-- into scheduled_event_invites for the corresponding scheduled_event (poll.scheduled_event_id).
-- Map the participant's vote on the winning option to the invite status.
-- Uses CTE with ROW_NUMBER() to handle potential duplicates based on email *and* user_id per scheduled event, preferring the most recent participant.
-- Uses NOT EXISTS in WHERE clause to avoid inserting invites if they already exist from other sources.
-- Reuses the participant's unique ID (pt.id) as the invite ID for this migration.
-- Excludes participants with NULL or empty string emails.
WITH PotentialInvites AS (
SELECT
pt.id as participant_id, -- Keep original participant ID for reuse
p.scheduled_event_id,
pt.name as invitee_name,
pt.email as invitee_email,
pt.user_id as invitee_id,
u.time_zone as invitee_time_zone,
v.type as vote_type,
pt.created_at as participant_created_at,
-- Assign row number partitioned by event and email, preferring most recent participant
ROW_NUMBER() OVER(PARTITION BY p.scheduled_event_id, pt.email ORDER BY pt.created_at DESC) as rn_email,
-- Assign row number partitioned by event and user_id (if not null), preferring most recent participant
CASE
WHEN pt.user_id IS NOT NULL THEN ROW_NUMBER() OVER(PARTITION BY p.scheduled_event_id, pt.user_id ORDER BY pt.created_at DESC)
ELSE NULL
END as rn_user
FROM
events e
JOIN
polls p ON e.id = p.event_id
JOIN
participants pt ON p.id = pt.poll_id
LEFT JOIN
votes v ON pt.id = v.participant_id AND e.option_id = v.option_id
LEFT JOIN
users u ON pt.user_id = u.id
WHERE
e.option_id IS NOT NULL
AND p.scheduled_event_id IS NOT NULL
AND pt.email IS NOT NULL
AND pt.email != ''
AND pt.deleted = false
)
INSERT INTO scheduled_event_invites (
id,
scheduled_event_id,
invitee_name,
invitee_email,
invitee_id,
invitee_time_zone,
status,
created_at,
updated_at
)
SELECT
pi.participant_id as id, -- Reuse participant's unique CUID as invite ID
pi.scheduled_event_id,
pi.invitee_name,
pi.invitee_email,
pi.invitee_id,
pi.invitee_time_zone,
CASE pi.vote_type
WHEN 'yes' THEN 'accepted'::scheduled_event_invite_status
WHEN 'ifNeedBe' THEN 'tentative'::scheduled_event_invite_status
WHEN 'no' THEN 'declined'::scheduled_event_invite_status
ELSE 'pending'::scheduled_event_invite_status
END as status,
NOW() as created_at,
NOW() as updated_at
FROM
PotentialInvites pi
WHERE
pi.rn_email = 1 -- Only take the first row for each email/event combo
AND (pi.invitee_id IS NULL OR pi.rn_user = 1) -- Only take the first row for each user_id/event combo (if user_id exists)
-- Check for existing invite by email for the same scheduled event
AND NOT EXISTS (
SELECT 1
FROM scheduled_event_invites sei
WHERE sei.scheduled_event_id = pi.scheduled_event_id
AND sei.invitee_email = pi.invitee_email
)
-- Check for existing invite by user ID for the same scheduled event (only if participant has a user ID)
AND (pi.invitee_id IS NULL OR NOT EXISTS (
SELECT 1
FROM scheduled_event_invites sei
WHERE sei.scheduled_event_id = pi.scheduled_event_id
AND sei.invitee_id = pi.invitee_id
));