-- Migration 007: Update roles system -- Old roles: guardian, caretaker, installer -- New roles: custodian, guardian, caretaker -- Step 1: Drop old constraints ALTER TABLE user_access DROP CONSTRAINT IF EXISTS user_access_role_check; ALTER TABLE invitations DROP CONSTRAINT IF EXISTS invitations_role_check; -- Step 2: Update existing guardian records to custodian -- (The first guardian per beneficiary becomes the custodian) -- We use the one with the earliest granted_at date WITH ranked_guardians AS ( SELECT id, beneficiary_id, ROW_NUMBER() OVER (PARTITION BY beneficiary_id ORDER BY granted_at ASC, id ASC) as rn FROM user_access WHERE role = 'guardian' ) UPDATE user_access SET role = 'custodian' WHERE id IN (SELECT id FROM ranked_guardians WHERE rn = 1); -- Step 3: Update any installer roles to caretaker (fallback) UPDATE user_access SET role = 'caretaker' WHERE role = 'installer'; UPDATE invitations SET role = 'caretaker' WHERE role = 'installer'; -- Step 4: Add new CHECK constraints ALTER TABLE user_access ADD CONSTRAINT user_access_role_check CHECK (role IN ('custodian', 'guardian', 'caretaker')); ALTER TABLE invitations ADD CONSTRAINT invitations_role_check CHECK (role IN ('guardian', 'caretaker')); -- Step 5: Add unique partial index for ONE custodian per beneficiary CREATE UNIQUE INDEX IF NOT EXISTS idx_one_custodian_per_beneficiary ON user_access (beneficiary_id) WHERE role = 'custodian'; -- Verify the changes SELECT 'user_access roles after migration:' as info; SELECT role, COUNT(*) FROM user_access GROUP BY role; SELECT 'invitations roles after migration:' as info; SELECT role, COUNT(*) FROM invitations GROUP BY role;