# MOPC Platform - Database Design ## Overview The MOPC platform uses PostgreSQL as its primary database, accessed via Prisma ORM. The schema is designed for: 1. **Type Safety**: Prisma generates TypeScript types from the schema 2. **Extensibility**: JSON fields allow future attributes without migrations 3. **Auditability**: All significant changes are logged 4. **Performance**: Strategic indexes for common query patterns ## Entity Relationship Diagram ``` ┌─────────────┐ │ Program │ │─────────────│ │ id │ │ name │ │ year │ │ status │ └──────┬──────┘ │ 1:N ▼ ┌─────────────┐ ┌─────────────────┐ │ Round │ │ EvaluationForm │ │─────────────│ │─────────────────│ │ id │◄──────►│ id │ │ programId │ 1:N │ roundId │ │ name │ │ version │ │ status │ │ criteriaJson │ │ votingStart │ │ scalesJson │ │ votingEnd │ └─────────────────┘ │ settings │ └──────┬──────┘ │ 1:N ▼ ┌─────────────┐ ┌─────────────────┐ │ Project │ │ ProjectFile │ │─────────────│ │─────────────────│ │ id │◄──────►│ id │ │ roundId │ 1:N │ projectId │ │ title │ │ fileType │ │ teamName │ │ bucket │ │ description │ │ objectKey │ │ status │ │ mimeType │ │ tags[] │ │ size │ │ metadata │ └─────────────────┘ └──────┬──────┘ │ │ N:M (via Assignment) │ ┌──────┴──────┐ │ Assignment │ │─────────────│ │ id │ │ userId │◄─────────┐ │ projectId │ │ │ roundId │ │ │ method │ │ │ completed │ │ └──────┬──────┘ │ │ 1:1 │ ▼ │ ┌─────────────┐ ┌─────┴───────┐ │ Evaluation │ │ User │ │─────────────│ │─────────────│ │ id │ │ id │ │ assignmentId│ │ email │ │ status │ │ name │ │ scores │ │ role │ │ globalScore │ │ status │ │ decision │ │ expertise[] │ │ feedback │ │ metadata │ └─────────────┘ └─────────────┘ ┌─────────────┐ │ AuditLog │ │─────────────│ │ id │ │ userId │ │ action │ │ entityType │ │ entityId │ │ details │ │ ipAddress │ │ timestamp │ └─────────────┘ ┌─────────────────────┐ │ SystemSettings │ │─────────────────────│ │ id │ │ key │ │ value │ │ type │ │ category │ │ description │ │ updatedAt │ │ updatedBy │ └─────────────────────┘ ┌─────────────────────┐ │ GracePeriod │ │─────────────────────│ │ id │ │ roundId │ │ userId │ │ projectId (opt) │ │ extendedUntil │ │ reason │ │ grantedBy │ │ createdAt │ └─────────────────────┘ ``` ## Prisma Schema ```prisma // prisma/schema.prisma generator client { provider = "prisma-client-js" } datasource db { provider = "postgresql" url = env("DATABASE_URL") } // ============================================================================= // ENUMS // ============================================================================= enum UserRole { SUPER_ADMIN PROGRAM_ADMIN JURY_MEMBER OBSERVER } enum UserStatus { INVITED ACTIVE SUSPENDED } enum ProgramStatus { DRAFT ACTIVE ARCHIVED } enum RoundStatus { DRAFT ACTIVE CLOSED ARCHIVED } enum ProjectStatus { SUBMITTED ELIGIBLE ASSIGNED SEMIFINALIST FINALIST REJECTED } enum EvaluationStatus { NOT_STARTED DRAFT SUBMITTED LOCKED } enum AssignmentMethod { MANUAL AUTO BULK } enum FileType { EXEC_SUMMARY PRESENTATION VIDEO OTHER } // ============================================================================= // USERS & AUTHENTICATION // ============================================================================= model User { id String @id @default(cuid()) email String @unique name String? role UserRole @default(JURY_MEMBER) status UserStatus @default(INVITED) expertiseTags String[] @default([]) metadataJson Json? @db.JsonB createdAt DateTime @default(now()) updatedAt DateTime @updatedAt lastLoginAt DateTime? // Relations assignments Assignment[] auditLogs AuditLog[] // Indexes @@index([email]) @@index([role]) @@index([status]) } // NextAuth.js required models model Account { id String @id @default(cuid()) userId String type String provider String providerAccountId String refresh_token String? @db.Text access_token String? @db.Text expires_at Int? token_type String? scope String? id_token String? @db.Text session_state String? @@unique([provider, providerAccountId]) } model Session { id String @id @default(cuid()) sessionToken String @unique userId String expires DateTime } model VerificationToken { identifier String token String @unique expires DateTime @@unique([identifier, token]) } // ============================================================================= // PROGRAMS & ROUNDS // ============================================================================= model Program { id String @id @default(cuid()) name String // e.g., "Monaco Ocean Protection Challenge" year Int // e.g., 2026 status ProgramStatus @default(DRAFT) description String? settingsJson Json? @db.JsonB createdAt DateTime @default(now()) updatedAt DateTime @updatedAt // Relations rounds Round[] // Indexes @@unique([name, year]) @@index([status]) } model Round { id String @id @default(cuid()) programId String name String // e.g., "Round 1 - Semi-Finalists" status RoundStatus @default(DRAFT) // Voting window votingStartAt DateTime? votingEndAt DateTime? // Configuration requiredReviews Int @default(3) // Min evaluations per project settingsJson Json? @db.JsonB // Grace periods, visibility rules, etc. createdAt DateTime @default(now()) updatedAt DateTime @updatedAt // Relations program Program @relation(fields: [programId], references: [id], onDelete: Cascade) projects Project[] assignments Assignment[] evaluationForms EvaluationForm[] // Indexes @@index([programId]) @@index([status]) @@index([votingStartAt, votingEndAt]) } model EvaluationForm { id String @id @default(cuid()) roundId String version Int @default(1) // Form configuration criteriaJson Json @db.JsonB // Array of criteria with labels, scales scalesJson Json? @db.JsonB // Scale definitions (1-5, 1-10, etc.) isActive Boolean @default(false) createdAt DateTime @default(now()) updatedAt DateTime @updatedAt // Relations round Round @relation(fields: [roundId], references: [id], onDelete: Cascade) evaluations Evaluation[] // Indexes @@unique([roundId, version]) @@index([roundId, isActive]) } // ============================================================================= // PROJECTS // ============================================================================= model Project { id String @id @default(cuid()) roundId String // Core fields title String teamName String? description String? @db.Text status ProjectStatus @default(SUBMITTED) // Flexible fields tags String[] @default([]) // "Ocean Conservation", "Tech", etc. metadataJson Json? @db.JsonB // Custom fields from Typeform, etc. externalIdsJson Json? @db.JsonB // Typeform ID, Notion ID, etc. createdAt DateTime @default(now()) updatedAt DateTime @updatedAt // Relations round Round @relation(fields: [roundId], references: [id], onDelete: Cascade) files ProjectFile[] assignments Assignment[] // Indexes @@index([roundId]) @@index([status]) @@index([tags]) } model ProjectFile { id String @id @default(cuid()) projectId String // File info fileType FileType fileName String mimeType String size Int // bytes // MinIO location bucket String objectKey String createdAt DateTime @default(now()) // Relations project Project @relation(fields: [projectId], references: [id], onDelete: Cascade) // Indexes @@index([projectId]) @@index([fileType]) @@unique([bucket, objectKey]) } // ============================================================================= // ASSIGNMENTS & EVALUATIONS // ============================================================================= model Assignment { id String @id @default(cuid()) userId String projectId String roundId String // Assignment info method AssignmentMethod @default(MANUAL) isRequired Boolean @default(true) isCompleted Boolean @default(false) createdAt DateTime @default(now()) createdBy String? // Admin who created the assignment // Relations user User @relation(fields: [userId], references: [id], onDelete: Cascade) project Project @relation(fields: [projectId], references: [id], onDelete: Cascade) round Round @relation(fields: [roundId], references: [id], onDelete: Cascade) evaluation Evaluation? // Constraints @@unique([userId, projectId, roundId]) // Indexes @@index([userId]) @@index([projectId]) @@index([roundId]) @@index([isCompleted]) } model Evaluation { id String @id @default(cuid()) assignmentId String @unique formId String // Status status EvaluationStatus @default(NOT_STARTED) // Scores criterionScoresJson Json? @db.JsonB // { "criterion1": 4, "criterion2": 5 } globalScore Int? // 1-10 binaryDecision Boolean? // Yes/No for semi-finalist feedbackText String? @db.Text // Versioning version Int @default(1) // Timestamps createdAt DateTime @default(now()) updatedAt DateTime @updatedAt submittedAt DateTime? // Relations assignment Assignment @relation(fields: [assignmentId], references: [id], onDelete: Cascade) form EvaluationForm @relation(fields: [formId], references: [id]) // Indexes @@index([status]) @@index([submittedAt]) } // ============================================================================= // AUDIT LOGGING // ============================================================================= model AuditLog { id String @id @default(cuid()) userId String? // Event info action String // "CREATE", "UPDATE", "DELETE", "LOGIN", "EXPORT", etc. entityType String // "Round", "Project", "Evaluation", etc. entityId String? // Details detailsJson Json? @db.JsonB // Before/after values, additional context // Request info ipAddress String? userAgent String? timestamp DateTime @default(now()) // Relations user User? @relation(fields: [userId], references: [id], onDelete: SetNull) // Indexes @@index([userId]) @@index([action]) @@index([entityType, entityId]) @@index([timestamp]) } ``` ## Indexing Strategy ### Primary Indexes (Automatic) - All `@id` fields have primary key indexes - All `@unique` constraints have unique indexes ### Query-Optimized Indexes | Table | Index | Purpose | |-------|-------|---------| | User | `email` | Login lookup | | User | `role` | Filter by role | | User | `status` | Filter active users | | Program | `status` | List active programs | | Round | `programId` | Get rounds for program | | Round | `status` | Filter active rounds | | Round | `votingStartAt, votingEndAt` | Check voting window | | Project | `roundId` | Get projects in round | | Project | `status` | Filter by status | | Project | `tags` | Filter by tag (GIN index) | | Assignment | `userId` | Get user's assignments | | Assignment | `projectId` | Get project's reviewers | | Assignment | `roundId` | Get all assignments for round | | Assignment | `isCompleted` | Track progress | | Evaluation | `status` | Filter by completion | | Evaluation | `submittedAt` | Sort by submission time | | AuditLog | `timestamp` | Time-based queries | | AuditLog | `entityType, entityId` | Entity history | ### JSON Field Indexes For PostgreSQL JSONB fields, we can add GIN indexes for complex queries: ```sql -- Add via migration if needed CREATE INDEX idx_project_metadata ON "Project" USING GIN ("metadataJson"); CREATE INDEX idx_evaluation_scores ON "Evaluation" USING GIN ("criterionScoresJson"); ``` ## Migration Strategy ### Development ```bash # Push schema changes directly (no migration files) npx prisma db push # Generate client after schema changes npx prisma generate ``` ### Production ```bash # Create migration from schema changes npx prisma migrate dev --name description_of_change # Apply migrations in production npx prisma migrate deploy ``` ### Migration Best Practices 1. **Never** use `db push` in production 2. **Always** backup before migrations 3. **Test** migrations on staging first 4. **Review** generated SQL before applying 5. **Keep** migrations small and focused ## Data Seeding ```typescript // prisma/seed.ts import { PrismaClient, UserRole, ProgramStatus, RoundStatus } from '@prisma/client' const prisma = new PrismaClient() async function main() { // Create super admin const admin = await prisma.user.upsert({ where: { email: 'admin@mopc.org' }, update: {}, create: { email: 'admin@mopc.org', name: 'System Admin', role: UserRole.SUPER_ADMIN, status: 'ACTIVE', }, }) // Create sample program const program = await prisma.program.upsert({ where: { name_year: { name: 'Monaco Ocean Protection Challenge', year: 2026 } }, update: {}, create: { name: 'Monaco Ocean Protection Challenge', year: 2026, status: ProgramStatus.ACTIVE, description: 'Annual ocean conservation startup competition', }, }) // Create Round 1 const round1 = await prisma.round.create({ data: { programId: program.id, name: 'Round 1 - Semi-Finalists Selection', status: RoundStatus.DRAFT, requiredReviews: 3, votingStartAt: new Date('2026-02-18'), votingEndAt: new Date('2026-02-23'), }, }) // Create evaluation form for Round 1 await prisma.evaluationForm.create({ data: { roundId: round1.id, version: 1, isActive: true, criteriaJson: [ { id: 'need_clarity', label: 'Need clarity', scale: '1-5', weight: 1 }, { id: 'solution_relevance', label: 'Solution relevance', scale: '1-5', weight: 1 }, { id: 'gap_analysis', label: 'Gap analysis', scale: '1-5', weight: 1 }, { id: 'target_customers', label: 'Target customers clarity', scale: '1-5', weight: 1 }, { id: 'ocean_impact', label: 'Ocean impact', scale: '1-5', weight: 1 }, ], scalesJson: { '1-5': { min: 1, max: 5, labels: { 1: 'Poor', 3: 'Average', 5: 'Excellent' } }, '1-10': { min: 1, max: 10, labels: { 1: 'Poor', 5: 'Average', 10: 'Excellent' } }, }, }, }) console.log('Seed completed') } main() .catch((e) => { console.error(e) process.exit(1) }) .finally(async () => { await prisma.$disconnect() }) ``` Run seed: ```bash npx prisma db seed ``` ## Query Patterns ### Get Jury's Assigned Projects ```typescript const assignments = await prisma.assignment.findMany({ where: { userId: currentUser.id, round: { status: 'ACTIVE', }, }, include: { project: { include: { files: true, }, }, evaluation: true, }, }) ``` ### Get Project Evaluation Stats ```typescript const stats = await prisma.evaluation.groupBy({ by: ['status'], where: { assignment: { projectId: projectId, }, }, _count: true, }) ``` ### Check Voting Window ```typescript const isVotingOpen = await prisma.round.findFirst({ where: { id: roundId, status: 'ACTIVE', votingStartAt: { lte: new Date() }, votingEndAt: { gte: new Date() }, }, }) ``` ## Backup Strategy ### Automated Backups ```bash # Daily backup cron job 0 2 * * * pg_dump -h localhost -U mopc -d mopc -F c -f /backups/mopc_$(date +\%Y\%m\%d).dump # Keep last 30 days find /backups -name "mopc_*.dump" -mtime +30 -delete ``` ### Manual Backup ```bash docker exec -t mopc-postgres pg_dump -U mopc mopc > backup.sql ``` ### Restore ```bash docker exec -i mopc-postgres psql -U mopc mopc < backup.sql ``` ## Related Documentation - [API Design](./api.md) - How the database is accessed via tRPC - [Infrastructure](./infrastructure.md) - PostgreSQL deployment