-- ============================================ -- UNIFIED RLS CONSOLIDATION & TABLE FIXES -- ============================================ -- 1. Fix Table Mismatch (Rename to match services) -- 2. Consolidate RLS for Bottles, Tastings, Sessions -- 3. Resolve Naming Conflicts (tasting_tags vs tasting_buddies) -- ============================================ -- 1. FIX TABLE NAMES (Ensuring consistency across project) DO $$ BEGIN -- If 'tasting_tags' currently contains buddy_id (old schema), rename it IF EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'tasting_tags' AND column_name = 'buddy_id' ) THEN DROP TABLE IF EXISTS tasting_buddies CASCADE; ALTER TABLE tasting_tags RENAME TO tasting_buddies; END IF; -- Ensure 'tasting_tags' exists for Aroma Tags (Aroma Filter) IF NOT EXISTS (SELECT 1 FROM pg_tables WHERE tablename = 'tasting_tags') THEN CREATE TABLE tasting_tags ( tasting_id UUID REFERENCES tastings(id) ON DELETE CASCADE NOT NULL, tag_id UUID REFERENCES tags(id) ON DELETE CASCADE NOT NULL, user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL, PRIMARY KEY (tasting_id, tag_id) ); END IF; END $$; -- Enable RLS on all relevant tables ALTER TABLE bottles ENABLE ROW LEVEL SECURITY; ALTER TABLE tastings ENABLE ROW LEVEL SECURITY; ALTER TABLE tasting_sessions ENABLE ROW LEVEL SECURITY; ALTER TABLE tasting_buddies ENABLE ROW LEVEL SECURITY; ALTER TABLE tasting_tags ENABLE ROW LEVEL SECURITY; -- 2. UNIFIED BOTTLES POLICIES DROP POLICY IF EXISTS "bottles_policy" ON bottles; DROP POLICY IF EXISTS "bottles_select_policy" ON bottles; DROP POLICY IF EXISTS "bottles_insert_policy" ON bottles; DROP POLICY IF EXISTS "bottles_update_policy" ON bottles; DROP POLICY IF EXISTS "bottles_delete_policy" ON bottles; -- SELECT: owner OR split participant OR session buddy CREATE POLICY "bottles_select_policy" ON bottles FOR SELECT USING ( (SELECT auth.uid()) = user_id OR EXISTS (SELECT 1 FROM bottle_splits WHERE bottle_id = bottles.id AND is_active = true) OR EXISTS ( SELECT 1 FROM tasting_sessions ts JOIN session_participants sp ON sp.session_id = ts.id JOIN buddies b ON b.id = sp.buddy_id JOIN tastings t ON t.session_id = ts.id WHERE t.bottle_id = bottles.id AND b.buddy_profile_id = (SELECT auth.uid()) ) ); CREATE POLICY "bottles_insert_policy" ON bottles FOR INSERT WITH CHECK ((SELECT auth.uid()) = user_id); CREATE POLICY "bottles_update_policy" ON bottles FOR UPDATE USING ((SELECT auth.uid()) = user_id); CREATE POLICY "bottles_delete_policy" ON bottles FOR DELETE USING ((SELECT auth.uid()) = user_id); -- 3. UNIFIED TASTINGS POLICIES DROP POLICY IF EXISTS "tastings_policy" ON tastings; DROP POLICY IF EXISTS "tastings_select_policy" ON tastings; DROP POLICY IF EXISTS "tastings_insert_policy" ON tastings; DROP POLICY IF EXISTS "tastings_update_policy" ON tastings; DROP POLICY IF EXISTS "tastings_delete_policy" ON tastings; DROP POLICY IF EXISTS "tastings_modify_policy" ON tastings; -- SELECT: owner OR buddy in the same tasting/session CREATE POLICY "tastings_select_policy" ON tastings FOR SELECT USING ( (SELECT auth.uid()) = user_id OR EXISTS ( SELECT 1 FROM tasting_buddies tb JOIN buddies b ON b.id = tb.buddy_id WHERE tb.tasting_id = tastings.id AND b.buddy_profile_id = (SELECT auth.uid()) ) ); -- INSERT: Anyone can insert if they are the user_id (the owner of the note) CREATE POLICY "tastings_insert_policy" ON tastings FOR INSERT WITH CHECK ((SELECT auth.uid()) = user_id); -- UPDATE/DELETE: strictly owner CREATE POLICY "tastings_modify_policy" ON tastings FOR ALL USING ((SELECT auth.uid()) = user_id); -- 4. UNIFIED JOIN TABLES POLICIES (Buddies & Aroma Tags) DROP POLICY IF EXISTS "tasting_buddies_policy" ON tasting_buddies; DROP POLICY IF EXISTS "tasting_tags_policy" ON tasting_tags; CREATE POLICY "tasting_buddies_policy" ON tasting_buddies FOR ALL USING ((SELECT auth.uid()) = user_id); CREATE POLICY "tasting_tags_policy" ON tasting_tags FOR ALL USING ((SELECT auth.uid()) = user_id); -- 5. UNIFIED SESSIONS POLICIES DROP POLICY IF EXISTS "tasting_sessions_policy" ON tasting_sessions; DROP POLICY IF EXISTS "sessions_access_policy" ON tasting_sessions; CREATE POLICY "tasting_sessions_policy" ON tasting_sessions FOR ALL USING ( (SELECT auth.uid()) = user_id OR id IN ( SELECT sp.session_id FROM session_participants sp JOIN buddies b ON b.id = sp.buddy_id WHERE b.buddy_profile_id = (SELECT auth.uid()) ) ); -- 6. BOTTLE SPLITS & RECURSION FIXES -- Breaks loop between bottle_splits and split_participants CREATE OR REPLACE FUNCTION public.check_is_split_host(check_split_id UUID, check_user_id UUID) RETURNS BOOLEAN AS $$ BEGIN RETURN EXISTS ( SELECT 1 FROM public.bottle_splits WHERE id = check_split_id AND host_id = check_user_id ); END; $$ LANGUAGE plpgsql SECURITY DEFINER; CREATE OR REPLACE FUNCTION public.check_is_split_participant(check_split_id UUID, check_user_id UUID) RETURNS BOOLEAN AS $$ BEGIN RETURN EXISTS ( SELECT 1 FROM public.split_participants WHERE split_id = check_split_id AND user_id = check_user_id ); END; $$ LANGUAGE plpgsql SECURITY DEFINER; DROP POLICY IF EXISTS "bottle_splits_host_policy" ON bottle_splits; DROP POLICY IF EXISTS "bottle_splits_participant_view" ON bottle_splits; DROP POLICY IF EXISTS "bottle_splits_public_select" ON bottle_splits; CREATE POLICY "bottle_splits_host_policy" ON bottle_splits FOR ALL USING ((SELECT auth.uid()) = host_id); CREATE POLICY "bottle_splits_participant_view" ON bottle_splits FOR SELECT USING (check_is_split_participant(id, (SELECT auth.uid()))); CREATE POLICY "bottle_splits_public_select" ON bottle_splits FOR SELECT USING (is_active = true); -- 7. SPLIT PARTICIPANTS DROP POLICY IF EXISTS "split_participants_own_policy" ON split_participants; DROP POLICY IF EXISTS "split_participants_host_policy" ON split_participants; DROP POLICY IF EXISTS "split_participants_public_select" ON split_participants; CREATE POLICY "split_participants_own_policy" ON split_participants FOR ALL USING ((SELECT auth.uid()) = user_id); CREATE POLICY "split_participants_host_policy" ON split_participants FOR ALL USING (check_is_split_host(split_id, (SELECT auth.uid()))); CREATE POLICY "split_participants_public_select" ON split_participants FOR SELECT USING ( EXISTS ( SELECT 1 FROM public.bottle_splits WHERE id = split_participants.split_id AND is_active = true ) );