monacousa-portal/deploy/post-deploy.sql

227 lines
9.8 KiB
PL/PgSQL

-- Monaco USA Portal - Post-Deployment Database Fixes
-- This script is IDEMPOTENT - safe to run multiple times.
-- Run after `docker compose up` once all containers are healthy.
--
-- Handles:
-- 1. Storage RLS policies (storage-api creates tables AFTER db init)
-- 2. Service role access grants
-- 3. Incremental migrations for existing databases
-- 4. Notifications table (if missing)
-- ============================================================================
-- ============================================
-- 1. STORAGE POLICIES
-- storage-api creates storage.objects and storage.buckets with RLS enabled
-- but no policies. We need to add service_role policies so the portal
-- can upload/delete files via supabaseAdmin.
-- ============================================
DO $$
BEGIN
-- Ensure service_role has BYPASSRLS
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 to service_role - will rely on explicit policies';
END $$;
-- storage.objects policies
DO $$
BEGIN
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'storage' AND table_name = 'objects') THEN
-- Drop and recreate to ensure clean state
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 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);
-- Public read access for avatars and event images
DROP POLICY IF EXISTS "public_read_avatars" ON storage.objects;
CREATE POLICY "public_read_avatars" ON storage.objects
FOR SELECT USING (bucket_id IN ('avatars', 'event-images'));
-- Authenticated users can read documents
DROP POLICY IF EXISTS "authenticated_read_documents" ON storage.objects;
CREATE POLICY "authenticated_read_documents" ON storage.objects
FOR SELECT TO authenticated USING (bucket_id = 'documents');
GRANT ALL ON storage.objects TO service_role;
RAISE NOTICE 'storage.objects policies applied';
ELSE
RAISE NOTICE 'storage.objects table not found - storage-api may not have started yet';
END IF;
END $$;
-- storage.buckets policies
DO $$
BEGIN
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'storage' AND table_name = 'buckets') THEN
DROP POLICY IF EXISTS "service_role_all_buckets_select" ON storage.buckets;
DROP POLICY IF EXISTS "service_role_all_buckets_insert" ON storage.buckets;
DROP POLICY IF EXISTS "service_role_all_buckets_update" ON storage.buckets;
DROP POLICY IF EXISTS "service_role_all_buckets_delete" ON storage.buckets;
CREATE POLICY "service_role_all_buckets_select" ON storage.buckets
FOR SELECT TO service_role USING (true);
CREATE POLICY "service_role_all_buckets_insert" ON storage.buckets
FOR INSERT TO service_role WITH CHECK (true);
CREATE POLICY "service_role_all_buckets_update" ON storage.buckets
FOR UPDATE TO service_role USING (true);
CREATE POLICY "service_role_all_buckets_delete" ON storage.buckets
FOR DELETE TO service_role USING (true);
-- Allow authenticated users to read bucket info (needed for uploads)
DROP POLICY IF EXISTS "authenticated_read_buckets" ON storage.buckets;
CREATE POLICY "authenticated_read_buckets" ON storage.buckets
FOR SELECT TO authenticated USING (true);
GRANT ALL ON storage.buckets TO service_role;
RAISE NOTICE 'storage.buckets policies applied';
ELSE
RAISE NOTICE 'storage.buckets table not found - storage-api may not have started yet';
END IF;
END $$;
-- Ensure schema and general grants
GRANT USAGE ON SCHEMA storage TO service_role;
GRANT USAGE ON SCHEMA storage TO authenticated;
-- ============================================
-- 2. STORAGE BUCKETS
-- Ensure required buckets exist
-- ============================================
DO $$
BEGIN
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'storage' AND table_name = 'buckets') THEN
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;
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;
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;
RAISE NOTICE 'Storage buckets ensured';
END IF;
END $$;
-- ============================================
-- 3. NOTIFICATIONS TABLE (added post-migration-016)
-- ============================================
CREATE TABLE IF NOT EXISTS public.notifications (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
member_id UUID NOT NULL REFERENCES public.members(id) ON DELETE CASCADE,
type TEXT NOT NULL CHECK (type IN ('welcome', 'event', 'payment', 'membership', 'system', 'announcement')),
title TEXT NOT NULL,
message TEXT NOT NULL,
link TEXT,
read_at TIMESTAMPTZ,
created_at TIMESTAMPTZ DEFAULT NOW()
);
CREATE INDEX IF NOT EXISTS idx_notifications_member ON public.notifications(member_id);
CREATE INDEX IF NOT EXISTS idx_notifications_unread ON public.notifications(member_id) WHERE read_at IS NULL;
CREATE INDEX IF NOT EXISTS idx_notifications_created ON public.notifications(created_at DESC);
ALTER TABLE public.notifications ENABLE ROW LEVEL SECURITY;
-- Idempotent policy creation
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_policy WHERE polrelid = 'public.notifications'::regclass AND polname = 'Members can view own notifications') THEN
CREATE POLICY "Members can view own notifications"
ON public.notifications FOR SELECT TO authenticated
USING (member_id = auth.uid());
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_policy WHERE polrelid = 'public.notifications'::regclass AND polname = 'Members can update own notifications') THEN
CREATE POLICY "Members can update own notifications"
ON public.notifications FOR UPDATE TO authenticated
USING (member_id = auth.uid());
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_policy WHERE polrelid = 'public.notifications'::regclass AND polname = 'Admin can manage all notifications') THEN
CREATE POLICY "Admin can manage all notifications"
ON public.notifications FOR ALL TO authenticated
USING (EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin'))
WITH CHECK (EXISTS (SELECT 1 FROM public.members WHERE id = auth.uid() AND role = 'admin'));
END IF;
END $$;
GRANT SELECT, UPDATE ON public.notifications TO authenticated;
GRANT ALL ON public.notifications TO service_role;
-- Welcome notification trigger
CREATE OR REPLACE FUNCTION create_welcome_notification()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO public.notifications (member_id, type, title, message, link)
VALUES (
NEW.id, 'welcome',
'Welcome to Monaco USA!',
'Thank you for joining our community. Complete your profile and explore upcoming events.',
'/profile'
);
RETURN NEW;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
DROP TRIGGER IF EXISTS on_member_created_notification ON public.members;
CREATE TRIGGER on_member_created_notification
AFTER INSERT ON public.members
FOR EACH ROW
EXECUTE FUNCTION create_welcome_notification();
-- ============================================
-- 4. MIGRATION 017: Fix RLS role escalation
-- ============================================
DROP POLICY IF EXISTS "Users can update own profile" ON public.members;
CREATE POLICY "Users can update own profile"
ON public.members FOR UPDATE
TO authenticated
USING (auth.uid() = id)
WITH CHECK (
auth.uid() = id
AND role = (SELECT m.role FROM public.members m WHERE m.id = auth.uid())
);
-- ============================================
-- 5. ENSURE SERVICE_ROLE ACCESS TO ALL TABLES
-- ============================================
GRANT ALL ON ALL TABLES IN SCHEMA public TO service_role;
GRANT ALL ON ALL SEQUENCES IN SCHEMA public TO service_role;
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;
-- ============================================
-- DONE
-- ============================================
DO $$ BEGIN RAISE NOTICE '=== Post-deploy script completed successfully ==='; END $$;