-- ============================================================================ -- Create Tables Only (ENUMs already exist) -- Run this when ENUMs exist but tables don't -- ============================================================================ BEGIN; -- ============================================================================ -- STEP 1: Core Tables -- ============================================================================ -- Users table CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255) NOT NULL, first_name VARCHAR(100) NOT NULL, last_name VARCHAR(100) NOT NULL, phone VARCHAR(20), address TEXT, city VARCHAR(100), state VARCHAR(2), zipcode VARCHAR(10), date_of_birth DATE, -- Profile profile_image_url TEXT, bio TEXT, interests TEXT, -- Partner Information partner_first_name VARCHAR(100), partner_last_name VARCHAR(100), partner_is_member BOOLEAN DEFAULT FALSE, partner_plan_to_become_member BOOLEAN DEFAULT FALSE, -- Referral referred_by_member_name VARCHAR(200), -- Newsletter Preferences newsletter_subscribed BOOLEAN DEFAULT TRUE, newsletter_publish_name BOOLEAN DEFAULT FALSE, newsletter_publish_photo BOOLEAN DEFAULT FALSE, newsletter_publish_birthday BOOLEAN DEFAULT FALSE, newsletter_publish_none BOOLEAN DEFAULT FALSE, -- Volunteer & Scholarship volunteer_interests TEXT, scholarship_requested BOOLEAN DEFAULT FALSE, -- Directory show_in_directory BOOLEAN DEFAULT TRUE, -- Lead Sources (JSON array) lead_sources JSONB DEFAULT '[]'::jsonb, -- Status & Role status userstatus DEFAULT 'pending_email' NOT NULL, role userrole DEFAULT 'guest' NOT NULL, role_id UUID, -- Rejection Tracking rejection_reason TEXT, rejected_at TIMESTAMP WITH TIME ZONE, rejected_by UUID REFERENCES users(id), -- Membership member_since DATE, accepts_tos BOOLEAN DEFAULT FALSE, tos_accepted_at TIMESTAMP WITH TIME ZONE, -- Reminder Tracking (from migration 004) email_verification_reminders_sent INTEGER DEFAULT 0 NOT NULL, last_email_verification_reminder_at TIMESTAMP WITH TIME ZONE, event_attendance_reminders_sent INTEGER DEFAULT 0 NOT NULL, last_event_attendance_reminder_at TIMESTAMP WITH TIME ZONE, payment_reminders_sent INTEGER DEFAULT 0 NOT NULL, last_payment_reminder_at TIMESTAMP WITH TIME ZONE, renewal_reminders_sent INTEGER DEFAULT 0 NOT NULL, last_renewal_reminder_at TIMESTAMP WITH TIME ZONE, -- WordPress Import Tracking import_source VARCHAR(50), import_job_id UUID, wordpress_user_id BIGINT, wordpress_registered_date TIMESTAMP WITH TIME ZONE, -- Authentication email_verified BOOLEAN DEFAULT FALSE, email_verification_token VARCHAR(255), email_verification_expires TIMESTAMP WITH TIME ZONE, password_reset_token VARCHAR(255), password_reset_expires TIMESTAMP WITH TIME ZONE, force_password_change BOOLEAN DEFAULT FALSE, -- Timestamps created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Events table CREATE TABLE IF NOT EXISTS events ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), title VARCHAR(255) NOT NULL, description TEXT, location VARCHAR(255), start_at TIMESTAMP WITH TIME ZONE NOT NULL, end_at TIMESTAMP WITH TIME ZONE NOT NULL, capacity INTEGER, published BOOLEAN DEFAULT FALSE, calendar_uid VARCHAR(255) UNIQUE, created_by UUID REFERENCES users(id), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Event RSVPs CREATE TABLE IF NOT EXISTS event_rsvps ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), event_id UUID NOT NULL REFERENCES events(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, rsvp_status rsvpstatus NOT NULL, attended BOOLEAN DEFAULT FALSE, attended_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), UNIQUE(event_id, user_id) ); -- Event Gallery CREATE TABLE IF NOT EXISTS event_galleries ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), event_id UUID NOT NULL REFERENCES events(id) ON DELETE CASCADE, image_url TEXT NOT NULL, caption TEXT, uploaded_by UUID NOT NULL REFERENCES users(id), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Import Jobs CREATE TABLE IF NOT EXISTS import_jobs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), filename VARCHAR(255) NOT NULL, file_key VARCHAR(255), total_rows INTEGER NOT NULL, processed_rows INTEGER DEFAULT 0, successful_rows INTEGER DEFAULT 0, failed_rows INTEGER DEFAULT 0, status importjobstatus DEFAULT 'processing' NOT NULL, errors JSONB DEFAULT '[]'::jsonb, -- WordPress import enhancements field_mapping JSONB DEFAULT '{}'::jsonb, wordpress_metadata JSONB DEFAULT '{}'::jsonb, imported_user_ids JSONB DEFAULT '[]'::jsonb, rollback_at TIMESTAMP WITH TIME ZONE, rollback_by UUID REFERENCES users(id), imported_by UUID NOT NULL REFERENCES users(id), started_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), completed_at TIMESTAMP WITH TIME ZONE ); COMMIT; -- ============================================================================ -- STEP 2: Subscription & Payment Tables -- ============================================================================ BEGIN; CREATE TABLE IF NOT EXISTS subscription_plans ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name VARCHAR(100) NOT NULL, description TEXT, price_cents INTEGER NOT NULL, billing_cycle VARCHAR(20) NOT NULL, stripe_price_id VARCHAR(255), custom_cycle_enabled BOOLEAN DEFAULT FALSE, minimum_price_cents INTEGER DEFAULT 0, allow_donation BOOLEAN DEFAULT FALSE, is_active BOOLEAN DEFAULT TRUE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS subscriptions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, plan_id UUID NOT NULL REFERENCES subscription_plans(id), stripe_subscription_id VARCHAR(255), stripe_customer_id VARCHAR(255), base_subscription_cents INTEGER NOT NULL, donation_cents INTEGER DEFAULT 0, status subscriptionstatus DEFAULT 'active' NOT NULL, current_period_start TIMESTAMP WITH TIME ZONE, current_period_end TIMESTAMP WITH TIME ZONE, cancel_at_period_end BOOLEAN DEFAULT FALSE, canceled_at TIMESTAMP WITH TIME ZONE, manual_payment BOOLEAN DEFAULT FALSE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS donations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id), amount_cents INTEGER NOT NULL, donation_type donationtype NOT NULL, status donationstatus DEFAULT 'pending' NOT NULL, stripe_payment_intent_id VARCHAR(255), donor_name VARCHAR(200), donor_email VARCHAR(255), message TEXT, is_anonymous BOOLEAN DEFAULT FALSE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), completed_at TIMESTAMP WITH TIME ZONE ); COMMIT; -- ============================================================================ -- STEP 3: RBAC Tables -- ============================================================================ BEGIN; CREATE TABLE IF NOT EXISTS permissions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), code VARCHAR(100) UNIQUE NOT NULL, name VARCHAR(200) NOT NULL, description TEXT, module VARCHAR(50), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS roles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), code VARCHAR(50) UNIQUE NOT NULL, name VARCHAR(100) NOT NULL, description TEXT, is_system_role BOOLEAN DEFAULT FALSE, created_by UUID REFERENCES users(id), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS role_permissions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), role VARCHAR(50), role_id UUID REFERENCES roles(id) ON DELETE CASCADE, permission_id UUID NOT NULL REFERENCES permissions(id) ON DELETE CASCADE, created_by UUID REFERENCES users(id), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS user_invitations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR(255) NOT NULL, role userrole NOT NULL, token VARCHAR(255) UNIQUE NOT NULL, invited_by UUID NOT NULL REFERENCES users(id), invited_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), expires_at TIMESTAMP WITH TIME ZONE NOT NULL, accepted_by UUID REFERENCES users(id), accepted_at TIMESTAMP WITH TIME ZONE, status invitationstatus DEFAULT 'pending' NOT NULL ); COMMIT; -- ============================================================================ -- STEP 4: Document Management Tables -- ============================================================================ BEGIN; CREATE TABLE IF NOT EXISTS newsletter_archives ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), title VARCHAR(255) NOT NULL, description TEXT, published_date TIMESTAMP WITH TIME ZONE NOT NULL, document_url TEXT NOT NULL, document_type VARCHAR(50) NOT NULL, created_by UUID NOT NULL REFERENCES users(id), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS financial_reports ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), year INTEGER NOT NULL, title VARCHAR(255) NOT NULL, document_url TEXT NOT NULL, document_type VARCHAR(50) NOT NULL, created_by UUID NOT NULL REFERENCES users(id), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS bylaws_documents ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), title VARCHAR(255) NOT NULL, version VARCHAR(50) NOT NULL, effective_date TIMESTAMP WITH TIME ZONE NOT NULL, document_url TEXT NOT NULL, document_type VARCHAR(50) NOT NULL, is_current BOOLEAN DEFAULT FALSE, created_by UUID NOT NULL REFERENCES users(id), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); COMMIT; -- ============================================================================ -- STEP 5: System Tables -- ============================================================================ BEGIN; CREATE TABLE IF NOT EXISTS storage_usage ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), total_bytes_used BIGINT DEFAULT 0, max_bytes_allowed BIGINT, last_calculated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS import_rollback_audit ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), import_job_id UUID NOT NULL REFERENCES import_jobs(id), rolled_back_by UUID NOT NULL REFERENCES users(id), rolled_back_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), deleted_user_count INTEGER NOT NULL, deleted_user_ids JSONB NOT NULL, reason TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Initialize storage_usage with default row INSERT INTO storage_usage (id, total_bytes_used, max_bytes_allowed) VALUES (gen_random_uuid(), 0, 107374182400) -- 100GB limit ON CONFLICT DO NOTHING; COMMIT; -- ============================================================================ -- STEP 6: Create Indexes -- ============================================================================ BEGIN; -- Users indexes CREATE INDEX IF NOT EXISTS idx_users_email ON users(email); CREATE INDEX IF NOT EXISTS idx_users_status ON users(status); CREATE INDEX IF NOT EXISTS idx_users_role ON users(role); CREATE INDEX IF NOT EXISTS idx_users_created_at ON users(created_at); -- Events indexes CREATE INDEX IF NOT EXISTS idx_events_start_at ON events(start_at); CREATE INDEX IF NOT EXISTS idx_events_published ON events(published); CREATE INDEX IF NOT EXISTS idx_events_created_by ON events(created_by); -- Event RSVPs indexes CREATE INDEX IF NOT EXISTS idx_event_rsvps_event_id ON event_rsvps(event_id); CREATE INDEX IF NOT EXISTS idx_event_rsvps_user_id ON event_rsvps(user_id); CREATE INDEX IF NOT EXISTS idx_event_rsvps_attended ON event_rsvps(attended); -- Subscriptions indexes CREATE INDEX IF NOT EXISTS idx_subscriptions_user_id ON subscriptions(user_id); CREATE INDEX IF NOT EXISTS idx_subscriptions_status ON subscriptions(status); CREATE INDEX IF NOT EXISTS idx_subscriptions_stripe_customer_id ON subscriptions(stripe_customer_id); -- Permissions indexes CREATE INDEX IF NOT EXISTS ix_permissions_code ON permissions(code); CREATE INDEX IF NOT EXISTS ix_permissions_module ON permissions(module); -- Roles indexes CREATE INDEX IF NOT EXISTS ix_roles_code ON roles(code); -- Role permissions indexes CREATE INDEX IF NOT EXISTS ix_role_permissions_role ON role_permissions(role); CREATE INDEX IF NOT EXISTS ix_role_permissions_role_id ON role_permissions(role_id); -- User invitations indexes CREATE INDEX IF NOT EXISTS ix_user_invitations_email ON user_invitations(email); CREATE INDEX IF NOT EXISTS ix_user_invitations_token ON user_invitations(token); COMMIT; \echo '✅ All tables created successfully!' \echo 'Run: psql ... -c "\dt" to verify'