-- Create function to atomically claim a specific submission CREATE OR REPLACE FUNCTION public.claim_specific_submission( p_submission_id UUID, p_moderator_id UUID, p_lock_duration INTERVAL DEFAULT '15 minutes' ) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE rows_updated INTEGER; BEGIN -- Atomically update the submission if it's unclaimed or lock expired UPDATE content_submissions SET assigned_to = p_moderator_id, assigned_at = NOW(), locked_until = NOW() + p_lock_duration, first_reviewed_at = COALESCE(first_reviewed_at, NOW()) WHERE id = p_submission_id AND ( assigned_to IS NULL OR locked_until < NOW() ) AND status = 'pending'; GET DIAGNOSTICS rows_updated = ROW_COUNT; -- Log the action if successful IF rows_updated > 0 THEN BEGIN PERFORM log_admin_action( p_moderator_id, (SELECT user_id FROM content_submissions WHERE id = p_submission_id), 'submission_claimed', jsonb_build_object( 'submission_id', p_submission_id, 'claim_type', 'specific' ) ); EXCEPTION WHEN OTHERS THEN RAISE WARNING 'Failed to log submission claim audit: %', SQLERRM; END; RETURN TRUE; END IF; RETURN FALSE; END; $$;