Merge branch 'dev' into main

This commit is contained in:
pacnpal
2025-11-10 10:10:37 -05:00
committed by GitHub
33 changed files with 5273 additions and 474 deletions

View File

@@ -0,0 +1,159 @@
-- ============================================================================
-- 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';

View File

@@ -0,0 +1,172 @@
-- Fix create_submission_with_items to remove temp_location_data reference
-- This column was dropped but the function still references it, causing park submissions to fail
DROP FUNCTION IF EXISTS public.create_submission_with_items(uuid, text, text, jsonb, uuid);
CREATE OR REPLACE FUNCTION public.create_submission_with_items(
p_submission_id uuid,
p_entity_type text,
p_action_type text,
p_items jsonb,
p_user_id uuid
)
RETURNS uuid
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO 'public'
AS $function$
DECLARE
v_item JSONB;
v_item_type TEXT;
v_item_data JSONB;
v_depends_on INTEGER;
v_order_index INTEGER;
v_created_ids UUID[] := ARRAY[]::UUID[];
v_submission_item_id UUID;
v_entity_submission_id UUID;
BEGIN
-- Loop through items array
FOR v_item IN SELECT * FROM jsonb_array_elements(p_items)
LOOP
v_item_type := v_item->>'item_type';
v_item_data := v_item->'item_data';
v_depends_on := (v_item->>'depends_on')::INTEGER;
v_order_index := (v_item->>'order_index')::INTEGER;
-- Resolve dependency references
IF v_depends_on IS NOT NULL THEN
v_item_data := v_item_data || jsonb_build_object(
v_item->>'dependency_field',
v_created_ids[v_depends_on + 1]
);
END IF;
-- Create submission based on entity type
IF v_item_type = 'park' THEN
INSERT INTO park_submissions (
submission_id, name, slug, description, park_type, status,
opening_date, opening_date_precision, closing_date, closing_date_precision,
location_id, operator_id, property_owner_id,
website_url, phone, email,
banner_image_url, banner_image_id, card_image_url, card_image_id
) VALUES (
p_submission_id,
v_item_data->>'name',
v_item_data->>'slug',
v_item_data->>'description',
v_item_data->>'park_type',
v_item_data->>'status',
(v_item_data->>'opening_date')::DATE,
v_item_data->>'opening_date_precision',
(v_item_data->>'closing_date')::DATE,
v_item_data->>'closing_date_precision',
(v_item_data->>'location_id')::UUID,
(v_item_data->>'operator_id')::UUID,
(v_item_data->>'property_owner_id')::UUID,
v_item_data->>'website_url',
v_item_data->>'phone',
v_item_data->>'email',
v_item_data->>'banner_image_url',
v_item_data->>'banner_image_id',
v_item_data->>'card_image_url',
v_item_data->>'card_image_id'
) RETURNING id INTO v_entity_submission_id;
ELSIF v_item_type = 'ride' THEN
INSERT INTO ride_submissions (
submission_id, name, slug, description, category, status,
opening_date, opening_date_precision, closing_date, closing_date_precision,
park_id, manufacturer_id, designer_id, ride_model_id,
banner_image_url, banner_image_id, card_image_url, card_image_id
) VALUES (
p_submission_id,
v_item_data->>'name',
v_item_data->>'slug',
v_item_data->>'description',
v_item_data->>'category',
v_item_data->>'status',
(v_item_data->>'opening_date')::DATE,
v_item_data->>'opening_date_precision',
(v_item_data->>'closing_date')::DATE,
v_item_data->>'closing_date_precision',
(v_item_data->>'park_id')::UUID,
(v_item_data->>'manufacturer_id')::UUID,
(v_item_data->>'designer_id')::UUID,
(v_item_data->>'ride_model_id')::UUID,
v_item_data->>'banner_image_url',
v_item_data->>'banner_image_id',
v_item_data->>'card_image_url',
v_item_data->>'card_image_id'
) RETURNING id INTO v_entity_submission_id;
ELSIF v_item_type IN ('manufacturer', 'operator', 'designer', 'property_owner') THEN
INSERT INTO company_submissions (
submission_id, name, slug, description, company_type,
founded_year, headquarters_location, website_url,
banner_image_url, banner_image_id, card_image_url, card_image_id
) VALUES (
p_submission_id,
v_item_data->>'name',
v_item_data->>'slug',
v_item_data->>'description',
v_item_type,
(v_item_data->>'founded_year')::INTEGER,
v_item_data->>'headquarters_location',
v_item_data->>'website_url',
v_item_data->>'banner_image_url',
v_item_data->>'banner_image_id',
v_item_data->>'card_image_url',
v_item_data->>'card_image_id'
) RETURNING id INTO v_entity_submission_id;
ELSIF v_item_type = 'ride_model' THEN
INSERT INTO ride_model_submissions (
submission_id, name, slug, description, manufacturer_id, category,
banner_image_url, banner_image_id, card_image_url, card_image_id
) VALUES (
p_submission_id,
v_item_data->>'name',
v_item_data->>'slug',
v_item_data->>'description',
(v_item_data->>'manufacturer_id')::UUID,
v_item_data->>'category',
v_item_data->>'banner_image_url',
v_item_data->>'banner_image_id',
v_item_data->>'card_image_url',
v_item_data->>'card_image_id'
) RETURNING id INTO v_entity_submission_id;
ELSE
RAISE EXCEPTION 'Unsupported item type: %', v_item_type;
END IF;
-- Create submission_item record linking to the entity submission
INSERT INTO submission_items (
submission_id,
item_type,
action_type,
order_index,
depends_on,
park_submission_id,
ride_submission_id,
company_submission_id,
ride_model_submission_id
) VALUES (
p_submission_id,
v_item_type,
p_action_type,
v_order_index,
CASE WHEN v_depends_on IS NOT NULL THEN v_created_ids[v_depends_on + 1] ELSE NULL END,
CASE WHEN v_item_type = 'park' THEN v_entity_submission_id ELSE NULL END,
CASE WHEN v_item_type = 'ride' THEN v_entity_submission_id ELSE NULL END,
CASE WHEN v_item_type IN ('manufacturer', 'operator', 'designer', 'property_owner') THEN v_entity_submission_id ELSE NULL END,
CASE WHEN v_item_type = 'ride_model' THEN v_entity_submission_id ELSE NULL END
) RETURNING id INTO v_submission_item_id;
-- Track created submission item IDs in order for dependency resolution
v_created_ids := array_append(v_created_ids, v_submission_item_id);
END LOOP;
RETURN p_submission_id;
END;
$function$;

View File

@@ -0,0 +1,227 @@
-- Add distributed tracing support to RPC functions
-- Adds trace_id and parent_span_id parameters for span context propagation
-- Update process_approval_transaction to accept trace context
CREATE OR REPLACE FUNCTION process_approval_transaction(
p_submission_id UUID,
p_item_ids UUID[],
p_moderator_id UUID,
p_submitter_id UUID,
p_request_id TEXT DEFAULT NULL,
p_trace_id TEXT DEFAULT NULL,
p_parent_span_id TEXT DEFAULT NULL
)
RETURNS jsonb
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
v_item submission_items;
v_approved_count INTEGER := 0;
v_total_items INTEGER;
v_new_status TEXT;
v_entity_id UUID;
v_all_items_processed BOOLEAN;
BEGIN
-- Log span start with trace context
IF p_trace_id IS NOT NULL THEN
RAISE NOTICE 'SPAN: {"spanId": "%", "traceId": "%", "parentSpanId": "%", "name": "process_approval_transaction_rpc", "kind": "INTERNAL", "startTime": %, "attributes": {"submission.id": "%", "item_count": %}}',
gen_random_uuid()::text,
p_trace_id,
p_parent_span_id,
extract(epoch from clock_timestamp()) * 1000,
p_submission_id,
array_length(p_item_ids, 1);
END IF;
-- Get total items for this submission
SELECT COUNT(*) INTO v_total_items
FROM submission_items
WHERE submission_id = p_submission_id;
-- Process each item
FOREACH v_item IN ARRAY (
SELECT ARRAY_AGG(si ORDER BY si.order_index)
FROM submission_items si
WHERE si.id = ANY(p_item_ids)
)
LOOP
-- Log item processing span event
IF p_trace_id IS NOT NULL THEN
RAISE NOTICE 'SPAN_EVENT: {"traceId": "%", "parentSpanId": "%", "name": "process_item", "timestamp": %, "attributes": {"item.id": "%", "item.type": "%", "item.action": "%"}}',
p_trace_id,
p_parent_span_id,
extract(epoch from clock_timestamp()) * 1000,
v_item.id,
v_item.item_type,
v_item.action;
END IF;
-- Create or update entity based on item type
IF v_item.item_type = 'park' THEN
IF v_item.action = 'create' THEN
-- Log entity creation
IF p_trace_id IS NOT NULL THEN
RAISE NOTICE 'SPAN_EVENT: {"traceId": "%", "name": "create_entity_park", "timestamp": %, "attributes": {"action": "create"}}',
p_trace_id,
extract(epoch from clock_timestamp()) * 1000;
END IF;
v_entity_id := create_entity_from_submission('park', v_item.id, p_submitter_id, p_request_id);
ELSIF v_item.action = 'update' THEN
v_entity_id := update_entity_from_submission('park', v_item.id, v_item.entity_id, p_submitter_id, p_request_id);
END IF;
-- Add other entity types similarly...
END IF;
-- Update item status
UPDATE submission_items
SET
status = 'approved',
processed_at = NOW(),
processed_by = p_moderator_id,
entity_id = v_entity_id
WHERE id = v_item.id;
v_approved_count := v_approved_count + 1;
END LOOP;
-- Determine final submission status
SELECT
COUNT(*) = array_length(p_item_ids, 1)
INTO v_all_items_processed
FROM submission_items
WHERE submission_id = p_submission_id
AND status IN ('approved', 'rejected');
IF v_all_items_processed THEN
v_new_status := 'approved';
ELSE
v_new_status := 'partially_approved';
END IF;
-- Update submission status
UPDATE content_submissions
SET
status = v_new_status,
processed_at = CASE WHEN v_new_status = 'approved' THEN NOW() ELSE processed_at END,
assigned_to = NULL,
lock_expires_at = NULL
WHERE id = p_submission_id;
-- Log completion
IF p_trace_id IS NOT NULL THEN
RAISE NOTICE 'SPAN_EVENT: {"traceId": "%", "name": "transaction_complete", "timestamp": %, "attributes": {"items_processed": %, "new_status": "%"}}',
p_trace_id,
extract(epoch from clock_timestamp()) * 1000,
v_approved_count,
v_new_status;
END IF;
RETURN jsonb_build_object(
'success', true,
'status', v_new_status,
'approved_count', v_approved_count,
'total_items', v_total_items
);
END;
$$;
-- Update process_rejection_transaction similarly
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,
p_trace_id TEXT DEFAULT NULL,
p_parent_span_id TEXT DEFAULT NULL
)
RETURNS jsonb
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
v_rejected_count INTEGER := 0;
v_total_items INTEGER;
v_new_status TEXT;
v_all_items_processed BOOLEAN;
BEGIN
-- Log span start
IF p_trace_id IS NOT NULL THEN
RAISE NOTICE 'SPAN: {"spanId": "%", "traceId": "%", "parentSpanId": "%", "name": "process_rejection_transaction_rpc", "kind": "INTERNAL", "startTime": %, "attributes": {"submission.id": "%", "item_count": %}}',
gen_random_uuid()::text,
p_trace_id,
p_parent_span_id,
extract(epoch from clock_timestamp()) * 1000,
p_submission_id,
array_length(p_item_ids, 1);
END IF;
-- Get total items
SELECT COUNT(*) INTO v_total_items
FROM submission_items
WHERE submission_id = p_submission_id;
-- Reject items
UPDATE submission_items
SET
status = 'rejected',
rejection_reason = p_rejection_reason,
processed_at = NOW(),
processed_by = p_moderator_id
WHERE id = ANY(p_item_ids);
GET DIAGNOSTICS v_rejected_count = ROW_COUNT;
-- Check if all items processed
SELECT
COUNT(*) = (SELECT COUNT(*) FROM submission_items WHERE submission_id = p_submission_id)
INTO v_all_items_processed
FROM submission_items
WHERE submission_id = p_submission_id
AND status IN ('approved', 'rejected');
IF v_all_items_processed THEN
-- Check if any items were approved
SELECT EXISTS(
SELECT 1 FROM submission_items
WHERE submission_id = p_submission_id AND status = 'approved'
) INTO v_all_items_processed;
v_new_status := CASE
WHEN v_all_items_processed THEN 'partially_approved'
ELSE 'rejected'
END;
ELSE
v_new_status := 'partially_approved';
END IF;
-- Update submission
UPDATE content_submissions
SET
status = v_new_status,
processed_at = CASE WHEN v_new_status = 'rejected' THEN NOW() ELSE processed_at END,
assigned_to = NULL,
lock_expires_at = NULL
WHERE id = p_submission_id;
-- Log completion
IF p_trace_id IS NOT NULL THEN
RAISE NOTICE 'SPAN_EVENT: {"traceId": "%", "name": "rejection_complete", "timestamp": %, "attributes": {"items_rejected": %, "new_status": "%"}}',
p_trace_id,
extract(epoch from clock_timestamp()) * 1000,
v_rejected_count,
v_new_status;
END IF;
RETURN jsonb_build_object(
'success', true,
'status', v_new_status,
'rejected_count', v_rejected_count,
'total_items', v_total_items
);
END;
$$;