-- ============================================================================ -- Fix remaining SECURITY DEFINER functions without search_path -- ============================================================================ -- Fix all notification trigger functions CREATE OR REPLACE FUNCTION notify_moderators_submission_new() RETURNS trigger LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE base_url text; edge_function_url text; payload jsonb; BEGIN SELECT setting_value::text INTO base_url FROM admin_settings WHERE setting_key = 'supabase_api_url'; base_url := trim(both '"' from base_url); IF base_url IS NULL THEN base_url := 'https://api.thrillwiki.com'; END IF; edge_function_url := base_url || '/functions/v1/notify-moderators'; payload := jsonb_build_object( 'event_type', 'new_submission', 'submission_id', NEW.id, 'submission_type', NEW.submission_type, 'user_id', NEW.user_id ); PERFORM public.pg_net.http_post( edge_function_url, payload::text, 'application/json' ); RETURN NEW; EXCEPTION WHEN OTHERS THEN RAISE NOTICE 'Failed to notify moderators: %', SQLERRM; RETURN NEW; END; $$; CREATE OR REPLACE FUNCTION notify_moderators_report_new() RETURNS trigger LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE base_url text; edge_function_url text; payload jsonb; BEGIN SELECT setting_value::text INTO base_url FROM admin_settings WHERE setting_key = 'supabase_api_url'; base_url := trim(both '"' from base_url); IF base_url IS NULL THEN base_url := 'https://api.thrillwiki.com'; END IF; edge_function_url := base_url || '/functions/v1/notify-moderators'; payload := jsonb_build_object( 'event_type', 'new_report', 'report_id', NEW.id, 'reported_content_type', NEW.content_type, 'reporter_id', NEW.reporter_id ); PERFORM public.pg_net.http_post( edge_function_url, payload::text, 'application/json' ); RETURN NEW; EXCEPTION WHEN OTHERS THEN RAISE NOTICE 'Failed to notify moderators: %', SQLERRM; RETURN NEW; END; $$; CREATE OR REPLACE FUNCTION get_current_user_id() RETURNS uuid LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE v_user_id uuid; v_auth0_sub text; BEGIN v_user_id := auth.uid(); IF v_user_id IS NOT NULL THEN RETURN v_user_id; END IF; v_auth0_sub := current_setting('request.jwt.claims', true)::json->>'sub'; IF v_auth0_sub IS NOT NULL THEN SELECT user_id INTO v_user_id FROM public.profiles WHERE auth0_sub = v_auth0_sub; RETURN v_user_id; END IF; RETURN NULL; END; $$; CREATE OR REPLACE FUNCTION has_auth0_mfa() RETURNS boolean LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE v_amr jsonb; BEGIN v_amr := current_setting('request.jwt.claims', true)::json->'amr'; RETURN v_amr ? 'mfa'; EXCEPTION WHEN OTHERS THEN RETURN false; END; $$; CREATE OR REPLACE FUNCTION is_auth0_user() RETURNS boolean LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE v_iss text; BEGIN v_iss := current_setting('request.jwt.claims', true)::json->>'iss'; RETURN v_iss LIKE '%auth0.com%'; EXCEPTION WHEN OTHERS THEN RETURN false; END; $$; CREATE OR REPLACE FUNCTION get_auth0_sub_from_jwt() RETURNS text LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ BEGIN RETURN current_setting('request.jwt.claims', true)::json->>'sub'; EXCEPTION WHEN OTHERS THEN RETURN NULL; END; $$; CREATE OR REPLACE FUNCTION auto_log_submission_changes() RETURNS trigger LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE _action TEXT; BEGIN IF OLD.status != NEW.status THEN _action := CASE WHEN NEW.status = 'approved' THEN 'approve' WHEN NEW.status = 'rejected' THEN 'reject' WHEN NEW.status = 'pending' THEN 'reset' ELSE 'update' END; PERFORM log_moderation_action( NEW.id, _action, OLD.status, NEW.status, NEW.reviewer_notes ); ELSIF OLD.assigned_to IS NULL AND NEW.assigned_to IS NOT NULL THEN PERFORM log_moderation_action( NEW.id, 'claim', NULL, NULL, NULL, jsonb_build_object('locked_until', NEW.locked_until) ); ELSIF OLD.assigned_to IS NOT NULL AND NEW.assigned_to IS NULL THEN PERFORM log_moderation_action( NEW.id, 'release', NULL, NULL, NULL, jsonb_build_object('previous_lock', OLD.locked_until) ); ELSIF OLD.locked_until IS NOT NULL AND NEW.locked_until IS NOT NULL AND NEW.locked_until > OLD.locked_until THEN PERFORM log_moderation_action( NEW.id, 'extend_lock', NULL, NULL, NULL, jsonb_build_object('old_expiry', OLD.locked_until, 'new_expiry', NEW.locked_until) ); END IF; RETURN NEW; END; $$; CREATE OR REPLACE FUNCTION can_manage_deletion(_user_id uuid, _deletion_id uuid) RETURNS boolean LANGUAGE sql STABLE SECURITY DEFINER SET search_path = public AS $$ SELECT EXISTS ( SELECT 1 FROM account_deletion_requests WHERE id = _deletion_id AND user_id = _user_id AND status IN ('pending', 'confirmed') ) $$; CREATE OR REPLACE FUNCTION audit_role_changes() RETURNS trigger LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ BEGIN IF TG_OP = 'INSERT' THEN INSERT INTO public.admin_audit_log ( admin_user_id, target_user_id, action, details ) VALUES ( auth.uid(), NEW.user_id, 'role_granted', jsonb_build_object( 'role', NEW.role, 'timestamp', now() ) ); ELSIF TG_OP = 'DELETE' THEN INSERT INTO public.admin_audit_log ( admin_user_id, target_user_id, action, details ) VALUES ( auth.uid(), OLD.user_id, 'role_revoked', jsonb_build_object( 'role', OLD.role, 'timestamp', now() ) ); END IF; RETURN COALESCE(NEW, OLD); END; $$; DO $$ BEGIN RAISE NOTICE '✅ Fixed search_path for all SECURITY DEFINER functions'; END $$;