Files
thrilltrack-explorer/supabase/migrations/20251110132555_bafeab71-bea0-4704-92de-b0b68921fe58.sql
gpt-engineer-app[bot] 6c03a5b0e7 Implement rejection bulletproofing
Created atomic rejection edge function process-selective-rejection and RPC, updated moderation client to use it, and ensured resilience; added CORS wrapper. Reminder: generate package-lock.json by running npm install.
2025-11-10 13:26:13 +00:00

159 lines
5.3 KiB
PL/PgSQL

-- ============================================================================
-- CRITICAL: Add Atomic Rejection Transaction RPC
-- ============================================================================
-- This migration creates process_rejection_transaction to ensure atomic
-- rejection of submission items with proper audit logging and status updates.
--
-- Features:
-- - Atomic updates to submission_items.status = 'rejected'
-- - Sets rejection_reason for each item
-- - Updates parent submission status (rejected or partially_approved)
-- - Logs to moderation_audit_log
-- - Releases lock (assigned_to = NULL, locked_until = NULL)
-- - Returns transaction result
-- ============================================================================
CREATE OR REPLACE FUNCTION process_rejection_transaction(
p_submission_id UUID,
p_item_ids UUID[],
p_moderator_id UUID,
p_rejection_reason TEXT,
p_request_id TEXT DEFAULT NULL
)
RETURNS JSONB
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
v_start_time TIMESTAMPTZ;
v_result JSONB;
v_rejected_count INTEGER := 0;
v_final_status TEXT;
v_some_pending BOOLEAN := FALSE;
BEGIN
v_start_time := clock_timestamp();
RAISE NOTICE '[%] Starting atomic rejection transaction for submission %',
COALESCE(p_request_id, 'NO_REQUEST_ID'),
p_submission_id;
-- ========================================================================
-- STEP 1: Set session variables (transaction-scoped)
-- ========================================================================
PERFORM set_config('app.moderator_id', p_moderator_id::text, true);
-- ========================================================================
-- STEP 2: Validate submission ownership and lock status
-- ========================================================================
IF NOT EXISTS (
SELECT 1 FROM content_submissions
WHERE id = p_submission_id
AND (assigned_to = p_moderator_id OR assigned_to IS NULL)
AND status IN ('pending', 'partially_approved')
) THEN
RAISE EXCEPTION 'Submission not found, locked by another moderator, or already processed'
USING ERRCODE = '42501';
END IF;
-- ========================================================================
-- STEP 3: Update all items to rejected atomically
-- ========================================================================
UPDATE submission_items
SET
status = 'rejected',
rejection_reason = p_rejection_reason,
updated_at = NOW()
WHERE id = ANY(p_item_ids)
AND submission_id = p_submission_id
AND status IN ('pending', 'rejected');
GET DIAGNOSTICS v_rejected_count = ROW_COUNT;
RAISE NOTICE '[%] Rejected % items',
COALESCE(p_request_id, 'NO_REQUEST_ID'),
v_rejected_count;
-- ========================================================================
-- STEP 4: Determine final submission status
-- ========================================================================
-- Check if any items are still pending
SELECT EXISTS(
SELECT 1 FROM submission_items
WHERE submission_id = p_submission_id
AND status = 'pending'
) INTO v_some_pending;
-- Set final status
v_final_status := CASE
WHEN v_some_pending THEN 'partially_approved'
WHEN EXISTS(
SELECT 1 FROM submission_items
WHERE submission_id = p_submission_id
AND status = 'approved'
) THEN 'partially_approved'
ELSE 'rejected'
END;
-- ========================================================================
-- STEP 5: Update parent submission
-- ========================================================================
UPDATE content_submissions
SET
status = v_final_status,
reviewer_id = p_moderator_id,
reviewed_at = NOW(),
assigned_to = NULL,
locked_until = NULL,
reviewer_notes = p_rejection_reason
WHERE id = p_submission_id;
-- ========================================================================
-- STEP 6: Log to moderation_audit_log
-- ========================================================================
INSERT INTO moderation_audit_log (
submission_id,
moderator_id,
action,
details,
created_at
) VALUES (
p_submission_id,
p_moderator_id,
'rejection',
jsonb_build_object(
'item_ids', p_item_ids,
'rejection_reason', p_rejection_reason,
'rejected_count', v_rejected_count,
'final_status', v_final_status,
'request_id', p_request_id
),
NOW()
);
-- ========================================================================
-- STEP 7: Build result
-- ========================================================================
v_result := jsonb_build_object(
'success', TRUE,
'rejected_count', v_rejected_count,
'submission_status', v_final_status,
'duration_ms', EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000
);
-- Clear session variables
PERFORM set_config('app.moderator_id', '', true);
RAISE NOTICE '[%] Rejection transaction completed in %ms',
COALESCE(p_request_id, 'NO_REQUEST_ID'),
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000;
RETURN v_result;
END;
$$;
-- Grant execute permissions
GRANT EXECUTE ON FUNCTION process_rejection_transaction TO authenticated;
COMMENT ON FUNCTION process_rejection_transaction IS
'Atomic rejection transaction with audit logging and lock release';