diff --git a/supabase/migrations/20251008225526_97c57bee-3394-4edc-aa39-b50a6e271b8a.sql b/supabase/migrations/20251008225526_97c57bee-3394-4edc-aa39-b50a6e271b8a.sql new file mode 100644 index 00000000..e6932320 --- /dev/null +++ b/supabase/migrations/20251008225526_97c57bee-3394-4edc-aa39-b50a6e271b8a.sql @@ -0,0 +1,31 @@ +-- Fix Security Definer View warning by explicitly setting SECURITY INVOKER +-- This ensures the view uses the querying user's permissions, not the view creator's + +-- Drop and recreate the moderation_sla_metrics view with explicit SECURITY INVOKER +DROP VIEW IF EXISTS public.moderation_sla_metrics; + +CREATE VIEW public.moderation_sla_metrics +WITH (security_invoker = true) +AS +SELECT + submission_type, + COUNT(*) FILTER (WHERE status IN ('pending', 'partially_approved')) AS pending_count, + AVG(EXTRACT(EPOCH FROM (NOW() - submitted_at)) / 3600) + FILTER (WHERE status IN ('pending', 'partially_approved')) AS avg_wait_hours, + MAX(EXTRACT(EPOCH FROM (NOW() - submitted_at)) / 3600) + FILTER (WHERE status IN ('pending', 'partially_approved')) AS max_wait_hours, + AVG(EXTRACT(EPOCH FROM (resolved_at - submitted_at)) / 3600) + FILTER (WHERE status IN ('approved', 'rejected')) AS avg_resolution_hours, + COUNT(*) FILTER (WHERE escalated = true AND status IN ('pending', 'partially_approved')) AS escalated_count, + COUNT(*) FILTER (WHERE review_count > 1) AS reassigned_count, + COUNT(*) FILTER (WHERE assigned_to IS NOT NULL AND locked_until > NOW()) AS currently_locked +FROM public.content_submissions +GROUP BY submission_type; + +-- Add helpful comment +COMMENT ON VIEW public.moderation_sla_metrics IS +'Moderation queue SLA metrics. Uses SECURITY INVOKER to enforce RLS policies of the querying user.'; + +-- Grant appropriate access +GRANT SELECT ON public.moderation_sla_metrics TO authenticated; +GRANT SELECT ON public.moderation_sla_metrics TO service_role; \ No newline at end of file