-- Migration 006: Add Dynamic Roles System (Phase 1) -- -- This migration adds support for dynamic role creation: -- 1. Creates the 'roles' table for dynamic role management -- 2. Adds 'role_id' column to 'users' table (nullable for backward compatibility) -- 3. Adds 'role_id' column to 'role_permissions' table (nullable for backward compatibility) -- -- IMPORTANT: This is Phase 1 of the migration. The old 'role' enum columns are kept -- for backward compatibility. They will be removed in Phase 4 after data migration. -- ============================================================ -- TRANSACTION 1: Create roles table -- ============================================================ BEGIN; -- Create roles table CREATE TABLE IF NOT EXISTS roles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), code VARCHAR NOT NULL UNIQUE, name VARCHAR NOT NULL, description TEXT, is_system_role BOOLEAN NOT NULL DEFAULT FALSE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, created_by UUID REFERENCES users(id) ON DELETE SET NULL ); -- Create indexes for roles CREATE INDEX IF NOT EXISTS idx_roles_code ON roles(code); CREATE INDEX IF NOT EXISTS idx_roles_is_system_role ON roles(is_system_role); COMMIT; -- Display progress SELECT 'Step 1 completed: roles table created' AS progress; -- ============================================================ -- TRANSACTION 2: Add role_id column to users table -- ============================================================ BEGIN; -- Add role_id column to users table (nullable for Phase 1) ALTER TABLE users ADD COLUMN IF NOT EXISTS role_id UUID REFERENCES roles(id) ON DELETE SET NULL; -- Create index for role_id CREATE INDEX IF NOT EXISTS idx_users_role_id ON users(role_id); COMMIT; -- Display progress SELECT 'Step 2 completed: role_id column added to users table' AS progress; -- ============================================================ -- TRANSACTION 3: Add role_id column to role_permissions table -- ============================================================ BEGIN; -- Add role_id column to role_permissions table (nullable for Phase 1) ALTER TABLE role_permissions ADD COLUMN IF NOT EXISTS role_id UUID REFERENCES roles(id) ON DELETE CASCADE; -- Create index for role_id CREATE INDEX IF NOT EXISTS idx_role_permissions_role_id ON role_permissions(role_id); COMMIT; -- Display progress SELECT 'Step 3 completed: role_id column added to role_permissions table' AS progress; -- ============================================================ -- Migration Complete -- ============================================================ SELECT ' Migration 006 completed successfully! Next steps: 1. Run Phase 2: Create seed script to populate system roles (Superadmin, Finance, Member, Guest) 2. Run Phase 3: Migrate existing data from enum to role_id 3. Run Phase 4: Remove old enum columns (after verifying data migration) Current status: - roles table created ✓ - users.role_id added (nullable) ✓ - role_permissions.role_id added (nullable) ✓ - Legacy enum columns retained for backward compatibility ✓ ' AS migration_status;