-- Add audit logging to submission lock RPC functions CREATE OR REPLACE FUNCTION public.claim_next_submission( moderator_id UUID, lock_duration INTERVAL DEFAULT '15 minutes' ) RETURNS TABLE ( submission_id UUID, submission_type TEXT, waiting_time INTERVAL ) LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE claimed_submission RECORD; BEGIN UPDATE content_submissions SET assigned_to = moderator_id, assigned_at = NOW(), locked_until = NOW() + lock_duration, first_reviewed_at = COALESCE(first_reviewed_at, NOW()) WHERE id = ( SELECT cs.id FROM content_submissions cs WHERE cs.status IN ('pending', 'partially_approved') AND (cs.assigned_to IS NULL OR cs.locked_until < NOW()) ORDER BY cs.escalated DESC, cs.submitted_at ASC LIMIT 1 FOR UPDATE SKIP LOCKED ) RETURNING content_submissions.id, content_submissions.submission_type, content_submissions.user_id, NOW() - content_submissions.submitted_at INTO claimed_submission; IF FOUND THEN BEGIN PERFORM log_admin_action( moderator_id, claimed_submission.user_id, 'submission_claimed', jsonb_build_object( 'submission_id', claimed_submission.id, 'submission_type', claimed_submission.submission_type ) ); EXCEPTION WHEN OTHERS THEN RAISE WARNING 'Failed to log submission claim audit: %', SQLERRM; END; END IF; RETURN QUERY SELECT claimed_submission.id, claimed_submission.submission_type, claimed_submission.waiting_time; END; $$; CREATE OR REPLACE FUNCTION release_submission_lock( submission_id UUID, moderator_id UUID ) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE submission_details RECORD; BEGIN SELECT user_id, submission_type INTO submission_details FROM content_submissions WHERE id = submission_id AND assigned_to = moderator_id; UPDATE content_submissions SET assigned_to = NULL, assigned_at = NULL, locked_until = NULL WHERE id = submission_id AND assigned_to = moderator_id; IF FOUND THEN BEGIN PERFORM log_admin_action( moderator_id, submission_details.user_id, 'submission_released', jsonb_build_object( 'submission_id', submission_id, 'submission_type', submission_details.submission_type ) ); EXCEPTION WHEN OTHERS THEN RAISE WARNING 'Failed to log submission release audit: %', SQLERRM; END; END IF; RETURN FOUND; END; $$; CREATE OR REPLACE FUNCTION extend_submission_lock( submission_id UUID, moderator_id UUID, extension_duration INTERVAL DEFAULT '15 minutes' ) RETURNS TIMESTAMP WITH TIME ZONE LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE new_lock_time TIMESTAMP WITH TIME ZONE; submission_details RECORD; BEGIN SELECT user_id, submission_type INTO submission_details FROM content_submissions WHERE id = submission_id AND assigned_to = moderator_id; UPDATE content_submissions SET locked_until = NOW() + extension_duration WHERE id = submission_id AND assigned_to = moderator_id RETURNING locked_until INTO new_lock_time; IF FOUND THEN BEGIN PERFORM log_admin_action( moderator_id, submission_details.user_id, 'submission_lock_extended', jsonb_build_object( 'submission_id', submission_id, 'submission_type', submission_details.submission_type, 'new_lock_until', new_lock_time ) ); EXCEPTION WHEN OTHERS THEN RAISE WARNING 'Failed to log submission lock extension audit: %', SQLERRM; END; END IF; RETURN new_lock_time; END; $$;