-- Migration 005: Add RBAC Permission Management, User Invitations, and Import Jobs -- -- This migration adds: -- 1. Superadmin role to UserRole enum -- 2. Permission and RolePermission tables for RBAC -- 3. UserInvitation table for email-based invitations -- 4. ImportJob table for CSV import tracking -- -- IMPORTANT: PostgreSQL requires enum values to be committed before they can be used, -- so this migration uses multiple transactions. -- ============================================================ -- TRANSACTION 1: Add new enum values -- ============================================================ -- Add 'superadmin' to UserRole enum ALTER TYPE userrole ADD VALUE IF NOT EXISTS 'superadmin'; COMMIT; -- Display progress SELECT 'Step 1 completed: UserRole enum updated with superadmin' AS progress; -- ============================================================ -- TRANSACTION 2: Create new enum types -- ============================================================ BEGIN; -- Create InvitationStatus enum DO $$ BEGIN CREATE TYPE invitationstatus AS ENUM ('pending', 'accepted', 'expired', 'revoked'); EXCEPTION WHEN duplicate_object THEN null; END $$; -- Create ImportJobStatus enum DO $$ BEGIN CREATE TYPE importjobstatus AS ENUM ('processing', 'completed', 'failed', 'partial'); EXCEPTION WHEN duplicate_object THEN null; END $$; COMMIT; -- Display progress SELECT 'Step 2 completed: New enum types created' AS progress; -- ============================================================ -- TRANSACTION 3: Create Permission and RolePermission tables -- ============================================================ BEGIN; -- Create permissions table CREATE TABLE IF NOT EXISTS permissions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), code VARCHAR NOT NULL UNIQUE, name VARCHAR NOT NULL, description TEXT, module VARCHAR NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for permissions CREATE INDEX IF NOT EXISTS idx_permissions_code ON permissions(code); CREATE INDEX IF NOT EXISTS idx_permissions_module ON permissions(module); -- Create role_permissions junction table CREATE TABLE IF NOT EXISTS role_permissions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), role userrole NOT NULL, permission_id UUID NOT NULL REFERENCES permissions(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, created_by UUID REFERENCES users(id) ON DELETE SET NULL ); -- Create indexes for role_permissions CREATE INDEX IF NOT EXISTS idx_role_permissions_role ON role_permissions(role); CREATE UNIQUE INDEX IF NOT EXISTS idx_role_permission ON role_permissions(role, permission_id); COMMIT; -- Display progress SELECT 'Step 3 completed: Permission tables created' AS progress; -- ============================================================ -- TRANSACTION 4: Create UserInvitation table -- ============================================================ BEGIN; -- Create user_invitations table CREATE TABLE IF NOT EXISTS user_invitations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR NOT NULL, token VARCHAR NOT NULL UNIQUE, role userrole NOT NULL, status invitationstatus NOT NULL DEFAULT 'pending', -- Optional pre-filled information first_name VARCHAR, last_name VARCHAR, phone VARCHAR, -- Invitation tracking invited_by UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, invited_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, expires_at TIMESTAMP WITH TIME ZONE NOT NULL, accepted_at TIMESTAMP WITH TIME ZONE, accepted_by UUID REFERENCES users(id) ON DELETE SET NULL ); -- Create indexes for user_invitations CREATE INDEX IF NOT EXISTS idx_user_invitations_email ON user_invitations(email); CREATE INDEX IF NOT EXISTS idx_user_invitations_token ON user_invitations(token); CREATE INDEX IF NOT EXISTS idx_user_invitations_status ON user_invitations(status); COMMIT; -- Display progress SELECT 'Step 4 completed: UserInvitation table created' AS progress; -- ============================================================ -- TRANSACTION 5: Create ImportJob table -- ============================================================ BEGIN; -- Create import_jobs table CREATE TABLE IF NOT EXISTS import_jobs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), filename VARCHAR NOT NULL, file_key VARCHAR, total_rows INTEGER NOT NULL, processed_rows INTEGER NOT NULL DEFAULT 0, successful_rows INTEGER NOT NULL DEFAULT 0, failed_rows INTEGER NOT NULL DEFAULT 0, status importjobstatus NOT NULL DEFAULT 'processing', errors JSONB NOT NULL DEFAULT '[]'::jsonb, -- Tracking imported_by UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, started_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, completed_at TIMESTAMP WITH TIME ZONE ); -- Create indexes for import_jobs CREATE INDEX IF NOT EXISTS idx_import_jobs_imported_by ON import_jobs(imported_by); CREATE INDEX IF NOT EXISTS idx_import_jobs_status ON import_jobs(status); CREATE INDEX IF NOT EXISTS idx_import_jobs_started_at ON import_jobs(started_at DESC); COMMIT; -- Success message SELECT 'Migration 005 completed successfully: RBAC, Invitations, and Import Jobs tables created' AS result; -- ============================================================ -- Verification Queries -- ============================================================ -- Verify UserRole enum includes superadmin SELECT enumlabel FROM pg_enum WHERE enumtypid = 'userrole'::regtype ORDER BY enumlabel; -- Verify new tables exist SELECT table_name FROM information_schema.tables WHERE table_schema = 'public' AND table_name IN ('permissions', 'role_permissions', 'user_invitations', 'import_jobs') ORDER BY table_name; -- ============================================================ -- Rollback Instructions (if needed) -- ============================================================ -- To rollback this migration, run: -- -- DROP TABLE IF EXISTS import_jobs CASCADE; -- DROP TABLE IF EXISTS user_invitations CASCADE; -- DROP TABLE IF EXISTS role_permissions CASCADE; -- DROP TABLE IF EXISTS permissions CASCADE; -- DROP TYPE IF EXISTS importjobstatus; -- DROP TYPE IF EXISTS invitationstatus; -- -- Note: Cannot remove 'superadmin' from UserRole enum without recreating the entire enum -- and updating all dependent tables. Only do this if no users have the superadmin role.