Merge pull request #8 from pacnpal/claude/pipeline-error-handling-011CUujxQjLLS8RcB1jtZoT5

Bulletproof pipeline error handling and validation
This commit is contained in:
pacnpal
2025-11-07 23:01:33 -05:00
committed by GitHub

View File

@@ -0,0 +1,485 @@
-- ============================================================================
-- CRITICAL FIX: Add missing `category` field to RPC SELECT query
-- ============================================================================
-- Bug: The process_approval_transaction function reads ride and ride_model
-- data but doesn't SELECT the category field, causing NULL to be passed
-- to create_entity_from_submission, which violates NOT NULL constraints.
--
-- This will cause ALL ride and ride_model approvals to fail with:
-- "ERROR: null value in column "category" violates not-null constraint"
-- ============================================================================
-- Drop and recreate with category fields in SELECT
DO $$
DECLARE
func_rec RECORD;
BEGIN
FOR func_rec IN
SELECT oid::regprocedure::text as func_signature
FROM pg_proc
WHERE proname = 'process_approval_transaction'
AND pg_function_is_visible(oid)
LOOP
EXECUTE format('DROP FUNCTION IF EXISTS %s CASCADE', func_rec.func_signature);
END LOOP;
END $$;
CREATE 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
)
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;
BEGIN
v_start_time := clock_timestamp();
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,
psl.name as location_name,
psl.street_address as location_street_address,
psl.city as location_city,
psl.state_province as location_state_province,
psl.country as location_country,
psl.postal_code as location_postal_code,
psl.latitude as location_latitude,
psl.longitude as location_longitude,
psl.timezone as location_timezone,
psl.display_name as location_display_name,
rs.name as ride_name,
rs.slug as ride_slug,
rs.park_id as ride_park_id,
rs.category as ride_category,
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.category as ride_model_category,
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,
tes.entity_type as timeline_entity_type,
tes.entity_id as timeline_entity_id,
tes.event_type as timeline_event_type,
tes.event_date as timeline_event_date,
tes.event_date_precision as timeline_event_date_precision,
tes.title as timeline_title,
tes.description as timeline_description,
tes.from_value as timeline_from_value,
tes.to_value as timeline_to_value,
tes.from_entity_id as timeline_from_entity_id,
tes.to_entity_id as timeline_to_entity_id,
tes.from_location_id as timeline_from_location_id,
tes.to_location_id as timeline_to_location_id
FROM submission_items si
LEFT JOIN park_submissions ps ON si.park_submission_id = ps.id
LEFT JOIN park_submission_locations psl ON ps.id = psl.park_submission_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 timeline_event_submissions tes ON si.timeline_event_submission_id = tes.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;
-- 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,
'location_name', v_item.location_name,
'location_street_address', v_item.location_street_address,
'location_city', v_item.location_city,
'location_state_province', v_item.location_state_province,
'location_country', v_item.location_country,
'location_postal_code', v_item.location_postal_code,
'location_latitude', v_item.location_latitude,
'location_longitude', v_item.location_longitude,
'location_timezone', v_item.location_timezone,
'location_display_name', v_item.location_display_name
);
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,
'category', v_item.ride_category,
'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,
'category', v_item.ride_model_category,
'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 IN ('timeline_event', 'milestone') THEN
v_item_data := jsonb_build_object(
'entity_type', v_item.timeline_entity_type,
'entity_id', v_item.timeline_entity_id,
'event_type', v_item.timeline_event_type,
'event_date', v_item.timeline_event_date,
'event_date_precision', v_item.timeline_event_date_precision,
'title', v_item.timeline_title,
'description', v_item.timeline_description,
'from_value', v_item.timeline_from_value,
'to_value', v_item.timeline_to_value,
'from_entity_id', v_item.timeline_from_entity_id,
'to_entity_id', v_item.timeline_to_entity_id,
'from_location_id', v_item.timeline_from_location_id,
'to_location_id', v_item.timeline_to_location_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
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;
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;
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 (now with resolved foreign keys)
IF v_item.action_type = 'create' THEN
v_entity_id := create_entity_from_submission(
v_item.item_type,
v_item_data,
p_submitter_id
);
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_items
SET
status = 'approved',
approved_entity_id = v_entity_id,
updated_at = NOW()
WHERE id = v_item.id;
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
RAISE WARNING '[%] Item % failed: % (SQLSTATE: %)',
COALESCE(p_request_id, 'NO_REQUEST_ID'),
v_item.id,
SQLERRM,
SQLSTATE;
UPDATE submission_items
SET
status = 'rejected',
rejection_reason = SQLERRM,
updated_at = NOW()
WHERE id = v_item.id;
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;
v_final_status := CASE
WHEN v_all_approved THEN 'approved'
WHEN v_some_approved THEN 'partially_approved'
ELSE 'rejected'
END;
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;
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,
array_length(p_item_ids, 1),
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000,
v_all_approved,
p_request_id
);
v_result := jsonb_build_object(
'success', TRUE,
'results', to_jsonb(v_approval_results),
'submissionStatus', v_final_status,
'itemsProcessed', v_items_processed,
'allApproved', v_all_approved,
'someApproved', v_some_approved
);
PERFORM set_config('app.current_user_id', '', true);
PERFORM set_config('app.submission_id', '', true);
PERFORM set_config('app.moderator_id', '', true);
RAISE NOTICE '[%] Transaction completed successfully in %ms',
COALESCE(p_request_id, 'NO_REQUEST_ID'),
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000;
RETURN v_result;
EXCEPTION WHEN OTHERS THEN
RAISE WARNING '[%] Transaction failed, rolling back: % (SQLSTATE: %)',
COALESCE(p_request_id, 'NO_REQUEST_ID'),
SQLERRM,
SQLSTATE;
INSERT INTO approval_transaction_metrics (
submission_id,
moderator_id,
submitter_id,
items_count,
duration_ms,
success,
rollback_triggered,
error_message,
request_id
) VALUES (
p_submission_id,
p_moderator_id,
p_submitter_id,
array_length(p_item_ids, 1),
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000,
FALSE,
TRUE,
SQLERRM,
p_request_id
);
PERFORM set_config('app.current_user_id', '', true);
PERFORM set_config('app.submission_id', '', true);
PERFORM set_config('app.moderator_id', '', true);
RAISE;
END;
$$;
GRANT EXECUTE ON FUNCTION process_approval_transaction TO authenticated;
COMMENT ON FUNCTION process_approval_transaction IS
'Fixed: Now correctly reads and passes category field for rides and ride_models';