-- Monaco USA Portal - Combined Database Initialization -- This file combines all schema initialization and migrations for production deployment -- Generated from: 00-init-schemas.sql + migrations 001-016 -- ================================================================================ -- ============================================ -- INITIALIZATION: Roles and Schemas -- ============================================ -- Create roles if they don't exist DO $$ BEGIN -- Create anon role IF NOT EXISTS (SELECT FROM pg_catalog.pg_roles WHERE rolname = 'anon') THEN CREATE ROLE anon NOLOGIN NOINHERIT; END IF; -- Create authenticated role IF NOT EXISTS (SELECT FROM pg_catalog.pg_roles WHERE rolname = 'authenticated') THEN CREATE ROLE authenticated NOLOGIN NOINHERIT; END IF; -- Create service_role IF NOT EXISTS (SELECT FROM pg_catalog.pg_roles WHERE rolname = 'service_role') THEN CREATE ROLE service_role NOLOGIN NOINHERIT BYPASSRLS; END IF; -- Create supabase_admin role IF NOT EXISTS (SELECT FROM pg_catalog.pg_roles WHERE rolname = 'supabase_admin') THEN CREATE ROLE supabase_admin LOGIN SUPERUSER CREATEDB CREATEROLE REPLICATION BYPASSRLS; END IF; -- Create authenticator role IF NOT EXISTS (SELECT FROM pg_catalog.pg_roles WHERE rolname = 'authenticator') THEN CREATE ROLE authenticator NOINHERIT LOGIN; END IF; -- Create supabase_auth_admin role IF NOT EXISTS (SELECT FROM pg_catalog.pg_roles WHERE rolname = 'supabase_auth_admin') THEN CREATE ROLE supabase_auth_admin NOLOGIN NOINHERIT; END IF; -- Create supabase_storage_admin role IF NOT EXISTS (SELECT FROM pg_catalog.pg_roles WHERE rolname = 'supabase_storage_admin') THEN CREATE ROLE supabase_storage_admin NOLOGIN NOINHERIT; END IF; END $$; -- Grant roles GRANT anon TO authenticator; GRANT authenticated TO authenticator; GRANT service_role TO authenticator; GRANT supabase_admin TO postgres; -- Note: Passwords for supabase_admin, authenticator, and other roles are set by -- zz-set-passwords.sh which runs after this script and uses POSTGRES_PASSWORD. -- Create schemas CREATE SCHEMA IF NOT EXISTS auth AUTHORIZATION supabase_auth_admin; CREATE SCHEMA IF NOT EXISTS storage AUTHORIZATION supabase_storage_admin; CREATE SCHEMA IF NOT EXISTS extensions; CREATE SCHEMA IF NOT EXISTS _realtime; CREATE SCHEMA IF NOT EXISTS graphql; CREATE SCHEMA IF NOT EXISTS graphql_public; -- Grant schema usage GRANT USAGE ON SCHEMA public TO anon, authenticated, service_role; GRANT USAGE ON SCHEMA auth TO anon, authenticated, service_role, supabase_auth_admin; GRANT USAGE ON SCHEMA storage TO anon, authenticated, service_role, supabase_storage_admin; GRANT USAGE ON SCHEMA extensions TO anon, authenticated, service_role; GRANT USAGE ON SCHEMA graphql_public TO anon, authenticated, service_role; -- Grant auth schema to supabase_auth_admin GRANT ALL ON SCHEMA auth TO supabase_auth_admin; GRANT ALL ON ALL TABLES IN SCHEMA auth TO supabase_auth_admin; GRANT ALL ON ALL SEQUENCES IN SCHEMA auth TO supabase_auth_admin; GRANT ALL ON ALL ROUTINES IN SCHEMA auth TO supabase_auth_admin; -- Grant storage schema to supabase_storage_admin GRANT ALL ON SCHEMA storage TO supabase_storage_admin; GRANT ALL ON ALL TABLES IN SCHEMA storage TO supabase_storage_admin; GRANT ALL ON ALL SEQUENCES IN SCHEMA storage TO supabase_storage_admin; GRANT ALL ON ALL ROUTINES IN SCHEMA storage TO supabase_storage_admin; -- Set default privileges ALTER DEFAULT PRIVILEGES IN SCHEMA auth GRANT ALL ON TABLES TO supabase_auth_admin; ALTER DEFAULT PRIVILEGES IN SCHEMA auth GRANT ALL ON SEQUENCES TO supabase_auth_admin; ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON TABLES TO supabase_storage_admin; ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON SEQUENCES TO supabase_storage_admin; -- Set search path ALTER DATABASE postgres SET search_path TO public, extensions; -- Create extensions in extensions schema CREATE EXTENSION IF NOT EXISTS "uuid-ossp" WITH SCHEMA extensions; CREATE EXTENSION IF NOT EXISTS "pgcrypto" WITH SCHEMA extensions; -- ============================================ -- AUTH HELPER FUNCTIONS -- These are normally created by GoTrue, but we need them for RLS policies -- ============================================ -- Get current user ID from JWT CREATE OR REPLACE FUNCTION auth.uid() RETURNS UUID LANGUAGE sql STABLE AS $$ SELECT COALESCE( current_setting('request.jwt.claim.sub', true), (current_setting('request.jwt.claims', true)::jsonb ->> 'sub') )::uuid $$; -- Get current user role from JWT CREATE OR REPLACE FUNCTION auth.role() RETURNS TEXT LANGUAGE sql STABLE AS $$ SELECT COALESCE( current_setting('request.jwt.claim.role', true), (current_setting('request.jwt.claims', true)::jsonb ->> 'role') )::text $$; -- Get JWT claim value CREATE OR REPLACE FUNCTION auth.jwt() RETURNS JSONB LANGUAGE sql STABLE AS $$ SELECT COALESCE( current_setting('request.jwt.claims', true)::jsonb, '{}'::jsonb ) $$; -- ============================================ -- MIGRATION 001: Initial Schema -- ============================================ -- MEMBERSHIP STATUSES (Admin-configurable) CREATE TABLE public.membership_statuses ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL UNIQUE, display_name TEXT NOT NULL, color TEXT NOT NULL DEFAULT '#6b7280', description TEXT, is_default BOOLEAN DEFAULT FALSE, sort_order INTEGER DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW() ); -- Default statuses INSERT INTO public.membership_statuses (name, display_name, color, description, is_default, sort_order) VALUES ('pending', 'Pending', '#eab308', 'New member, awaiting dues payment', true, 1), ('active', 'Active', '#22c55e', 'Dues paid, full access', false, 2), ('inactive', 'Inactive', '#6b7280', 'Lapsed membership or suspended', false, 3), ('expired', 'Expired', '#ef4444', 'Membership terminated', false, 4); -- MEMBERSHIP TYPES (Admin-configurable pricing) CREATE TABLE public.membership_types ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL UNIQUE, display_name TEXT NOT NULL, annual_dues DECIMAL(10,2) NOT NULL, description TEXT, is_default BOOLEAN DEFAULT FALSE, is_active BOOLEAN DEFAULT TRUE, sort_order INTEGER DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW() ); -- Default membership types INSERT INTO public.membership_types (name, display_name, annual_dues, description, is_default, sort_order) VALUES ('regular', 'Regular Member', 50.00, 'Standard individual membership', true, 1), ('student', 'Student', 25.00, 'For students with valid ID', false, 2), ('senior', 'Senior (65+)', 35.00, 'For members 65 years and older', false, 3), ('family', 'Family', 75.00, 'Household membership', false, 4), ('honorary', 'Honorary Member', 0.00, 'Granted by the board', false, 5); -- MEMBERS TABLE -- Note: FK to auth.users is added after GoTrue creates the auth schema CREATE TABLE public.members ( id UUID PRIMARY KEY, member_id TEXT UNIQUE NOT NULL, first_name TEXT NOT NULL, last_name TEXT NOT NULL, email TEXT UNIQUE NOT NULL, phone TEXT, date_of_birth DATE, address TEXT, nationality TEXT[] NOT NULL DEFAULT '{}', role TEXT NOT NULL DEFAULT 'member' CHECK (role IN ('member', 'board', 'admin')), membership_status_id UUID REFERENCES public.membership_statuses(id), membership_type_id UUID REFERENCES public.membership_types(id), member_since DATE DEFAULT CURRENT_DATE, avatar_url TEXT, notes TEXT, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); -- Auto-generate member_id trigger CREATE OR REPLACE FUNCTION generate_member_id() RETURNS TRIGGER AS $$ DECLARE next_num INTEGER; BEGIN SELECT COALESCE(MAX(CAST(SUBSTRING(member_id FROM 6) AS INTEGER)), 0) + 1 INTO next_num FROM public.members; NEW.member_id := 'MUSA-' || LPAD(next_num::TEXT, 4, '0'); RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER set_member_id BEFORE INSERT ON public.members FOR EACH ROW WHEN (NEW.member_id IS NULL) EXECUTE FUNCTION generate_member_id(); -- Update timestamp trigger CREATE OR REPLACE FUNCTION update_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER members_updated_at BEFORE UPDATE ON public.members FOR EACH ROW EXECUTE FUNCTION update_updated_at(); -- Grant service_role full access to core tables GRANT ALL ON public.membership_statuses TO service_role; GRANT ALL ON public.membership_types TO service_role; GRANT ALL ON public.members TO service_role; -- Grant authenticated role read access to core tables (required for RLS to work) GRANT SELECT ON public.membership_statuses TO authenticated; GRANT SELECT ON public.membership_types TO authenticated; GRANT SELECT ON public.members TO authenticated; GRANT UPDATE ON public.members TO authenticated; -- DUES PAYMENTS CREATE TABLE public.dues_payments ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), member_id UUID NOT NULL REFERENCES public.members(id) ON DELETE CASCADE, amount DECIMAL(10,2) NOT NULL, currency TEXT DEFAULT 'EUR', payment_date DATE NOT NULL, due_date DATE NOT NULL, payment_method TEXT DEFAULT 'bank_transfer', reference TEXT, notes TEXT, recorded_by UUID NOT NULL REFERENCES public.members(id), created_at TIMESTAMPTZ DEFAULT NOW() ); -- Auto-calculate due_date (1 year from payment) CREATE OR REPLACE FUNCTION calculate_due_date() RETURNS TRIGGER AS $$ BEGIN IF NEW.due_date IS NULL THEN NEW.due_date := NEW.payment_date + INTERVAL '1 year'; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER set_due_date BEFORE INSERT ON public.dues_payments FOR EACH ROW EXECUTE FUNCTION calculate_due_date(); -- Auto-update member status to active after payment CREATE OR REPLACE FUNCTION update_member_status_on_payment() RETURNS TRIGGER AS $$ DECLARE active_status_id UUID; BEGIN SELECT id INTO active_status_id FROM public.membership_statuses WHERE name = 'active'; UPDATE public.members SET membership_status_id = active_status_id, updated_at = NOW() WHERE id = NEW.member_id; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER activate_member_on_payment AFTER INSERT ON public.dues_payments FOR EACH ROW EXECUTE FUNCTION update_member_status_on_payment(); -- EVENT TYPES (Admin-configurable) CREATE TABLE public.event_types ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL UNIQUE, display_name TEXT NOT NULL, color TEXT NOT NULL DEFAULT '#3b82f6', icon TEXT, description TEXT, is_active BOOLEAN DEFAULT TRUE, sort_order INTEGER DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW() ); -- Default event types INSERT INTO public.event_types (name, display_name, color, icon, sort_order) VALUES ('social', 'Social Event', '#10b981', 'party-popper', 1), ('meeting', 'Meeting', '#6366f1', 'users', 2), ('fundraiser', 'Fundraiser', '#f59e0b', 'heart-handshake', 3), ('workshop', 'Workshop', '#8b5cf6', 'graduation-cap', 4), ('gala', 'Gala/Formal', '#ec4899', 'sparkles', 5), ('other', 'Other', '#6b7280', 'calendar', 6); -- EVENTS CREATE TABLE public.events ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), title TEXT NOT NULL, description TEXT, event_type_id UUID REFERENCES public.event_types(id), start_datetime TIMESTAMPTZ NOT NULL, end_datetime TIMESTAMPTZ NOT NULL, all_day BOOLEAN DEFAULT FALSE, timezone TEXT DEFAULT 'Europe/Monaco', location TEXT, location_url TEXT, max_attendees INTEGER, max_guests_per_member INTEGER DEFAULT 1, is_paid BOOLEAN DEFAULT FALSE, member_price DECIMAL(10,2) DEFAULT 0, non_member_price DECIMAL(10,2) DEFAULT 0, pricing_notes TEXT, visibility TEXT NOT NULL DEFAULT 'members' CHECK (visibility IN ('public', 'members', 'board', 'admin')), status TEXT NOT NULL DEFAULT 'published' CHECK (status IN ('draft', 'published', 'cancelled', 'completed')), cover_image_url TEXT, created_by UUID NOT NULL REFERENCES public.members(id), created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE TRIGGER events_updated_at BEFORE UPDATE ON public.events FOR EACH ROW EXECUTE FUNCTION update_updated_at(); -- EVENT RSVPs (Members) CREATE TABLE public.event_rsvps ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), event_id UUID NOT NULL REFERENCES public.events(id) ON DELETE CASCADE, member_id UUID NOT NULL REFERENCES public.members(id) ON DELETE CASCADE, status TEXT NOT NULL DEFAULT 'confirmed' CHECK (status IN ('confirmed', 'declined', 'maybe', 'waitlist', 'cancelled')), guest_count INTEGER DEFAULT 0, guest_names TEXT[], notes TEXT, payment_status TEXT DEFAULT 'not_required' CHECK (payment_status IN ('not_required', 'pending', 'paid')), payment_reference TEXT, payment_amount DECIMAL(10,2), attended BOOLEAN DEFAULT FALSE, checked_in_at TIMESTAMPTZ, checked_in_by UUID REFERENCES public.members(id), created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), UNIQUE(event_id, member_id) ); CREATE TRIGGER event_rsvps_updated_at BEFORE UPDATE ON public.event_rsvps FOR EACH ROW EXECUTE FUNCTION update_updated_at(); -- EVENT RSVPs (Public/Non-members) CREATE TABLE public.event_rsvps_public ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), event_id UUID NOT NULL REFERENCES public.events(id) ON DELETE CASCADE, full_name TEXT NOT NULL, email TEXT NOT NULL, phone TEXT, status TEXT NOT NULL DEFAULT 'confirmed' CHECK (status IN ('confirmed', 'declined', 'maybe', 'waitlist', 'cancelled')), guest_count INTEGER DEFAULT 0, guest_names TEXT[], payment_status TEXT DEFAULT 'not_required' CHECK (payment_status IN ('not_required', 'pending', 'paid')), payment_reference TEXT, payment_amount DECIMAL(10,2), attended BOOLEAN DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), UNIQUE(event_id, email) ); CREATE TRIGGER event_rsvps_public_updated_at BEFORE UPDATE ON public.event_rsvps_public FOR EACH ROW EXECUTE FUNCTION update_updated_at(); -- DOCUMENT CATEGORIES CREATE TABLE public.document_categories ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL UNIQUE, display_name TEXT NOT NULL, description TEXT, icon TEXT, sort_order INTEGER DEFAULT 0, is_active BOOLEAN DEFAULT TRUE, created_at TIMESTAMPTZ DEFAULT NOW() ); -- Default categories INSERT INTO public.document_categories (name, display_name, icon, sort_order) VALUES ('meeting_minutes', 'Meeting Minutes', 'file-text', 1), ('governance', 'Governance & Bylaws', 'scale', 2), ('legal', 'Legal Documents', 'briefcase', 3), ('financial', 'Financial Reports', 'dollar-sign', 4), ('member_resources', 'Member Resources', 'book-open', 5), ('forms', 'Forms & Templates', 'clipboard', 6), ('other', 'Other Documents', 'file', 7); -- DOCUMENTS CREATE TABLE public.documents ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), title TEXT NOT NULL, description TEXT, category_id UUID REFERENCES public.document_categories(id), file_path TEXT NOT NULL, file_name TEXT NOT NULL, file_size INTEGER NOT NULL, mime_type TEXT NOT NULL, visibility TEXT NOT NULL DEFAULT 'members' CHECK (visibility IN ('public', 'members', 'board', 'admin')), allowed_member_ids UUID[], version INTEGER DEFAULT 1, replaces_document_id UUID REFERENCES public.documents(id), meeting_date DATE, meeting_attendees UUID[], uploaded_by UUID NOT NULL REFERENCES public.members(id), created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE TRIGGER documents_updated_at BEFORE UPDATE ON public.documents FOR EACH ROW EXECUTE FUNCTION update_updated_at(); -- APP SETTINGS (Unified key-value store) CREATE TABLE public.app_settings ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), category TEXT NOT NULL, setting_key TEXT NOT NULL, setting_value JSONB NOT NULL, setting_type TEXT NOT NULL DEFAULT 'text' CHECK (setting_type IN ('text', 'number', 'boolean', 'json', 'array')), display_name TEXT NOT NULL, description TEXT, is_public BOOLEAN DEFAULT FALSE, updated_at TIMESTAMPTZ DEFAULT NOW(), updated_by UUID REFERENCES public.members(id), UNIQUE(category, setting_key) ); -- Default settings INSERT INTO public.app_settings (category, setting_key, setting_value, setting_type, display_name, description, is_public) VALUES ('organization', 'association_name', '"Monaco USA"', 'text', 'Association Name', 'Official name of the association', true), ('organization', 'tagline', '"Americans in Monaco"', 'text', 'Tagline', 'Association tagline shown on login', true), ('organization', 'contact_email', '"contact@monacousa.org"', 'text', 'Contact Email', 'Public contact email', true), ('organization', 'primary_color', '"#dc2626"', 'text', 'Primary Color', 'Brand primary color (hex)', true), ('dues', 'payment_iban', '"MC58 1756 9000 0104 0050 1001 860"', 'text', 'Payment IBAN', 'Bank IBAN for dues', false), ('dues', 'payment_account_holder', '"ASSOCIATION MONACO USA"', 'text', 'Account Holder', 'Bank account holder name', false), ('dues', 'payment_bank_name', '"Credit Foncier de Monaco"', 'text', 'Bank Name', 'Name of the bank', false), ('dues', 'reminder_days_before', '[30, 7, 1]', 'array', 'Reminder Days', 'Days before due to send reminders', false), ('dues', 'grace_period_days', '30', 'number', 'Grace Period', 'Days after due before auto-inactive', false), ('dues', 'auto_inactive_enabled', 'true', 'boolean', 'Auto Inactive', 'Auto set inactive after grace period', false), ('system', 'maintenance_mode', 'false', 'boolean', 'Maintenance Mode', 'Put portal in maintenance mode', false), ('system', 'max_upload_size_mb', '50', 'number', 'Max Upload Size', 'Maximum file upload size in MB', false); -- EMAIL TEMPLATES CREATE TABLE public.email_templates ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), template_key TEXT UNIQUE NOT NULL, template_name TEXT NOT NULL, category TEXT NOT NULL, subject TEXT NOT NULL, body_html TEXT NOT NULL, body_text TEXT, is_active BOOLEAN DEFAULT TRUE, is_system BOOLEAN DEFAULT FALSE, variables_schema JSONB, preview_data JSONB, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), updated_by UUID REFERENCES public.members(id) ); CREATE TRIGGER email_templates_updated_at BEFORE UPDATE ON public.email_templates FOR EACH ROW EXECUTE FUNCTION update_updated_at(); -- EMAIL LOGS CREATE TABLE public.email_logs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), recipient_id UUID REFERENCES public.members(id), recipient_email TEXT NOT NULL, recipient_name TEXT, template_key TEXT, subject TEXT NOT NULL, email_type TEXT NOT NULL, status TEXT NOT NULL DEFAULT 'queued' CHECK (status IN ('queued', 'sent', 'delivered', 'opened', 'clicked', 'bounced', 'failed')), provider TEXT, provider_message_id TEXT, opened_at TIMESTAMPTZ, clicked_at TIMESTAMPTZ, error_message TEXT, retry_count INTEGER DEFAULT 0, template_variables JSONB, sent_by UUID REFERENCES public.members(id), created_at TIMESTAMPTZ DEFAULT NOW(), sent_at TIMESTAMPTZ, delivered_at TIMESTAMPTZ ); -- VIEWS -- Members with dues status CREATE VIEW public.members_with_dues AS SELECT m.*, ms.name as status_name, ms.display_name as status_display_name, ms.color as status_color, mt.display_name as membership_type_name, mt.annual_dues, dp.last_payment_date, dp.current_due_date, CASE WHEN dp.current_due_date IS NULL THEN 'never_paid' WHEN dp.current_due_date < CURRENT_DATE THEN 'overdue' WHEN dp.current_due_date < CURRENT_DATE + INTERVAL '30 days' THEN 'due_soon' ELSE 'current' END as dues_status, CASE WHEN dp.current_due_date < CURRENT_DATE THEN (CURRENT_DATE - dp.current_due_date)::INTEGER ELSE NULL END as days_overdue, CASE WHEN dp.current_due_date >= CURRENT_DATE THEN (dp.current_due_date - CURRENT_DATE)::INTEGER ELSE NULL END as days_until_due FROM public.members m LEFT JOIN public.membership_statuses ms ON m.membership_status_id = ms.id LEFT JOIN public.membership_types mt ON m.membership_type_id = mt.id LEFT JOIN LATERAL ( SELECT payment_date as last_payment_date, due_date as current_due_date FROM public.dues_payments WHERE member_id = m.id ORDER BY due_date DESC LIMIT 1 ) dp ON true; -- Grant access to authenticated users GRANT SELECT ON public.members_with_dues TO authenticated; -- Events with attendee counts CREATE VIEW public.events_with_counts AS SELECT e.*, et.display_name as event_type_name, et.color as event_type_color, et.icon as event_type_icon, COALESCE(member_rsvps.confirmed_count, 0) + COALESCE(member_rsvps.guest_count, 0) + COALESCE(public_rsvps.confirmed_count, 0) + COALESCE(public_rsvps.guest_count, 0) as total_attendees, COALESCE(member_rsvps.confirmed_count, 0) as member_count, COALESCE(public_rsvps.confirmed_count, 0) as non_member_count, COALESCE(member_rsvps.waitlist_count, 0) + COALESCE(public_rsvps.waitlist_count, 0) as waitlist_count, CASE WHEN e.max_attendees IS NULL THEN FALSE WHEN (COALESCE(member_rsvps.confirmed_count, 0) + COALESCE(member_rsvps.guest_count, 0) + COALESCE(public_rsvps.confirmed_count, 0) + COALESCE(public_rsvps.guest_count, 0)) >= e.max_attendees THEN TRUE ELSE FALSE END as is_full FROM public.events e LEFT JOIN public.event_types et ON e.event_type_id = et.id LEFT JOIN LATERAL ( SELECT COUNT(*) FILTER (WHERE status = 'confirmed') as confirmed_count, COALESCE(SUM(guest_count) FILTER (WHERE status = 'confirmed'), 0) as guest_count, COUNT(*) FILTER (WHERE status = 'waitlist') as waitlist_count FROM public.event_rsvps WHERE event_id = e.id ) member_rsvps ON true LEFT JOIN LATERAL ( SELECT COUNT(*) FILTER (WHERE status = 'confirmed') as confirmed_count, COALESCE(SUM(guest_count) FILTER (WHERE status = 'confirmed'), 0) as guest_count, COUNT(*) FILTER (WHERE status = 'waitlist') as waitlist_count FROM public.event_rsvps_public WHERE event_id = e.id ) public_rsvps ON true; -- Grant view access to authenticated users GRANT SELECT ON public.events_with_counts TO authenticated; -- ============================================ -- TABLE GRANTS FOR AUTHENTICATED ROLE -- ============================================ -- These grants are required for RLS policies to work. -- RLS policies control WHAT rows can be accessed, -- but GRANT controls WHETHER the table can be accessed at all. -- Core tables GRANT SELECT ON public.dues_payments TO authenticated; -- Events GRANT SELECT ON public.events TO authenticated; GRANT SELECT ON public.event_types TO authenticated; GRANT SELECT, INSERT, UPDATE, DELETE ON public.event_rsvps TO authenticated; GRANT SELECT, INSERT ON public.event_rsvps_public TO authenticated; -- Documents GRANT SELECT ON public.documents TO authenticated; GRANT SELECT ON public.document_categories TO authenticated; GRANT SELECT ON public.document_folders TO authenticated; -- Settings (public settings viewable) GRANT SELECT ON public.app_settings TO authenticated; -- Email logs (own logs viewable) GRANT SELECT ON public.email_logs TO authenticated; -- Notification preferences GRANT SELECT, INSERT, UPDATE ON public.user_notification_preferences TO authenticated; -- ROW LEVEL SECURITY -- Enable RLS on all tables ALTER TABLE public.members ENABLE ROW LEVEL SECURITY; ALTER TABLE public.dues_payments ENABLE ROW LEVEL SECURITY; ALTER TABLE public.events ENABLE ROW LEVEL SECURITY; ALTER TABLE public.event_rsvps ENABLE ROW LEVEL SECURITY; ALTER TABLE public.event_rsvps_public ENABLE ROW LEVEL SECURITY; ALTER TABLE public.documents ENABLE ROW LEVEL SECURITY; ALTER TABLE public.app_settings ENABLE ROW LEVEL SECURITY; ALTER TABLE public.email_templates ENABLE ROW LEVEL SECURITY; ALTER TABLE public.email_logs ENABLE ROW LEVEL SECURITY; -- MEMBERS POLICIES CREATE POLICY "Members viewable by authenticated users" ON public.members FOR SELECT TO authenticated USING (true); CREATE POLICY "Users can update own profile" ON public.members FOR UPDATE TO authenticated USING (auth.uid() = id); CREATE POLICY "Admins can insert members" ON public.members FOR INSERT TO authenticated WITH CHECK ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin') OR auth.uid() = id ); CREATE POLICY "Admins can delete members" ON public.members FOR DELETE TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin') ); -- DUES PAYMENTS POLICIES CREATE POLICY "Own payments viewable" ON public.dues_payments FOR SELECT TO authenticated USING ( member_id = auth.uid() OR EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); CREATE POLICY "Board can record payments" ON public.dues_payments FOR INSERT TO authenticated WITH CHECK ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); -- EVENTS POLICIES CREATE POLICY "Events viewable based on visibility" ON public.events FOR SELECT TO authenticated USING ( visibility = 'members' OR visibility = 'public' OR (visibility = 'board' AND EXISTS ( SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin') )) OR (visibility = 'admin' AND EXISTS ( SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin' )) ); CREATE POLICY "Public events viewable by anyone" ON public.events FOR SELECT TO anon USING (visibility = 'public' AND status = 'published'); CREATE POLICY "Board can manage events" ON public.events FOR ALL TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); -- EVENT RSVPs POLICIES CREATE POLICY "RSVPs viewable by member and board" ON public.event_rsvps FOR SELECT TO authenticated USING ( member_id = auth.uid() OR EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); CREATE POLICY "Members can manage own RSVPs" ON public.event_rsvps FOR ALL TO authenticated USING (member_id = auth.uid()) WITH CHECK (member_id = auth.uid()); CREATE POLICY "Board can manage all RSVPs" ON public.event_rsvps FOR ALL TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); -- PUBLIC RSVPs POLICIES CREATE POLICY "Public RSVPs viewable by board" ON public.event_rsvps_public FOR SELECT TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); CREATE POLICY "Anyone can create public RSVP" ON public.event_rsvps_public FOR INSERT TO anon, authenticated WITH CHECK (true); CREATE POLICY "Board can manage public RSVPs" ON public.event_rsvps_public FOR ALL TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); -- DOCUMENTS POLICIES CREATE POLICY "Documents viewable based on visibility" ON public.documents FOR SELECT TO authenticated USING ( visibility = 'members' OR visibility = 'public' OR (visibility = 'board' AND EXISTS ( SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin') )) OR (visibility = 'admin' AND EXISTS ( SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin' )) OR (allowed_member_ids IS NOT NULL AND auth.uid() = ANY(allowed_member_ids)) ); CREATE POLICY "Board can upload documents" ON public.documents FOR INSERT TO authenticated WITH CHECK ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); CREATE POLICY "Admin can manage all documents" ON public.documents FOR ALL TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin') ); -- APP SETTINGS POLICIES CREATE POLICY "Public settings viewable by anyone" ON public.app_settings FOR SELECT USING (is_public = true); CREATE POLICY "All settings viewable by admin" ON public.app_settings FOR SELECT TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin') ); CREATE POLICY "Admin can manage settings" ON public.app_settings FOR ALL TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin') ); -- EMAIL TEMPLATES POLICIES CREATE POLICY "Admin can manage email templates" ON public.email_templates FOR ALL TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin') ); -- EMAIL LOGS POLICIES CREATE POLICY "Own email logs viewable" ON public.email_logs FOR SELECT TO authenticated USING ( recipient_id = auth.uid() OR EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin') ); CREATE POLICY "Admin can manage email logs" ON public.email_logs FOR ALL TO authenticated USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin') ); -- INDEXES CREATE INDEX idx_members_email ON public.members(email); CREATE INDEX idx_members_member_id ON public.members(member_id); CREATE INDEX idx_members_role ON public.members(role); CREATE INDEX idx_members_status ON public.members(membership_status_id); CREATE INDEX idx_dues_payments_member ON public.dues_payments(member_id); CREATE INDEX idx_dues_payments_date ON public.dues_payments(payment_date DESC); CREATE INDEX idx_events_start ON public.events(start_datetime); CREATE INDEX idx_events_visibility ON public.events(visibility); CREATE INDEX idx_events_status ON public.events(status); CREATE INDEX idx_event_rsvps_event ON public.event_rsvps(event_id); CREATE INDEX idx_event_rsvps_member ON public.event_rsvps(member_id); CREATE INDEX idx_documents_category ON public.documents(category_id); CREATE INDEX idx_documents_visibility ON public.documents(visibility); CREATE INDEX idx_app_settings_category ON public.app_settings(category, setting_key); CREATE INDEX idx_email_logs_recipient ON public.email_logs(recipient_id); CREATE INDEX idx_email_logs_status ON public.email_logs(status); CREATE INDEX idx_email_logs_created ON public.email_logs(created_at DESC); -- ============================================ -- MIGRATION 002: Admin Integration Settings -- ============================================ INSERT INTO public.app_settings (category, setting_key, setting_value, setting_type, display_name, description, is_public) VALUES ('email', 'smtp_host', '""', 'text', 'SMTP Host', 'SMTP server hostname (e.g., smtp.gmail.com)', false), ('email', 'smtp_port', '587', 'number', 'SMTP Port', 'SMTP server port (25, 465, 587)', false), ('email', 'smtp_secure', 'true', 'boolean', 'Use TLS/SSL', 'Enable secure connection (recommended)', false), ('email', 'smtp_username', '""', 'text', 'SMTP Username', 'SMTP authentication username', false), ('email', 'smtp_password', '""', 'text', 'SMTP Password', 'SMTP authentication password', false), ('email', 'smtp_from_address', '"noreply@monacousa.org"', 'text', 'From Address', 'Default sender email address', false), ('email', 'smtp_from_name', '"Monaco USA"', 'text', 'From Name', 'Default sender display name', false), ('email', 'smtp_reply_to', '"contact@monacousa.org"', 'text', 'Reply-To Address', 'Reply-to email address', false), ('email', 'smtp_enabled', 'false', 'boolean', 'Enable Email', 'Enable sending emails via SMTP', false), ('storage', 's3_endpoint', '""', 'text', 'S3 Endpoint', 'S3-compatible endpoint URL (e.g., http://minio:9000)', false), ('storage', 's3_bucket', '"monacousa-documents"', 'text', 'Bucket Name', 'S3 bucket name for file storage', false), ('storage', 's3_access_key', '""', 'text', 'Access Key', 'S3 access key ID', false), ('storage', 's3_secret_key', '""', 'text', 'Secret Key', 'S3 secret access key', false), ('storage', 's3_region', '"us-east-1"', 'text', 'Region', 'S3 region (use us-east-1 for MinIO)', false), ('storage', 's3_use_ssl', 'false', 'boolean', 'Use SSL', 'Enable SSL for S3 connections', false), ('storage', 's3_force_path_style', 'true', 'boolean', 'Force Path Style', 'Use path-style URLs (required for MinIO)', false), ('storage', 's3_enabled', 'false', 'boolean', 'Enable S3 Storage', 'Use external S3 instead of Supabase Storage', false), ('system', 'session_timeout_hours', '168', 'number', 'Session Timeout', 'Hours until session expires (default: 7 days)', false), ('system', 'allowed_file_types', '["pdf","doc","docx","xls","xlsx","ppt","pptx","txt","jpg","jpeg","png","webp"]', 'array', 'Allowed File Types', 'Allowed file extensions for uploads', false), ('system', 'maintenance_message', '"The portal is currently undergoing maintenance. Please check back soon."', 'text', 'Maintenance Message', 'Message shown during maintenance', false), ('system', 'enable_public_events', 'true', 'boolean', 'Enable Public Events', 'Allow non-members to view public events', false), ('system', 'enable_public_rsvp', 'true', 'boolean', 'Enable Public RSVP', 'Allow non-members to RSVP to public events', false) ON CONFLICT (category, setting_key) DO NOTHING; -- ============================================ -- MIGRATION 003: Storage Buckets and Audit -- ============================================ -- Note: Storage buckets and policies are created by storage-api service. -- These statements are wrapped in a conditional to avoid errors on fresh init. -- The storage service will create the buckets when it starts. DO $$ BEGIN -- Only run if storage.buckets table exists (created by storage-api) IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'storage' AND table_name = 'buckets') THEN -- Documents bucket INSERT INTO storage.buckets (id, name, public, file_size_limit, allowed_mime_types) VALUES ( 'documents', 'documents', true, 52428800, ARRAY['application/pdf', 'application/msword', 'application/vnd.openxmlformats-officedocument.wordprocessingml.document', 'application/vnd.ms-excel', 'application/vnd.openxmlformats-officedocument.spreadsheetml.sheet', 'application/vnd.ms-powerpoint', 'application/vnd.openxmlformats-officedocument.presentationml.presentation', 'text/plain', 'text/csv', 'application/json', 'image/jpeg', 'image/png', 'image/webp', 'image/gif'] ) ON CONFLICT (id) DO UPDATE SET public = true, file_size_limit = EXCLUDED.file_size_limit, allowed_mime_types = EXCLUDED.allowed_mime_types; -- Avatars bucket INSERT INTO storage.buckets (id, name, public, file_size_limit, allowed_mime_types) VALUES ( 'avatars', 'avatars', true, 5242880, ARRAY['image/jpeg', 'image/png', 'image/webp', 'image/gif'] ) ON CONFLICT (id) DO UPDATE SET public = true, file_size_limit = EXCLUDED.file_size_limit, allowed_mime_types = EXCLUDED.allowed_mime_types; -- Event images bucket INSERT INTO storage.buckets (id, name, public, file_size_limit, allowed_mime_types) VALUES ( 'event-images', 'event-images', true, 10485760, ARRAY['image/jpeg', 'image/png', 'image/webp'] ) ON CONFLICT (id) DO UPDATE SET public = true, file_size_limit = EXCLUDED.file_size_limit, allowed_mime_types = EXCLUDED.allowed_mime_types; END IF; END $$; -- Storage policies - wrapped in conditional since storage.objects is created by storage-api DO $$ BEGIN IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'storage' AND table_name = 'objects') THEN DROP POLICY IF EXISTS "documents_read_policy" ON storage.objects; DROP POLICY IF EXISTS "documents_insert_policy" ON storage.objects; DROP POLICY IF EXISTS "documents_delete_policy" ON storage.objects; DROP POLICY IF EXISTS "avatars_read_policy" ON storage.objects; DROP POLICY IF EXISTS "avatars_insert_policy" ON storage.objects; DROP POLICY IF EXISTS "avatars_update_policy" ON storage.objects; DROP POLICY IF EXISTS "avatars_delete_policy" ON storage.objects; DROP POLICY IF EXISTS "event_images_read_policy" ON storage.objects; DROP POLICY IF EXISTS "event_images_insert_policy" ON storage.objects; DROP POLICY IF EXISTS "event_images_delete_policy" ON storage.objects; -- Note: Policies will be created by the application when storage is ready -- The storage-api service handles initial policy setup END IF; END $$; -- AUDIT LOGS TABLE CREATE TABLE IF NOT EXISTS audit_logs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID, user_email TEXT, action TEXT NOT NULL, resource_type TEXT, resource_id TEXT, details JSONB DEFAULT '{}', ip_address TEXT, user_agent TEXT, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_audit_logs_user_id ON audit_logs(user_id); CREATE INDEX IF NOT EXISTS idx_audit_logs_action ON audit_logs(action); CREATE INDEX IF NOT EXISTS idx_audit_logs_resource_type ON audit_logs(resource_type); CREATE INDEX IF NOT EXISTS idx_audit_logs_created_at ON audit_logs(created_at DESC); ALTER TABLE audit_logs ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS "audit_logs_read_admin" ON audit_logs; CREATE POLICY "audit_logs_read_admin" ON audit_logs FOR SELECT USING ( EXISTS ( SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin' ) ); GRANT SELECT, INSERT, UPDATE, DELETE ON audit_logs TO authenticated; GRANT ALL ON audit_logs TO service_role; -- ============================================ -- MIGRATION 004: User Notification Preferences -- ============================================ CREATE TABLE IF NOT EXISTS user_notification_preferences ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), member_id UUID NOT NULL REFERENCES members(id) ON DELETE CASCADE UNIQUE, email_event_rsvp_confirmation BOOLEAN DEFAULT true, email_event_reminder BOOLEAN DEFAULT true, email_event_updates BOOLEAN DEFAULT true, email_waitlist_promotion BOOLEAN DEFAULT true, email_dues_reminder BOOLEAN DEFAULT true, email_payment_confirmation BOOLEAN DEFAULT true, email_membership_updates BOOLEAN DEFAULT true, email_announcements BOOLEAN DEFAULT true, email_newsletter BOOLEAN DEFAULT true, newsletter_frequency TEXT DEFAULT 'monthly' CHECK (newsletter_frequency IN ('weekly', 'monthly', 'quarterly', 'never')), created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_notification_prefs_member ON user_notification_preferences(member_id); ALTER TABLE user_notification_preferences ENABLE ROW LEVEL SECURITY; CREATE POLICY "Members can view own notification preferences" ON user_notification_preferences FOR SELECT USING (member_id = auth.uid()); CREATE POLICY "Members can insert own notification preferences" ON user_notification_preferences FOR INSERT WITH CHECK (member_id = auth.uid()); CREATE POLICY "Members can update own notification preferences" ON user_notification_preferences FOR UPDATE USING (member_id = auth.uid()) WITH CHECK (member_id = auth.uid()); CREATE POLICY "Admins can view all notification preferences" ON user_notification_preferences FOR SELECT USING ( EXISTS ( SELECT 1 FROM members WHERE members.id = auth.uid() AND members.role = 'admin' ) ); CREATE OR REPLACE FUNCTION create_default_notification_preferences() RETURNS TRIGGER AS $$ BEGIN INSERT INTO user_notification_preferences (member_id) VALUES (NEW.id) ON CONFLICT (member_id) DO NOTHING; RETURN NEW; END; $$ LANGUAGE plpgsql SECURITY DEFINER; DROP TRIGGER IF EXISTS on_member_created_create_notification_prefs ON members; CREATE TRIGGER on_member_created_create_notification_prefs AFTER INSERT ON members FOR EACH ROW EXECUTE FUNCTION create_default_notification_preferences(); CREATE OR REPLACE FUNCTION update_notification_prefs_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; DROP TRIGGER IF EXISTS set_notification_prefs_updated_at ON user_notification_preferences; CREATE TRIGGER set_notification_prefs_updated_at BEFORE UPDATE ON user_notification_preferences FOR EACH ROW EXECUTE FUNCTION update_notification_prefs_updated_at(); -- ============================================ -- MIGRATION 006: Document Folders -- ============================================ CREATE TABLE public.document_folders ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL, parent_id UUID REFERENCES public.document_folders(id) ON DELETE CASCADE, path TEXT, visibility TEXT NOT NULL DEFAULT 'members' CHECK (visibility IN ('public', 'members', 'board', 'admin')), created_by UUID REFERENCES public.members(id), created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), UNIQUE(name, parent_id) ); CREATE TRIGGER document_folders_updated_at BEFORE UPDATE ON public.document_folders FOR EACH ROW EXECUTE FUNCTION update_updated_at(); ALTER TABLE public.documents ADD COLUMN folder_id UUID REFERENCES public.document_folders(id) ON DELETE SET NULL; CREATE OR REPLACE FUNCTION update_folder_path() RETURNS TRIGGER AS $$ DECLARE parent_path TEXT; BEGIN IF NEW.parent_id IS NULL THEN NEW.path = NEW.name; ELSE SELECT path INTO parent_path FROM public.document_folders WHERE id = NEW.parent_id; NEW.path = parent_path || '/' || NEW.name; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER folder_path_trigger BEFORE INSERT OR UPDATE ON public.document_folders FOR EACH ROW EXECUTE FUNCTION update_folder_path(); ALTER TABLE public.document_folders ENABLE ROW LEVEL SECURITY; CREATE POLICY "Folders visible based on visibility" ON public.document_folders FOR SELECT USING ( visibility = 'public' OR (visibility = 'members' AND auth.uid() IS NOT NULL) OR (visibility = 'board' AND EXISTS ( SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin') )) OR (visibility = 'admin' AND EXISTS ( SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin' )) ); CREATE POLICY "Board/admin can create folders" ON public.document_folders FOR INSERT WITH CHECK ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); CREATE POLICY "Board/admin can update folders" ON public.document_folders FOR UPDATE USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); CREATE POLICY "Admin can delete folders" ON public.document_folders FOR DELETE USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin') ); CREATE INDEX idx_document_folders_parent ON public.document_folders(parent_id); CREATE INDEX idx_documents_folder ON public.documents(folder_id); -- ============================================ -- MIGRATION 007: Dues Reminders -- ============================================ CREATE TABLE public.dues_reminder_logs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), member_id UUID NOT NULL REFERENCES public.members(id) ON DELETE CASCADE, reminder_type TEXT NOT NULL CHECK (reminder_type IN ('due_soon_30', 'due_soon_7', 'due_soon_1', 'overdue', 'grace_period', 'inactive_notice', 'onboarding_welcome', 'onboarding_reminder_7', 'onboarding_reminder_1', 'onboarding_expired')), due_date DATE NOT NULL, sent_at TIMESTAMPTZ DEFAULT NOW(), email_log_id UUID REFERENCES public.email_logs(id), UNIQUE(member_id, reminder_type, due_date) ); ALTER TABLE public.dues_reminder_logs ENABLE ROW LEVEL SECURITY; CREATE POLICY "Board/admin can view reminder logs" ON public.dues_reminder_logs FOR SELECT USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); CREATE POLICY "Service role can manage reminder logs" ON public.dues_reminder_logs FOR ALL USING (true) WITH CHECK (true); CREATE INDEX idx_reminder_logs_member_date ON public.dues_reminder_logs(member_id, due_date); CREATE INDEX idx_reminder_logs_type_sent ON public.dues_reminder_logs(reminder_type, sent_at); CREATE OR REPLACE FUNCTION get_dues_settings() RETURNS TABLE ( reminder_days_before INTEGER[], grace_period_days INTEGER, auto_inactive_enabled BOOLEAN, payment_iban TEXT, payment_account_holder TEXT, payment_bank_name TEXT ) AS $$ BEGIN RETURN QUERY SELECT COALESCE((SELECT (setting_value)::INTEGER[] FROM app_settings WHERE category = 'dues' AND setting_key = 'reminder_days_before'), ARRAY[30, 7, 1])::INTEGER[], COALESCE((SELECT (setting_value)::INTEGER FROM app_settings WHERE category = 'dues' AND setting_key = 'grace_period_days'), 30)::INTEGER, COALESCE((SELECT (setting_value)::BOOLEAN FROM app_settings WHERE category = 'dues' AND setting_key = 'auto_inactive_enabled'), true)::BOOLEAN, COALESCE((SELECT setting_value::TEXT FROM app_settings WHERE category = 'dues' AND setting_key = 'payment_iban'), '')::TEXT, COALESCE((SELECT setting_value::TEXT FROM app_settings WHERE category = 'dues' AND setting_key = 'payment_account_holder'), '')::TEXT, COALESCE((SELECT setting_value::TEXT FROM app_settings WHERE category = 'dues' AND setting_key = 'payment_bank_name'), '')::TEXT; END; $$ LANGUAGE plpgsql STABLE; -- ============================================ -- MIGRATION 008: S3 Public Endpoint -- ============================================ INSERT INTO public.app_settings (category, setting_key, setting_value, setting_type, display_name, description, is_public) VALUES ('storage', 's3_public_endpoint', '""', 'text', 'Public Endpoint URL', 'Browser-accessible S3 URL (e.g., http://localhost:9000). Leave empty to use the same as S3 Endpoint.', false) ON CONFLICT (category, setting_key) DO NOTHING; -- ============================================ -- MIGRATION 009: Dual Avatar URLs -- ============================================ ALTER TABLE public.members ADD COLUMN IF NOT EXISTS avatar_url_local TEXT; ALTER TABLE public.members ADD COLUMN IF NOT EXISTS avatar_url_s3 TEXT; ALTER TABLE public.members ADD COLUMN IF NOT EXISTS avatar_path TEXT; COMMENT ON COLUMN public.members.avatar_url IS 'Current active avatar URL (computed based on storage setting)'; COMMENT ON COLUMN public.members.avatar_url_local IS 'Avatar URL when stored in Supabase Storage'; COMMENT ON COLUMN public.members.avatar_url_s3 IS 'Avatar URL when stored in S3/MinIO'; COMMENT ON COLUMN public.members.avatar_path IS 'Storage path for avatar file (e.g., member_id/avatar.jpg)'; -- ============================================ -- MIGRATION 010: Storage Service Role Policies -- ============================================ -- Note: storage.objects is created by storage-api, these run conditionally DO $$ BEGIN -- Grant BYPASSRLS to service_role if possible IF EXISTS (SELECT 1 FROM pg_roles WHERE rolname = 'service_role' AND NOT rolbypassrls) THEN ALTER ROLE service_role BYPASSRLS; END IF; EXCEPTION WHEN insufficient_privilege THEN RAISE NOTICE 'Could not grant BYPASSRLS - using explicit policies'; WHEN OTHERS THEN RAISE NOTICE 'Error granting BYPASSRLS: %', SQLERRM; END $$; DO $$ BEGIN IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'storage' AND table_name = 'objects') THEN -- Drop existing policies DROP POLICY IF EXISTS "service_role_insert_avatars" ON storage.objects; DROP POLICY IF EXISTS "service_role_update_avatars" ON storage.objects; DROP POLICY IF EXISTS "service_role_delete_avatars" ON storage.objects; DROP POLICY IF EXISTS "service_role_select_avatars" ON storage.objects; DROP POLICY IF EXISTS "service_role_insert_documents" ON storage.objects; DROP POLICY IF EXISTS "service_role_update_documents" ON storage.objects; DROP POLICY IF EXISTS "service_role_delete_documents" ON storage.objects; DROP POLICY IF EXISTS "service_role_select_documents" ON storage.objects; DROP POLICY IF EXISTS "service_role_insert_event_images" ON storage.objects; DROP POLICY IF EXISTS "service_role_update_event_images" ON storage.objects; DROP POLICY IF EXISTS "service_role_delete_event_images" ON storage.objects; DROP POLICY IF EXISTS "service_role_select_event_images" ON storage.objects; DROP POLICY IF EXISTS "service_role_all_select" ON storage.objects; DROP POLICY IF EXISTS "service_role_all_insert" ON storage.objects; DROP POLICY IF EXISTS "service_role_all_update" ON storage.objects; DROP POLICY IF EXISTS "service_role_all_delete" ON storage.objects; -- Create universal service_role policies CREATE POLICY "service_role_all_select" ON storage.objects FOR SELECT TO service_role USING (true); CREATE POLICY "service_role_all_insert" ON storage.objects FOR INSERT TO service_role WITH CHECK (true); CREATE POLICY "service_role_all_update" ON storage.objects FOR UPDATE TO service_role USING (true); CREATE POLICY "service_role_all_delete" ON storage.objects FOR DELETE TO service_role USING (true); -- Grant permissions GRANT ALL ON storage.objects TO service_role; GRANT ALL ON storage.buckets TO service_role; END IF; END $$; -- Ensure storage schema access GRANT USAGE ON SCHEMA storage TO service_role; -- ============================================ -- MIGRATION 012: Dual Document URLs -- ============================================ ALTER TABLE public.documents ADD COLUMN IF NOT EXISTS file_url_local TEXT; ALTER TABLE public.documents ADD COLUMN IF NOT EXISTS file_url_s3 TEXT; ALTER TABLE public.documents ADD COLUMN IF NOT EXISTS storage_path TEXT; COMMENT ON COLUMN public.documents.file_path IS 'Current active file URL (computed based on storage setting) - kept for backwards compatibility'; COMMENT ON COLUMN public.documents.file_url_local IS 'File URL when stored in Supabase Storage'; COMMENT ON COLUMN public.documents.file_url_s3 IS 'File URL when stored in S3/MinIO'; COMMENT ON COLUMN public.documents.storage_path IS 'Storage path for file (e.g., timestamp-random-filename.pdf)'; CREATE INDEX IF NOT EXISTS idx_documents_storage_path ON public.documents(storage_path); -- ============================================ -- MIGRATION 014: Event Reminders -- ============================================ CREATE TABLE public.event_reminder_logs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), event_id UUID NOT NULL REFERENCES public.events(id) ON DELETE CASCADE, rsvp_id UUID NOT NULL REFERENCES public.event_rsvps(id) ON DELETE CASCADE, member_id UUID NOT NULL REFERENCES public.members(id) ON DELETE CASCADE, reminder_type TEXT NOT NULL DEFAULT '24hr' CHECK (reminder_type IN ('24hr', '1hr', 'day_of')), sent_at TIMESTAMPTZ DEFAULT NOW(), email_log_id UUID REFERENCES public.email_logs(id), UNIQUE(event_id, member_id, reminder_type) ); ALTER TABLE public.event_reminder_logs ENABLE ROW LEVEL SECURITY; CREATE POLICY "Board/admin can view event reminder logs" ON public.event_reminder_logs FOR SELECT USING ( EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role IN ('board', 'admin')) ); CREATE POLICY "Service role can manage event reminder logs" ON public.event_reminder_logs FOR ALL USING (true) WITH CHECK (true); CREATE INDEX idx_event_reminder_logs_event ON public.event_reminder_logs(event_id); CREATE INDEX idx_event_reminder_logs_member ON public.event_reminder_logs(member_id); CREATE INDEX idx_event_reminder_logs_sent ON public.event_reminder_logs(sent_at); INSERT INTO public.app_settings (category, setting_key, setting_value, display_name, description, is_public) VALUES ('events', 'event_reminders_enabled', 'true', 'Event Reminders Enabled', 'Enable automated event reminder emails', false), ('events', 'event_reminder_hours_before', '24', 'Reminder Hours Before', 'Hours before event to send reminder', false) ON CONFLICT (category, setting_key) DO NOTHING; CREATE OR REPLACE VIEW public.events_needing_reminders AS SELECT e.id AS event_id, e.title AS event_title, e.start_datetime, e.end_datetime, e.location, e.timezone, r.id AS rsvp_id, r.member_id, r.guest_count, r.status AS rsvp_status, m.first_name, m.last_name, m.email FROM public.events e JOIN public.event_rsvps r ON r.event_id = e.id JOIN public.members m ON m.id = r.member_id WHERE e.status = 'published' AND e.start_datetime > NOW() AND e.start_datetime <= NOW() + INTERVAL '25 hours' AND e.start_datetime > NOW() + INTERVAL '23 hours' AND r.status = 'confirmed' AND NOT EXISTS ( SELECT 1 FROM public.event_reminder_logs erl WHERE erl.event_id = e.id AND erl.member_id = r.member_id AND erl.reminder_type = '24hr' ) AND m.email IS NOT NULL; -- ============================================ -- MIGRATION 016: Onboarding Payment Tracking -- ============================================ ALTER TABLE public.members ADD COLUMN IF NOT EXISTS payment_deadline TIMESTAMPTZ; ALTER TABLE public.members ADD COLUMN IF NOT EXISTS onboarding_completed_at TIMESTAMPTZ; CREATE INDEX IF NOT EXISTS idx_members_payment_deadline ON public.members(payment_deadline) WHERE payment_deadline IS NOT NULL; -- ============================================ -- GRANT SERVICE_ROLE ACCESS TO ALL TABLES -- ============================================ -- Ensure service_role has full access to all public tables GRANT ALL ON ALL TABLES IN SCHEMA public TO service_role; GRANT ALL ON ALL SEQUENCES IN SCHEMA public TO service_role; -- Set default privileges for future tables ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT ALL ON TABLES TO service_role; ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT ALL ON SEQUENCES TO service_role; -- ============================================ -- END OF COMBINED MIGRATIONS -- ============================================