/** * Database migration script using PrismaClient raw SQL. * Does NOT require the Prisma CLI (npx prisma) — only the runtime client. * Safe to run multiple times (all statements are idempotent). */ const { PrismaClient } = require('@prisma/client') const prisma = new PrismaClient() async function migrate() { console.log('🔧 Running database migrations...') // ─── Step 1: Ensure enum values exist ─── console.log(' [1/7] Ensuring enum values...') const enumMigrations = [ // Role enum `DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM pg_enum WHERE enumlabel = 'SERVER_ADMIN' AND enumtypid = (SELECT oid FROM pg_type WHERE typname = 'Role')) THEN ALTER TYPE "Role" ADD VALUE 'SERVER_ADMIN'; END IF; END$$;`, `DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM pg_enum WHERE enumlabel = 'TENANT_ADMIN' AND enumtypid = (SELECT oid FROM pg_type WHERE typname = 'Role')) THEN ALTER TYPE "Role" ADD VALUE 'TENANT_ADMIN'; END IF; END$$;`, `DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM pg_enum WHERE enumlabel = 'OPERATOR' AND enumtypid = (SELECT oid FROM pg_type WHERE typname = 'Role')) THEN ALTER TYPE "Role" ADD VALUE 'OPERATOR'; END IF; END$$;`, `DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM pg_enum WHERE enumlabel = 'VIEWER' AND enumtypid = (SELECT oid FROM pg_type WHERE typname = 'Role')) THEN ALTER TYPE "Role" ADD VALUE 'VIEWER'; END IF; END$$;`, // DictionaryScope enum `DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'DictionaryScope') THEN CREATE TYPE "DictionaryScope" AS ENUM ('GLOBAL', 'TENANT'); END IF; END$$;`, ] for (const sql of enumMigrations) { try { await prisma.$executeRawUnsafe(sql) } catch (e) { /* enum might already exist */ } } // ─── Step 2: Migrate old enum data ─── console.log(' [2/7] Migrating old data...') const dataMigrations = [ `UPDATE users SET role = 'SERVER_ADMIN' WHERE role = 'ADMIN'`, `UPDATE users SET role = 'OPERATOR' WHERE role = 'EDITOR'`, `UPDATE tenants SET "subscriptionStatus" = 'ACTIVE' WHERE "subscriptionStatus" = 'TRIAL'`, ] for (const sql of dataMigrations) { try { await prisma.$executeRawUnsafe(sql) } catch (e) { /* table might not exist yet */ } } // ─── Step 3: Add missing columns (idempotent) ─── console.log(' [3/7] Adding missing columns...') const columnMigrations = [ // Tenants `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "logoUrl" TEXT`, `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "logoFileKey" TEXT`, `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "hiddenIconIds" TEXT[] DEFAULT '{}'`, `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "journalSuggestions" TEXT[] DEFAULT '{}'`, `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "contactEmail" TEXT`, `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "contactPhone" TEXT`, `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "address" TEXT`, `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "notes" TEXT`, `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "maxUsers" INTEGER DEFAULT 5`, `ALTER TABLE tenants ADD COLUMN IF NOT EXISTS "maxProjects" INTEGER DEFAULT 10`, // Users `ALTER TABLE users ADD COLUMN IF NOT EXISTS "lastLoginAt" TIMESTAMP`, `ALTER TABLE users ADD COLUMN IF NOT EXISTS "emailVerified" BOOLEAN DEFAULT true`, `ALTER TABLE users ADD COLUMN IF NOT EXISTS "emailVerificationToken" TEXT`, `ALTER TABLE users ADD COLUMN IF NOT EXISTS "resetToken" TEXT`, `ALTER TABLE users ADD COLUMN IF NOT EXISTS "resetTokenExpiry" TIMESTAMP`, // Icon categories `ALTER TABLE icon_categories ADD COLUMN IF NOT EXISTS "isGlobal" BOOLEAN DEFAULT false`, `ALTER TABLE icon_categories ADD COLUMN IF NOT EXISTS "tenantId" TEXT`, // Projects `ALTER TABLE projects ADD COLUMN IF NOT EXISTS "planImageKey" TEXT`, `ALTER TABLE projects ADD COLUMN IF NOT EXISTS "planBounds" JSONB`, `ALTER TABLE projects ADD COLUMN IF NOT EXISTS "einsatzleiter" TEXT`, `ALTER TABLE projects ADD COLUMN IF NOT EXISTS "journalfuehrer" TEXT`, `ALTER TABLE projects ADD COLUMN IF NOT EXISTS "editingById" TEXT`, `ALTER TABLE projects ADD COLUMN IF NOT EXISTS "editingUserName" TEXT`, `ALTER TABLE projects ADD COLUMN IF NOT EXISTS "editingSessionId" TEXT`, `ALTER TABLE projects ADD COLUMN IF NOT EXISTS "editingStartedAt" TIMESTAMP`, `ALTER TABLE projects ADD COLUMN IF NOT EXISTS "editingHeartbeat" TIMESTAMP`, // Journal `ALTER TABLE journal_entries ADD COLUMN IF NOT EXISTS "isCorrected" BOOLEAN DEFAULT false`, `ALTER TABLE journal_entries ADD COLUMN IF NOT EXISTS "correctionOfId" TEXT`, ] let added = 0 for (const sql of columnMigrations) { try { await prisma.$executeRawUnsafe(sql) added++ } catch (e) { // Table might not exist yet — that's OK, prisma db push or first seed will create it } } console.log(` ${added}/${columnMigrations.length} column migrations executed`) // ─── Step 4: Create new tables ─── console.log(' [4/7] Creating new tables...') const tableMigrations = [ // Dictionary entries table `CREATE TABLE IF NOT EXISTS dictionary_entries ( id TEXT PRIMARY KEY DEFAULT gen_random_uuid(), word TEXT NOT NULL, scope "DictionaryScope" NOT NULL DEFAULT 'GLOBAL', "createdAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, "tenantId" TEXT REFERENCES tenants(id) ON DELETE CASCADE, UNIQUE(word, "tenantId") )`, // Rapports table `CREATE TABLE IF NOT EXISTS rapports ( id TEXT PRIMARY KEY DEFAULT gen_random_uuid(), "reportNumber" TEXT NOT NULL, token TEXT NOT NULL UNIQUE DEFAULT gen_random_uuid(), data JSONB NOT NULL DEFAULT '{}', "generatedAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, "createdAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, "updatedAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, "projectId" TEXT NOT NULL REFERENCES projects(id) ON DELETE CASCADE, "tenantId" TEXT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE, "createdById" TEXT REFERENCES users(id) ON DELETE SET NULL, UNIQUE("tenantId", "reportNumber") )`, ] for (const sql of tableMigrations) { try { await prisma.$executeRawUnsafe(sql) } catch (e) { /* table might already exist */ } } // ─── Step 5: Set safe defaults ─── console.log(' [5/7] Setting defaults...') try { await prisma.$executeRawUnsafe(`UPDATE tenants SET "subscriptionStatus" = 'ACTIVE' WHERE "subscriptionStatus" = 'TRIAL'`) } catch (e) { /* ignore */ } // ─── Step 6: Clean up orphan users ─── console.log(' [6/7] Cleaning up orphan users...') try { // Find users who are NOT SERVER_ADMIN and have NO tenant membership const orphans = await prisma.user.findMany({ where: { role: { not: 'SERVER_ADMIN' }, memberships: { none: {} }, }, select: { id: true, email: true, name: true }, }) if (orphans.length > 0) { console.log(` Found ${orphans.length} orphan user(s):`) for (const o of orphans) { console.log(` - ${o.email} (${o.name})`) } // Delete orphan users and their related data await prisma.user.deleteMany({ where: { id: { in: orphans.map(o => o.id) }, }, }) console.log(` 🗑️ ${orphans.length} orphan user(s) removed`) } else { console.log(' No orphan users found') } } catch (e) { console.log(' Orphan cleanup skipped:', e.message) } // ─── Step 7: Backfill logoFileKey from logoUrl ─── console.log(' [7/7] Backfilling logoFileKey...') try { // Extract fileKey from MinIO URLs: the path after the bucket name // e.g. http://localhost:9002/lageplan-icons/logos/tenant-xxx.png → logos/tenant-xxx.png const tenants = await prisma.tenant.findMany({ where: { logoUrl: { not: null }, logoFileKey: null }, select: { id: true, logoUrl: true }, }) for (const t of tenants) { if (!t.logoUrl) continue // Try to extract the fileKey from the URL const match = t.logoUrl.match(/logos\/[^?]+/) if (match) { await prisma.tenant.update({ where: { id: t.id }, data: { logoFileKey: match[0] }, }) } } if (tenants.length > 0) console.log(` Backfilled ${tenants.length} logo fileKey(s)`) } catch (e) { console.log(' Logo backfill skipped:', e.message) } // ─── Step 8: Drop unique constraint on rapports(tenantId, reportNumber) ─── console.log(' [8] Dropping rapports unique constraint on (tenantId, reportNumber)...') try { await prisma.$executeRawUnsafe(`ALTER TABLE "rapports" DROP CONSTRAINT IF EXISTS "rapports_tenantId_reportNumber_key"`) console.log(' Constraint dropped (or did not exist)') } catch (e) { console.log(' Constraint drop skipped:', e.message) } // ─── Step 9: Add einsatzNr column to projects ─── console.log(' [9] Adding einsatzNr column to projects...') try { await prisma.$executeRawUnsafe(`ALTER TABLE "projects" ADD COLUMN IF NOT EXISTS "einsatzNr" TEXT`) console.log(' einsatzNr column added (or already exists)') } catch (e) { console.log(' einsatzNr column skipped:', e.message) } // ─── Step 10: Make rapports.tenantId nullable ─── console.log(' [10] Making rapports.tenantId nullable...') try { await prisma.$executeRawUnsafe(`ALTER TABLE "rapports" ALTER COLUMN "tenantId" DROP NOT NULL`) console.log(' rapports.tenantId is now nullable') } catch (e) { console.log(' rapports.tenantId nullable skipped:', e.message) } // ─── Step 11: Add privacy consent columns to tenants ─── console.log(' [11] Adding privacy consent columns to tenants...') try { await prisma.$executeRawUnsafe(`ALTER TABLE "tenants" ADD COLUMN IF NOT EXISTS "privacyAccepted" BOOLEAN DEFAULT false`) await prisma.$executeRawUnsafe(`ALTER TABLE "tenants" ADD COLUMN IF NOT EXISTS "privacyAcceptedAt" TIMESTAMP`) await prisma.$executeRawUnsafe(`ALTER TABLE "tenants" ADD COLUMN IF NOT EXISTS "adminAccessAccepted" BOOLEAN DEFAULT false`) console.log(' Privacy consent columns added') } catch (e) { console.log(' Privacy consent columns skipped:', e.message) } console.log('✅ Database migrations complete') } migrate() .then(async () => { await prisma.$disconnect() }) .catch(async (e) => { console.error('Migration error:', e.message) await prisma.$disconnect() process.exit(1) })