-- Phase 1 & 4: Comprehensive Ban Enforcement (Corrected) -- Create security definer function to check if user is banned CREATE OR REPLACE FUNCTION public.is_user_banned(_user_id uuid) RETURNS boolean LANGUAGE sql STABLE SECURITY DEFINER SET search_path = public AS $$ SELECT COALESCE( (SELECT banned FROM public.profiles WHERE user_id = _user_id), false ) $$; -- Update RLS policies for content_submissions DROP POLICY IF EXISTS "Users can create submissions" ON content_submissions; CREATE POLICY "Users can create submissions" ON content_submissions FOR INSERT TO authenticated WITH CHECK ( (auth.uid() = user_id) AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for park_submissions DROP POLICY IF EXISTS "Users can insert their own park submissions" ON park_submissions; CREATE POLICY "Users can insert their own park submissions" ON park_submissions FOR INSERT TO authenticated WITH CHECK ( EXISTS (SELECT 1 FROM content_submissions cs WHERE cs.id = park_submissions.submission_id AND cs.user_id = auth.uid()) AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for ride_submissions DROP POLICY IF EXISTS "Users can insert their own ride submissions" ON ride_submissions; CREATE POLICY "Users can insert their own ride submissions" ON ride_submissions FOR INSERT TO authenticated WITH CHECK ( EXISTS (SELECT 1 FROM content_submissions cs WHERE cs.id = ride_submissions.submission_id AND cs.user_id = auth.uid()) AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for company_submissions DROP POLICY IF EXISTS "Users can insert their own company submissions" ON company_submissions; CREATE POLICY "Users can insert their own company submissions" ON company_submissions FOR INSERT TO authenticated WITH CHECK ( EXISTS (SELECT 1 FROM content_submissions cs WHERE cs.id = company_submissions.submission_id AND cs.user_id = auth.uid()) AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for ride_model_submissions DROP POLICY IF EXISTS "Users can insert their own ride model submissions" ON ride_model_submissions; CREATE POLICY "Users can insert their own ride model submissions" ON ride_model_submissions FOR INSERT TO authenticated WITH CHECK ( EXISTS (SELECT 1 FROM content_submissions cs WHERE cs.id = ride_model_submissions.submission_id AND cs.user_id = auth.uid()) AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for photo_submissions DROP POLICY IF EXISTS "Users can insert their own photo submissions" ON photo_submissions; CREATE POLICY "Users can insert their own photo submissions" ON photo_submissions FOR INSERT TO authenticated WITH CHECK ( EXISTS (SELECT 1 FROM content_submissions cs WHERE cs.id = photo_submissions.submission_id AND cs.user_id = auth.uid()) AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for submission_items DROP POLICY IF EXISTS "Users can insert their own submission items" ON submission_items; CREATE POLICY "Users can insert their own submission items" ON submission_items FOR INSERT TO authenticated WITH CHECK ( EXISTS (SELECT 1 FROM content_submissions cs WHERE cs.id = submission_items.submission_id AND cs.user_id = auth.uid()) AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for reviews (using user_id) DROP POLICY IF EXISTS "Users can create reviews" ON reviews; CREATE POLICY "Users can create reviews" ON reviews FOR INSERT TO authenticated WITH CHECK ( user_id = auth.uid() AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for photos (using submitted_by) DROP POLICY IF EXISTS "Users can insert their own photos" ON photos; CREATE POLICY "Users can insert their own photos" ON photos FOR INSERT TO authenticated WITH CHECK ( submitted_by = auth.uid() AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for user_blocks DROP POLICY IF EXISTS "Users can block other users" ON user_blocks; CREATE POLICY "Users can block other users" ON user_blocks FOR INSERT TO authenticated WITH CHECK ( blocker_id = auth.uid() AND NOT is_user_banned(auth.uid()) ); -- Update RLS policies for contact_submissions DROP POLICY IF EXISTS "Anyone can submit contact form" ON contact_submissions; CREATE POLICY "Anyone can submit contact form" ON contact_submissions FOR INSERT TO authenticated WITH CHECK ( (user_id = auth.uid() OR user_id IS NULL) AND NOT is_user_banned(auth.uid()) ); -- Phase 4: Create trigger to invalidate sessions when user is banned CREATE OR REPLACE FUNCTION public.invalidate_banned_user_sessions() RETURNS TRIGGER LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ BEGIN -- If user was just banned (banned changed from false to true) IF NEW.banned = true AND OLD.banned = false THEN -- Notify application layer about the ban PERFORM pg_notify( 'user_banned', json_build_object( 'user_id', NEW.user_id, 'username', NEW.username, 'banned_at', NOW() )::text ); END IF; RETURN NEW; END; $$; DROP TRIGGER IF EXISTS enforce_ban_on_profile_update ON public.profiles; CREATE TRIGGER enforce_ban_on_profile_update AFTER UPDATE ON public.profiles FOR EACH ROW WHEN (NEW.banned IS DISTINCT FROM OLD.banned) EXECUTE FUNCTION invalidate_banned_user_sessions();