Files
thrilltrack-explorer/supabase/migrations/20251106043242_e648df5e-d4ca-4e6a-8f37-d8ebb787daf3.sql
2025-11-06 04:33:26 +00:00

70 lines
1.7 KiB
PL/PgSQL

-- Update log_moderation_action to use session variable for moderator_id
-- This allows edge functions using service role to pass the actual moderator ID
CREATE OR REPLACE FUNCTION public.log_moderation_action(
_submission_id uuid,
_action text,
_previous_status text DEFAULT NULL::text,
_new_status text DEFAULT NULL::text,
_notes text DEFAULT NULL::text,
_metadata jsonb DEFAULT '{}'::jsonb
)
RETURNS uuid
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO 'public'
AS $function$
DECLARE
_log_id UUID;
_metadata_record record;
_moderator_id UUID;
BEGIN
-- Get moderator ID from session variable (set by edge function) or auth.uid()
BEGIN
_moderator_id := COALESCE(
current_setting('app.moderator_id', true)::uuid,
auth.uid()
);
EXCEPTION WHEN OTHERS THEN
_moderator_id := auth.uid();
END;
-- Insert into moderation_audit_log (without metadata JSONB column)
INSERT INTO public.moderation_audit_log (
submission_id,
moderator_id,
action,
previous_status,
new_status,
notes
) VALUES (
_submission_id,
_moderator_id,
_action,
_previous_status,
_new_status,
_notes
)
RETURNING id INTO _log_id;
-- Write metadata to relational moderation_audit_metadata table
IF _metadata IS NOT NULL AND jsonb_typeof(_metadata) = 'object' THEN
FOR _metadata_record IN
SELECT key, value::text as text_value
FROM jsonb_each_text(_metadata)
LOOP
INSERT INTO public.moderation_audit_metadata (
audit_log_id,
metadata_key,
metadata_value
) VALUES (
_log_id,
_metadata_record.key,
_metadata_record.text_value
);
END LOOP;
END IF;
RETURN _log_id;
END;
$function$;