RBAC, Permissions, and Export/Import
This commit is contained in:
20
migrations/001_add_member_since_field.sql
Normal file
20
migrations/001_add_member_since_field.sql
Normal file
@@ -0,0 +1,20 @@
|
||||
-- Migration: Add member_since field to users table
|
||||
--
|
||||
-- This field allows admins to manually set historical membership dates
|
||||
-- for users imported from the old WordPress site.
|
||||
--
|
||||
-- For new users, it can be left NULL and will default to created_at when displayed.
|
||||
-- For imported users, admins can set it to the actual date they became a member.
|
||||
|
||||
-- Add member_since column (nullable timestamp with timezone)
|
||||
ALTER TABLE users
|
||||
ADD COLUMN member_since TIMESTAMP WITH TIME ZONE;
|
||||
|
||||
-- Backfill existing active members: use created_at as default
|
||||
-- This is reasonable since they became members when they created their account
|
||||
UPDATE users
|
||||
SET member_since = created_at
|
||||
WHERE status = 'active' AND member_since IS NULL;
|
||||
|
||||
-- Success message
|
||||
SELECT 'Migration completed: member_since field added to users table' AS result;
|
||||
59
migrations/002_rename_approval_to_validation.sql
Normal file
59
migrations/002_rename_approval_to_validation.sql
Normal file
@@ -0,0 +1,59 @@
|
||||
-- Migration: Rename approval terminology to validation in database
|
||||
--
|
||||
-- Updates all user status values from:
|
||||
-- - pending_approval → pending_validation
|
||||
-- - pre_approved → pre_validated
|
||||
--
|
||||
-- This migration aligns with the client's request to change all "approval"
|
||||
-- terminology to "validation" throughout the application.
|
||||
--
|
||||
-- IMPORTANT: This migration uses multiple transactions because PostgreSQL
|
||||
-- requires enum values to be committed before they can be used.
|
||||
|
||||
-- ============================================================
|
||||
-- TRANSACTION 1: Add new enum values
|
||||
-- ============================================================
|
||||
|
||||
-- Add renamed values (approval → validation)
|
||||
ALTER TYPE userstatus ADD VALUE IF NOT EXISTS 'pending_validation';
|
||||
ALTER TYPE userstatus ADD VALUE IF NOT EXISTS 'pre_validated';
|
||||
|
||||
-- Add new status types from Phase 4 (if they don't already exist)
|
||||
ALTER TYPE userstatus ADD VALUE IF NOT EXISTS 'canceled';
|
||||
ALTER TYPE userstatus ADD VALUE IF NOT EXISTS 'expired';
|
||||
ALTER TYPE userstatus ADD VALUE IF NOT EXISTS 'abandoned';
|
||||
|
||||
-- Commit the enum additions so they can be used
|
||||
COMMIT;
|
||||
|
||||
-- Display progress
|
||||
SELECT 'Step 1 completed: New enum values added' AS progress;
|
||||
|
||||
-- ============================================================
|
||||
-- TRANSACTION 2: Update existing data
|
||||
-- ============================================================
|
||||
|
||||
-- Start a new transaction
|
||||
BEGIN;
|
||||
|
||||
-- Update pending_approval to pending_validation
|
||||
UPDATE users
|
||||
SET status = 'pending_validation'
|
||||
WHERE status = 'pending_approval';
|
||||
|
||||
-- Update pre_approved to pre_validated
|
||||
UPDATE users
|
||||
SET status = 'pre_validated'
|
||||
WHERE status = 'pre_approved';
|
||||
|
||||
-- Commit the data updates
|
||||
COMMIT;
|
||||
|
||||
-- Success message
|
||||
SELECT 'Migration completed: approval terminology updated to validation' AS result;
|
||||
|
||||
-- Note: All API endpoints and frontend components must also be updated
|
||||
-- to use 'validation' terminology instead of 'approval'
|
||||
--
|
||||
-- Note: The old enum values 'pending_approval' and 'pre_approved' will remain
|
||||
-- in the enum type but will not be used. This is normal PostgreSQL behavior.
|
||||
23
migrations/003_add_tos_acceptance.sql
Normal file
23
migrations/003_add_tos_acceptance.sql
Normal file
@@ -0,0 +1,23 @@
|
||||
-- Migration: Add Terms of Service acceptance fields to users table
|
||||
--
|
||||
-- This migration adds:
|
||||
-- - accepts_tos: Boolean field to track ToS acceptance
|
||||
-- - tos_accepted_at: Timestamp of when user accepted ToS
|
||||
|
||||
-- Add accepts_tos column (Boolean, default False)
|
||||
ALTER TABLE users
|
||||
ADD COLUMN accepts_tos BOOLEAN DEFAULT FALSE NOT NULL;
|
||||
|
||||
-- Add tos_accepted_at column (nullable timestamp)
|
||||
ALTER TABLE users
|
||||
ADD COLUMN tos_accepted_at TIMESTAMP WITH TIME ZONE;
|
||||
|
||||
-- Backfill existing users: mark as accepted with created_at date
|
||||
-- This is reasonable since existing users registered before ToS requirement
|
||||
UPDATE users
|
||||
SET accepts_tos = TRUE,
|
||||
tos_accepted_at = created_at
|
||||
WHERE created_at IS NOT NULL;
|
||||
|
||||
-- Success message
|
||||
SELECT 'Migration completed: ToS acceptance fields added to users table' AS result;
|
||||
39
migrations/004_add_reminder_tracking_fields.sql
Normal file
39
migrations/004_add_reminder_tracking_fields.sql
Normal file
@@ -0,0 +1,39 @@
|
||||
-- Migration: Add Reminder Tracking Fields to User Model
|
||||
--
|
||||
-- This migration adds fields to track reminder emails sent to users,
|
||||
-- allowing admins to see how many reminders each user has received
|
||||
-- and when the last reminder was sent.
|
||||
--
|
||||
-- This is especially helpful for older members who may need personal outreach.
|
||||
|
||||
-- Add email verification reminder tracking
|
||||
ALTER TABLE users
|
||||
ADD COLUMN email_verification_reminders_sent INTEGER DEFAULT 0 NOT NULL;
|
||||
|
||||
ALTER TABLE users
|
||||
ADD COLUMN last_email_verification_reminder_at TIMESTAMP WITH TIME ZONE;
|
||||
|
||||
-- Add event attendance reminder tracking
|
||||
ALTER TABLE users
|
||||
ADD COLUMN event_attendance_reminders_sent INTEGER DEFAULT 0 NOT NULL;
|
||||
|
||||
ALTER TABLE users
|
||||
ADD COLUMN last_event_attendance_reminder_at TIMESTAMP WITH TIME ZONE;
|
||||
|
||||
-- Add payment reminder tracking
|
||||
ALTER TABLE users
|
||||
ADD COLUMN payment_reminders_sent INTEGER DEFAULT 0 NOT NULL;
|
||||
|
||||
ALTER TABLE users
|
||||
ADD COLUMN last_payment_reminder_at TIMESTAMP WITH TIME ZONE;
|
||||
|
||||
-- Add renewal reminder tracking
|
||||
ALTER TABLE users
|
||||
ADD COLUMN renewal_reminders_sent INTEGER DEFAULT 0 NOT NULL;
|
||||
|
||||
ALTER TABLE users
|
||||
ADD COLUMN last_renewal_reminder_at TIMESTAMP WITH TIME ZONE;
|
||||
|
||||
-- Success message
|
||||
SELECT 'Migration completed: Reminder tracking fields added to users table' AS result;
|
||||
SELECT 'Admins can now track reminder counts in the dashboard' AS note;
|
||||
187
migrations/005_add_rbac_and_invitations.sql
Normal file
187
migrations/005_add_rbac_and_invitations.sql
Normal file
@@ -0,0 +1,187 @@
|
||||
-- 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.
|
||||
91
migrations/006_add_dynamic_roles.sql
Normal file
91
migrations/006_add_dynamic_roles.sql
Normal file
@@ -0,0 +1,91 @@
|
||||
-- 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;
|
||||
@@ -136,3 +136,211 @@ DROP TABLE IF EXISTS financial_reports;
|
||||
DROP TABLE IF EXISTS bylaws_documents;
|
||||
DROP TABLE IF EXISTS storage_usage;
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## Running Phase 1-4.5 Migrations (December 2025)
|
||||
|
||||
These migrations add features from client feedback phases 1-4.5:
|
||||
- Member Since field for imported users
|
||||
- Approval → Validation terminology update
|
||||
- Terms of Service acceptance tracking
|
||||
- Reminder email tracking for admin dashboard
|
||||
|
||||
### Quick Start
|
||||
|
||||
Run all migrations at once:
|
||||
|
||||
```bash
|
||||
cd backend/migrations
|
||||
psql $DATABASE_URL -f run_all_migrations.sql
|
||||
```
|
||||
|
||||
### Individual Migration Files
|
||||
|
||||
The migrations are numbered in the order they should be run:
|
||||
|
||||
1. **001_add_member_since_field.sql** - Adds editable `member_since` field for imported users
|
||||
2. **002_rename_approval_to_validation.sql** - Updates terminology from "approval" to "validation"
|
||||
3. **003_add_tos_acceptance.sql** - Adds Terms of Service acceptance tracking
|
||||
4. **004_add_reminder_tracking_fields.sql** - Adds reminder email tracking for admin dashboard
|
||||
|
||||
### Run Individual Migrations
|
||||
|
||||
```bash
|
||||
cd backend/migrations
|
||||
|
||||
# Run migrations one by one
|
||||
psql $DATABASE_URL -f 001_add_member_since_field.sql
|
||||
psql $DATABASE_URL -f 002_rename_approval_to_validation.sql
|
||||
psql $DATABASE_URL -f 003_add_tos_acceptance.sql
|
||||
psql $DATABASE_URL -f 004_add_reminder_tracking_fields.sql
|
||||
```
|
||||
|
||||
### Using psql Interactive Mode
|
||||
|
||||
```bash
|
||||
# Connect to your database
|
||||
psql $DATABASE_URL
|
||||
|
||||
# Inside psql, run:
|
||||
\i backend/migrations/001_add_member_since_field.sql
|
||||
\i backend/migrations/002_rename_approval_to_validation.sql
|
||||
\i backend/migrations/003_add_tos_acceptance.sql
|
||||
\i backend/migrations/004_add_reminder_tracking_fields.sql
|
||||
```
|
||||
|
||||
### What Each Migration Adds
|
||||
|
||||
**Migration 001 - Member Since Field:**
|
||||
- Adds `member_since` column (nullable timestamp)
|
||||
- Backfills active members with their `created_at` date
|
||||
- Allows admins to edit dates for imported users
|
||||
|
||||
**Migration 002 - Approval → Validation Terminology:**
|
||||
- Updates `pending_approval` → `pending_validation`
|
||||
- Updates `pre_approved` → `pre_validated`
|
||||
- Aligns database with client's terminology requirements
|
||||
|
||||
**Migration 003 - ToS Acceptance:**
|
||||
- Adds `accepts_tos` boolean field (default false)
|
||||
- Adds `tos_accepted_at` timestamp field
|
||||
- Backfills existing users as having accepted ToS
|
||||
|
||||
**Migration 004 - Reminder Tracking:**
|
||||
- Adds 8 fields to track reminder emails:
|
||||
- `email_verification_reminders_sent` + `last_email_verification_reminder_at`
|
||||
- `event_attendance_reminders_sent` + `last_event_attendance_reminder_at`
|
||||
- `payment_reminders_sent` + `last_payment_reminder_at`
|
||||
- `renewal_reminders_sent` + `last_renewal_reminder_at`
|
||||
- Enables admin dashboard to show users needing personal outreach
|
||||
|
||||
### Verification
|
||||
|
||||
After running migrations, verify they completed successfully:
|
||||
|
||||
```sql
|
||||
-- Check if new columns exist
|
||||
SELECT column_name, data_type
|
||||
FROM information_schema.columns
|
||||
WHERE table_name = 'users'
|
||||
AND column_name IN (
|
||||
'member_since',
|
||||
'accepts_tos',
|
||||
'tos_accepted_at',
|
||||
'email_verification_reminders_sent',
|
||||
'last_email_verification_reminder_at',
|
||||
'event_attendance_reminders_sent',
|
||||
'last_event_attendance_reminder_at',
|
||||
'payment_reminders_sent',
|
||||
'last_payment_reminder_at',
|
||||
'renewal_reminders_sent',
|
||||
'last_renewal_reminder_at'
|
||||
)
|
||||
ORDER BY column_name;
|
||||
|
||||
-- Check status values were updated
|
||||
SELECT status, COUNT(*)
|
||||
FROM users
|
||||
GROUP BY status;
|
||||
```
|
||||
|
||||
### Rollback Phase 1-4.5 Migrations (If Needed)
|
||||
|
||||
```sql
|
||||
-- Rollback 004: Remove reminder tracking fields
|
||||
ALTER TABLE users
|
||||
DROP COLUMN IF EXISTS email_verification_reminders_sent,
|
||||
DROP COLUMN IF EXISTS last_email_verification_reminder_at,
|
||||
DROP COLUMN IF EXISTS event_attendance_reminders_sent,
|
||||
DROP COLUMN IF EXISTS last_event_attendance_reminder_at,
|
||||
DROP COLUMN IF EXISTS payment_reminders_sent,
|
||||
DROP COLUMN IF EXISTS last_payment_reminder_at,
|
||||
DROP COLUMN IF EXISTS renewal_reminders_sent,
|
||||
DROP COLUMN IF EXISTS last_renewal_reminder_at;
|
||||
|
||||
-- Rollback 003: Remove ToS fields
|
||||
ALTER TABLE users
|
||||
DROP COLUMN IF EXISTS accepts_tos,
|
||||
DROP COLUMN IF EXISTS tos_accepted_at;
|
||||
|
||||
-- Rollback 002: Revert validation to approval
|
||||
UPDATE users SET status = 'pending_approval' WHERE status = 'pending_validation';
|
||||
UPDATE users SET status = 'pre_approved' WHERE status = 'pre_validated';
|
||||
|
||||
-- Rollback 001: Remove member_since field
|
||||
ALTER TABLE users DROP COLUMN IF EXISTS member_since;
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## Running Phase RBAC Migration (December 2025)
|
||||
|
||||
This migration adds RBAC permission management, user invitations, and CSV import tracking capabilities.
|
||||
|
||||
### Quick Start
|
||||
|
||||
```bash
|
||||
cd backend/migrations
|
||||
psql $DATABASE_URL -f 005_add_rbac_and_invitations.sql
|
||||
```
|
||||
|
||||
### What This Migration Adds
|
||||
|
||||
**UserRole Enum Update:**
|
||||
- Adds `superadmin` role to UserRole enum
|
||||
|
||||
**New Tables:**
|
||||
1. **permissions** - Granular permission definitions (60+ permissions)
|
||||
2. **role_permissions** - Junction table linking roles to permissions
|
||||
3. **user_invitations** - Email-based invitation tracking with tokens
|
||||
4. **import_jobs** - CSV import job tracking with error logging
|
||||
|
||||
**New Enum Types:**
|
||||
- `invitationstatus` (pending, accepted, expired, revoked)
|
||||
- `importjobstatus` (processing, completed, failed, partial)
|
||||
|
||||
### Verification
|
||||
|
||||
After running the migration, verify it completed successfully:
|
||||
|
||||
```sql
|
||||
-- Check if superadmin role exists
|
||||
SELECT enumlabel FROM pg_enum
|
||||
WHERE enumtypid = 'userrole'::regtype
|
||||
ORDER BY enumlabel;
|
||||
|
||||
-- Check if 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;
|
||||
|
||||
-- Check table structures
|
||||
\d permissions
|
||||
\d role_permissions
|
||||
\d user_invitations
|
||||
\d import_jobs
|
||||
```
|
||||
|
||||
### Next Steps After Migration
|
||||
|
||||
1. **Seed Permissions**: Run `permissions_seed.py` to populate default permissions
|
||||
2. **Upgrade Admin to Superadmin**: Update existing admin users to superadmin role
|
||||
3. **Assign Permissions**: Configure permissions for admin, member, and guest roles
|
||||
|
||||
### Rollback (If Needed)
|
||||
|
||||
```sql
|
||||
-- Remove all RBAC tables and enums
|
||||
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. Only rollback if no users have the superadmin role.
|
||||
```
|
||||
|
||||
|
||||
Reference in New Issue
Block a user