70 lines
2.6 KiB
MySQL
70 lines
2.6 KiB
MySQL
|
|
-- Step 1: Add sortOrder to Round
|
||
|
|
ALTER TABLE "Round" ADD COLUMN "sortOrder" INTEGER NOT NULL DEFAULT 0;
|
||
|
|
|
||
|
|
-- Set initial sort order by creation date within each program
|
||
|
|
UPDATE "Round" r SET "sortOrder" = sub.rn - 1
|
||
|
|
FROM (
|
||
|
|
SELECT id, ROW_NUMBER() OVER (PARTITION BY "programId" ORDER BY "createdAt") as rn
|
||
|
|
FROM "Round"
|
||
|
|
) sub
|
||
|
|
WHERE r.id = sub.id;
|
||
|
|
|
||
|
|
-- Step 2: Add programId to Project (nullable initially)
|
||
|
|
ALTER TABLE "Project" ADD COLUMN "programId" TEXT;
|
||
|
|
|
||
|
|
-- Populate programId from the round's program
|
||
|
|
UPDATE "Project" p SET "programId" = r."programId"
|
||
|
|
FROM "Round" r WHERE p."roundId" = r."id";
|
||
|
|
|
||
|
|
-- Make programId required
|
||
|
|
ALTER TABLE "Project" ALTER COLUMN "programId" SET NOT NULL;
|
||
|
|
|
||
|
|
-- Add foreign key constraint
|
||
|
|
ALTER TABLE "Project" ADD CONSTRAINT "Project_programId_fkey"
|
||
|
|
FOREIGN KEY ("programId") REFERENCES "Program"("id") ON DELETE CASCADE ON UPDATE CASCADE;
|
||
|
|
|
||
|
|
-- Step 3: Create RoundProject table
|
||
|
|
CREATE TABLE "RoundProject" (
|
||
|
|
"id" TEXT NOT NULL,
|
||
|
|
"roundId" TEXT NOT NULL,
|
||
|
|
"projectId" TEXT NOT NULL,
|
||
|
|
"status" "ProjectStatus" NOT NULL DEFAULT 'SUBMITTED',
|
||
|
|
"addedAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
|
|
||
|
|
CONSTRAINT "RoundProject_pkey" PRIMARY KEY ("id")
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Populate RoundProject from existing Project.roundId and status
|
||
|
|
INSERT INTO "RoundProject" ("id", "roundId", "projectId", "status", "addedAt")
|
||
|
|
SELECT gen_random_uuid(), p."roundId", p."id", p."status", p."createdAt"
|
||
|
|
FROM "Project" p;
|
||
|
|
|
||
|
|
-- Add indexes and unique constraint
|
||
|
|
CREATE UNIQUE INDEX "RoundProject_roundId_projectId_key" ON "RoundProject"("roundId", "projectId");
|
||
|
|
CREATE INDEX "RoundProject_roundId_idx" ON "RoundProject"("roundId");
|
||
|
|
CREATE INDEX "RoundProject_projectId_idx" ON "RoundProject"("projectId");
|
||
|
|
CREATE INDEX "RoundProject_status_idx" ON "RoundProject"("status");
|
||
|
|
|
||
|
|
-- Add foreign keys
|
||
|
|
ALTER TABLE "RoundProject" ADD CONSTRAINT "RoundProject_roundId_fkey"
|
||
|
|
FOREIGN KEY ("roundId") REFERENCES "Round"("id") ON DELETE CASCADE ON UPDATE CASCADE;
|
||
|
|
ALTER TABLE "RoundProject" ADD CONSTRAINT "RoundProject_projectId_fkey"
|
||
|
|
FOREIGN KEY ("projectId") REFERENCES "Project"("id") ON DELETE CASCADE ON UPDATE CASCADE;
|
||
|
|
|
||
|
|
-- Step 4: Drop old columns from Project
|
||
|
|
-- Drop the roundId foreign key constraint first
|
||
|
|
ALTER TABLE "Project" DROP CONSTRAINT "Project_roundId_fkey";
|
||
|
|
|
||
|
|
-- Drop the roundId index
|
||
|
|
DROP INDEX IF EXISTS "Project_roundId_idx";
|
||
|
|
|
||
|
|
-- Drop status index
|
||
|
|
DROP INDEX IF EXISTS "Project_status_idx";
|
||
|
|
|
||
|
|
-- Drop the columns
|
||
|
|
ALTER TABLE "Project" DROP COLUMN "roundId";
|
||
|
|
ALTER TABLE "Project" DROP COLUMN "status";
|
||
|
|
|
||
|
|
-- Add programId index
|
||
|
|
CREATE INDEX "Project_programId_idx" ON "Project"("programId");
|