Connect to Lovable Cloud

The Lovable Cloud tool was approved and used to apply a migration. This migration fixes a critical bug in the composite submission approval process by resolving temporary references to actual entity IDs, ensuring correct foreign key population and data integrity.
This commit is contained in:
gpt-engineer-app[bot]
2025-11-08 01:14:07 +00:00
parent 576899cf25
commit f294794763
2 changed files with 527 additions and 0 deletions

View File

@@ -6346,6 +6346,16 @@ export type Database = {
monitor_failed_submissions: { Args: never; Returns: undefined }
monitor_slow_approvals: { Args: never; Returns: undefined }
process_approval_transaction:
| {
Args: {
p_item_ids: string[]
p_moderator_id: string
p_request_id?: string
p_submission_id: string
p_submitter_id: string
}
Returns: Json
}
| {
Args: {
p_idempotency_key?: string
@@ -6381,6 +6391,10 @@ export type Database = {
Args: { p_credit_id: string; p_new_position: number }
Returns: undefined
}
resolve_temp_refs_for_item: {
Args: { p_item_id: string; p_submission_id: string }
Returns: Json
}
revoke_my_session: { Args: { session_id: string }; Returns: undefined }
revoke_session_with_mfa: {
Args: { target_session_id: string; target_user_id: string }

View File

@@ -0,0 +1,513 @@
-- ============================================================================
-- FIX: Temp Reference Resolution for Composite Submissions
-- ============================================================================
-- This migration adds temp reference resolution to the approval transaction
-- to fix the bug where composite submissions have NULL foreign keys.
--
-- The fix ensures that when approving composite submissions:
-- 1. Temp refs (e.g., _temp_operator_ref) are resolved to actual entity IDs
-- 2. Foreign keys are properly populated before entity creation
-- 3. Dependencies are validated (must be approved before dependents)
-- ============================================================================
-- ============================================================================
-- HELPER FUNCTION: Resolve temp refs for a submission item
-- ============================================================================
-- Returns JSONB mapping ref_type → approved_entity_id
-- Example: {'operator': 'uuid-123', 'manufacturer': 'uuid-456'}
-- ============================================================================
CREATE OR REPLACE FUNCTION resolve_temp_refs_for_item(
p_item_id UUID,
p_submission_id UUID
)
RETURNS JSONB
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
v_resolved_refs JSONB := '{}'::JSONB;
v_ref RECORD;
v_dependency_item RECORD;
BEGIN
-- Loop through all temp refs for this item
FOR v_ref IN
SELECT ref_type, ref_order_index
FROM submission_item_temp_refs
WHERE submission_item_id = p_item_id
LOOP
-- Find the submission_item with matching order_index
SELECT id, item_type, status, approved_entity_id
INTO v_dependency_item
FROM submission_items
WHERE submission_id = p_submission_id
AND order_index = v_ref.ref_order_index;
-- Validate dependency exists
IF NOT FOUND THEN
RAISE EXCEPTION 'Temp ref resolution failed: No submission_item found with order_index % for submission %',
v_ref.ref_order_index, p_submission_id
USING ERRCODE = '23503';
END IF;
-- Validate dependency is approved
IF v_dependency_item.status != 'approved' THEN
RAISE EXCEPTION 'Temp ref resolution failed: Dependency at order_index % (item_id=%) is not approved (status=%)',
v_ref.ref_order_index, v_dependency_item.id, v_dependency_item.status
USING ERRCODE = '23503';
END IF;
-- Validate approved_entity_id exists
IF v_dependency_item.approved_entity_id IS NULL THEN
RAISE EXCEPTION 'Temp ref resolution failed: Dependency at order_index % (item_id=%) has NULL approved_entity_id',
v_ref.ref_order_index, v_dependency_item.id
USING ERRCODE = '23503';
END IF;
-- Add to resolved refs map
v_resolved_refs := v_resolved_refs || jsonb_build_object(
v_ref.ref_type,
v_dependency_item.approved_entity_id
);
RAISE NOTICE 'Resolved temp ref: % → % (order_index=%)',
v_ref.ref_type,
v_dependency_item.approved_entity_id,
v_ref.ref_order_index;
END LOOP;
RETURN v_resolved_refs;
END;
$$;
-- ============================================================================
-- UPDATE: process_approval_transaction with temp ref resolution
-- ============================================================================
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
)
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,
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
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
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
);
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
);
ELSE
RAISE EXCEPTION 'Unsupported item_type: %', v_item.item_type;
END IF;
-- ======================================================================
-- NEW: 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 (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_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,
array_length(p_item_ids, 1),
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', TRUE,
'results', to_jsonb(v_approval_results),
'submissionStatus', v_final_status,
'itemsProcessed', v_items_processed,
'allApproved', v_all_approved,
'someApproved', v_some_approved
);
-- Clear session variables (defense-in-depth)
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
-- ANY unhandled error triggers automatic ROLLBACK
RAISE WARNING '[%] Transaction failed, rolling back: % (SQLSTATE: %)',
COALESCE(p_request_id, 'NO_REQUEST_ID'),
SQLERRM,
SQLSTATE;
-- Log failed transaction metrics
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
);
-- Clear session variables before re-raising
PERFORM set_config('app.current_user_id', '', true);
PERFORM set_config('app.submission_id', '', true);
PERFORM set_config('app.moderator_id', '', true);
-- Re-raise the exception to trigger ROLLBACK
RAISE;
END;
$$;
-- Grant execute permissions
GRANT EXECUTE ON FUNCTION resolve_temp_refs_for_item TO authenticated;