From 00de87924cbf1ef599177c8261a4acb03eac877e Mon Sep 17 00:00:00 2001 From: pacnpal <183241239+pacnpal@users.noreply.github.com> Date: Mon, 10 Nov 2025 10:08:07 -0500 Subject: [PATCH] Restore approval pipeline with tracing functionality This migration restores the complete approval pipeline functionality by recreating the 'process_approval_transaction' function, which handles the approval process for various entity types. It also includes tracing capabilities for monitoring the approval process. --- ...2_53f450d6-21c3-4b5d-b682-51a9373ff2a1.sql | 474 ++++++++++++++++++ 1 file changed, 474 insertions(+) create mode 100644 supabase/migrations/20251110140052_53f450d6-21c3-4b5d-b682-51a9373ff2a1.sql diff --git a/supabase/migrations/20251110140052_53f450d6-21c3-4b5d-b682-51a9373ff2a1.sql b/supabase/migrations/20251110140052_53f450d6-21c3-4b5d-b682-51a9373ff2a1.sql new file mode 100644 index 00000000..f1900b1d --- /dev/null +++ b/supabase/migrations/20251110140052_53f450d6-21c3-4b5d-b682-51a9373ff2a1.sql @@ -0,0 +1,474 @@ +-- ============================================================================ +-- CRITICAL FIX: Restore complete approval pipeline with tracing +-- ============================================================================ +-- This fixes the broken RPC that deleted all non-park entity handling +-- and restores full functionality for all entity types +-- ============================================================================ + +DROP FUNCTION IF EXISTS process_approval_transaction(UUID, UUID[], UUID, UUID, TEXT, TEXT, TEXT); + +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_start_time TIMESTAMPTZ; + v_result JSONB; + v_item RECORD; + v_item_data JSONB; + v_resolved_refs JSONB; + v_entity_id UUID; + v_approval_results JSONB[] := ARRAY[]::JSONB[]; + v_final_status TEXT; + v_all_approved BOOLEAN := TRUE; + v_some_approved BOOLEAN := FALSE; + v_items_processed INTEGER := 0; + v_span_id TEXT; +BEGIN + v_start_time := clock_timestamp(); + v_span_id := gen_random_uuid()::text; + + -- 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": %}}', + v_span_id, + p_trace_id, + p_parent_span_id, + EXTRACT(EPOCH FROM v_start_time) * 1000, + p_submission_id, + array_length(p_item_ids, 1); + END IF; + + RAISE NOTICE '[%] Starting atomic approval transaction for submission %', + COALESCE(p_request_id, 'NO_REQUEST_ID'), + p_submission_id; + + -- ======================================================================== + -- STEP 1: Set session variables (transaction-scoped with is_local=true) + -- ======================================================================== + PERFORM set_config('app.current_user_id', p_submitter_id::text, true); + PERFORM set_config('app.submission_id', p_submission_id::text, true); + 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: Process each item sequentially within this transaction + -- ======================================================================== + FOR v_item IN + SELECT + si.*, + ps.name as park_name, + ps.slug as park_slug, + ps.description as park_description, + ps.park_type, + ps.status as park_status, + ps.location_id, + ps.operator_id, + ps.property_owner_id, + ps.opening_date as park_opening_date, + ps.closing_date as park_closing_date, + ps.opening_date_precision as park_opening_date_precision, + ps.closing_date_precision as park_closing_date_precision, + ps.website_url as park_website_url, + ps.phone as park_phone, + ps.email as park_email, + ps.banner_image_url as park_banner_image_url, + ps.banner_image_id as park_banner_image_id, + ps.card_image_url as park_card_image_url, + ps.card_image_id as park_card_image_id, + rs.name as ride_name, + rs.slug as ride_slug, + rs.park_id as ride_park_id, + rs.ride_type, + rs.status as ride_status, + rs.manufacturer_id, + rs.ride_model_id, + rs.opening_date as ride_opening_date, + rs.closing_date as ride_closing_date, + rs.opening_date_precision as ride_opening_date_precision, + rs.closing_date_precision as ride_closing_date_precision, + rs.description as ride_description, + rs.banner_image_url as ride_banner_image_url, + rs.banner_image_id as ride_banner_image_id, + rs.card_image_url as ride_card_image_url, + rs.card_image_id as ride_card_image_id, + cs.name as company_name, + cs.slug as company_slug, + cs.description as company_description, + cs.website_url as company_website_url, + cs.founded_year, + cs.banner_image_url as company_banner_image_url, + cs.banner_image_id as company_banner_image_id, + cs.card_image_url as company_card_image_url, + cs.card_image_id as company_card_image_id, + rms.name as ride_model_name, + rms.slug as ride_model_slug, + rms.manufacturer_id as ride_model_manufacturer_id, + rms.ride_type as ride_model_ride_type, + rms.description as ride_model_description, + rms.banner_image_url as ride_model_banner_image_url, + rms.banner_image_id as ride_model_banner_image_id, + rms.card_image_url as ride_model_card_image_url, + rms.card_image_id as ride_model_card_image_id, + phs.entity_id as photo_entity_id, + phs.entity_type as photo_entity_type, + phs.title as photo_title + FROM submission_items si + LEFT JOIN park_submissions ps ON si.park_submission_id = ps.id + LEFT JOIN ride_submissions rs ON si.ride_submission_id = rs.id + LEFT JOIN company_submissions cs ON si.company_submission_id = cs.id + LEFT JOIN ride_model_submissions rms ON si.ride_model_submission_id = rms.id + LEFT JOIN photo_submissions phs ON si.photo_submission_id = phs.id + WHERE si.id = ANY(p_item_ids) + ORDER BY si.order_index, si.created_at + LOOP + BEGIN + v_items_processed := v_items_processed + 1; + + -- 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, + v_span_id, + EXTRACT(EPOCH FROM clock_timestamp()) * 1000, + v_item.id, + v_item.item_type, + v_item.action_type; + END IF; + + -- Build item data based on entity type + IF v_item.item_type = 'park' THEN + v_item_data := jsonb_build_object( + 'name', v_item.park_name, + 'slug', v_item.park_slug, + 'description', v_item.park_description, + 'park_type', v_item.park_type, + 'status', v_item.park_status, + 'location_id', v_item.location_id, + 'operator_id', v_item.operator_id, + 'property_owner_id', v_item.property_owner_id, + 'opening_date', v_item.park_opening_date, + 'closing_date', v_item.park_closing_date, + 'opening_date_precision', v_item.park_opening_date_precision, + 'closing_date_precision', v_item.park_closing_date_precision, + 'website_url', v_item.park_website_url, + 'phone', v_item.park_phone, + 'email', v_item.park_email, + 'banner_image_url', v_item.park_banner_image_url, + 'banner_image_id', v_item.park_banner_image_id, + 'card_image_url', v_item.park_card_image_url, + 'card_image_id', v_item.park_card_image_id + ); + ELSIF v_item.item_type = 'ride' THEN + v_item_data := jsonb_build_object( + 'name', v_item.ride_name, + 'slug', v_item.ride_slug, + 'park_id', v_item.ride_park_id, + 'ride_type', v_item.ride_type, + 'status', v_item.ride_status, + 'manufacturer_id', v_item.manufacturer_id, + 'ride_model_id', v_item.ride_model_id, + 'opening_date', v_item.ride_opening_date, + 'closing_date', v_item.ride_closing_date, + 'opening_date_precision', v_item.ride_opening_date_precision, + 'closing_date_precision', v_item.ride_closing_date_precision, + 'description', v_item.ride_description, + 'banner_image_url', v_item.ride_banner_image_url, + 'banner_image_id', v_item.ride_banner_image_id, + 'card_image_url', v_item.ride_card_image_url, + 'card_image_id', v_item.ride_card_image_id + ); + ELSIF v_item.item_type IN ('manufacturer', 'operator', 'property_owner', 'designer') THEN + v_item_data := jsonb_build_object( + 'name', v_item.company_name, + 'slug', v_item.company_slug, + 'description', v_item.company_description, + 'website_url', v_item.company_website_url, + 'founded_year', v_item.founded_year, + 'banner_image_url', v_item.company_banner_image_url, + 'banner_image_id', v_item.company_banner_image_id, + 'card_image_url', v_item.company_card_image_url, + 'card_image_id', v_item.company_card_image_id + ); + ELSIF v_item.item_type = 'ride_model' THEN + v_item_data := jsonb_build_object( + 'name', v_item.ride_model_name, + 'slug', v_item.ride_model_slug, + 'manufacturer_id', v_item.ride_model_manufacturer_id, + 'ride_type', v_item.ride_model_ride_type, + 'description', v_item.ride_model_description, + 'banner_image_url', v_item.ride_model_banner_image_url, + 'banner_image_id', v_item.ride_model_banner_image_id, + 'card_image_url', v_item.ride_model_card_image_url, + 'card_image_id', v_item.ride_model_card_image_id + ); + ELSIF v_item.item_type = 'photo' THEN + v_item_data := jsonb_build_object( + 'entity_id', v_item.photo_entity_id, + 'entity_type', v_item.photo_entity_type, + 'title', v_item.photo_title, + 'photo_submission_id', v_item.photo_submission_id + ); + ELSE + RAISE EXCEPTION 'Unsupported item_type: %', v_item.item_type; + END IF; + + -- ====================================================================== + -- Resolve temp refs and update v_item_data with actual entity IDs + -- ====================================================================== + v_resolved_refs := resolve_temp_refs_for_item(v_item.id, p_submission_id); + + IF v_resolved_refs IS NOT NULL AND jsonb_typeof(v_resolved_refs) = 'object' THEN + -- Replace NULL foreign keys with resolved entity IDs + -- For parks: operator_id, property_owner_id + IF v_item.item_type = 'park' THEN + IF v_resolved_refs ? 'operator' AND (v_item_data->>'operator_id') IS NULL THEN + v_item_data := v_item_data || jsonb_build_object('operator_id', v_resolved_refs->>'operator'); + RAISE NOTICE 'Resolved park.operator_id → %', v_resolved_refs->>'operator'; + END IF; + IF v_resolved_refs ? 'property_owner' AND (v_item_data->>'property_owner_id') IS NULL THEN + v_item_data := v_item_data || jsonb_build_object('property_owner_id', v_resolved_refs->>'property_owner'); + RAISE NOTICE 'Resolved park.property_owner_id → %', v_resolved_refs->>'property_owner'; + END IF; + END IF; + + -- For rides: park_id, manufacturer_id, ride_model_id + IF v_item.item_type = 'ride' THEN + IF v_resolved_refs ? 'park' AND (v_item_data->>'park_id') IS NULL THEN + v_item_data := v_item_data || jsonb_build_object('park_id', v_resolved_refs->>'park'); + RAISE NOTICE 'Resolved ride.park_id → %', v_resolved_refs->>'park'; + END IF; + IF v_resolved_refs ? 'manufacturer' AND (v_item_data->>'manufacturer_id') IS NULL THEN + v_item_data := v_item_data || jsonb_build_object('manufacturer_id', v_resolved_refs->>'manufacturer'); + RAISE NOTICE 'Resolved ride.manufacturer_id → %', v_resolved_refs->>'manufacturer'; + END IF; + IF v_resolved_refs ? 'ride_model' AND (v_item_data->>'ride_model_id') IS NULL THEN + v_item_data := v_item_data || jsonb_build_object('ride_model_id', v_resolved_refs->>'ride_model'); + RAISE NOTICE 'Resolved ride.ride_model_id → %', v_resolved_refs->>'ride_model'; + END IF; + END IF; + + -- For ride_models: manufacturer_id + IF v_item.item_type = 'ride_model' THEN + IF v_resolved_refs ? 'manufacturer' AND (v_item_data->>'manufacturer_id') IS NULL THEN + v_item_data := v_item_data || jsonb_build_object('manufacturer_id', v_resolved_refs->>'manufacturer'); + RAISE NOTICE 'Resolved ride_model.manufacturer_id → %', v_resolved_refs->>'manufacturer'; + END IF; + END IF; + END IF; + + -- Execute action based on action_type and item_type + IF v_item.action_type = 'create' THEN + IF v_item.item_type = 'photo' THEN + -- Insert all photo_submission_items as photos atomically + INSERT INTO photos ( + entity_id, entity_type, cloudflare_image_id, cloudflare_image_url, + title, caption, date_taken, date_taken_precision, order_index, + submission_id, submitted_by, approved_by, approved_at + ) + SELECT + (v_item_data->>'entity_id')::UUID, + v_item_data->>'entity_type', + psi.cloudflare_image_id, + psi.cloudflare_image_url, + psi.title, + psi.caption, + psi.date_taken, + psi.date_taken_precision, + psi.order_index, + p_submission_id, + p_submitter_id, + p_moderator_id, + NOW() + FROM photo_submission_items psi + WHERE psi.photo_submission_id = (v_item_data->>'photo_submission_id')::UUID; + + -- Return the photo_submission entity_id as v_entity_id + v_entity_id := (v_item_data->>'entity_id')::UUID; + + RAISE NOTICE '[%] Created % photos for entity % (type=%)', + COALESCE(p_request_id, 'NO_REQUEST_ID'), + (SELECT COUNT(*) FROM photo_submission_items WHERE photo_submission_id = (v_item_data->>'photo_submission_id')::UUID), + v_entity_id, + v_item_data->>'entity_type'; + ELSE + -- Standard entity creation - FIXED: Pass v_item_data instead of v_item.id + v_entity_id := create_entity_from_submission( + v_item.item_type, + v_item_data, + p_submitter_id + ); + END IF; + ELSIF v_item.action_type = 'update' THEN + v_entity_id := update_entity_from_submission( + v_item.item_type, + v_item_data, + v_item.target_entity_id, + p_submitter_id + ); + ELSIF v_item.action_type = 'delete' THEN + PERFORM delete_entity_from_submission( + v_item.item_type, + v_item.target_entity_id, + p_submitter_id + ); + v_entity_id := v_item.target_entity_id; + ELSE + RAISE EXCEPTION 'Unknown action_type: %', v_item.action_type; + END IF; + + -- Update submission_item to approved status + UPDATE submission_items + SET + status = 'approved', + approved_entity_id = v_entity_id, + updated_at = NOW() + WHERE id = v_item.id; + + -- Track success + v_approval_results := array_append( + v_approval_results, + jsonb_build_object( + 'itemId', v_item.id, + 'entityId', v_entity_id, + 'itemType', v_item.item_type, + 'actionType', v_item.action_type, + 'success', true + ) + ); + + v_some_approved := TRUE; + + RAISE NOTICE '[%] Approved item % (type=%s, action=%s, entityId=%s)', + COALESCE(p_request_id, 'NO_REQUEST_ID'), + v_item.id, + v_item.item_type, + v_item.action_type, + v_entity_id; + + EXCEPTION WHEN OTHERS THEN + -- Log error but continue processing remaining items + RAISE WARNING '[%] Item % failed: % (SQLSTATE: %)', + COALESCE(p_request_id, 'NO_REQUEST_ID'), + v_item.id, + SQLERRM, + SQLSTATE; + + -- Update submission_item to rejected status + UPDATE submission_items + SET + status = 'rejected', + rejection_reason = SQLERRM, + updated_at = NOW() + WHERE id = v_item.id; + + -- Track failure + v_approval_results := array_append( + v_approval_results, + jsonb_build_object( + 'itemId', v_item.id, + 'itemType', v_item.item_type, + 'actionType', v_item.action_type, + 'success', false, + 'error', SQLERRM + ) + ); + + v_all_approved := FALSE; + END; + END LOOP; + + -- ======================================================================== + -- STEP 4: Determine final submission status + -- ======================================================================== + v_final_status := CASE + WHEN v_all_approved THEN 'approved' + WHEN v_some_approved THEN 'partially_approved' + ELSE 'rejected' + END; + + -- ======================================================================== + -- STEP 5: Update submission status + -- ======================================================================== + UPDATE content_submissions + SET + status = v_final_status, + reviewer_id = p_moderator_id, + reviewed_at = NOW(), + assigned_to = NULL, + locked_until = NULL + WHERE id = p_submission_id; + + -- ======================================================================== + -- STEP 6: Log metrics + -- ======================================================================== + INSERT INTO approval_transaction_metrics ( + submission_id, + moderator_id, + submitter_id, + items_count, + duration_ms, + success, + request_id + ) VALUES ( + p_submission_id, + p_moderator_id, + p_submitter_id, + v_items_processed, + EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000, + v_all_approved, + p_request_id + ); + + -- ======================================================================== + -- STEP 7: Build result + -- ======================================================================== + v_result := jsonb_build_object( + 'success', v_all_approved, + 'submissionId', p_submission_id, + 'finalStatus', v_final_status, + 'itemsProcessed', v_items_processed, + 'results', v_approval_results, + 'durationMs', EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000 + ); + + -- Log span completion + IF p_trace_id IS NOT NULL THEN + RAISE NOTICE 'SPAN_EVENT: {"traceId": "%", "parentSpanId": "%", "name": "transaction_complete", "timestamp": %, "attributes": {"items_processed": %, "final_status": "%"}}', + p_trace_id, + v_span_id, + EXTRACT(EPOCH FROM clock_timestamp()) * 1000, + v_items_processed, + v_final_status; + END IF; + + RAISE NOTICE '[%] Transaction complete: % items processed, status=%s', + COALESCE(p_request_id, 'NO_REQUEST_ID'), + v_items_processed, + v_final_status; + + RETURN v_result; +END; +$$;