Fix timeline event approval and park location creation

The migration to fix timeline event approval and park location creation has been successfully applied. This includes adding the necessary JOINs and data building logic for timeline events in `process_approval_transaction`, and implementing logic in `create_entity_from_submission` to create new locations for parks when location data is provided but no `location_id` exists.
This commit is contained in:
gpt-engineer-app[bot]
2025-11-08 02:24:22 +00:00
parent f294794763
commit d6a3df4fd7
2 changed files with 749 additions and 37 deletions

View File

@@ -6345,43 +6345,16 @@ export type Database = {
monitor_ban_attempts: { Args: never; Returns: undefined }
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
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
p_item_ids: string[]
p_moderator_id: string
p_submission_id: string
}
Returns: {
approved_count: number
error_code: string
failed_items: Json
message: string
success: boolean
}[]
}
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
}
release_expired_locks: { Args: never; Returns: number }
release_submission_lock: {
Args: { moderator_id: string; submission_id: string }

View File

@@ -0,0 +1,739 @@
-- ============================================================================
-- FIX: Timeline Event Approval & Park Location Creation
-- ============================================================================
-- This migration fixes two critical pipeline bugs:
-- 1. Timeline events fail approval due to missing JOIN (all NULL data)
-- 2. Parks with new locations fail approval (location never created)
-- ============================================================================
-- Drop all versions of the functions using DO block
DO $$
DECLARE
func_rec RECORD;
BEGIN
-- Drop all versions of process_approval_transaction
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;
-- Drop all versions of create_entity_from_submission
FOR func_rec IN
SELECT oid::regprocedure::text as func_signature
FROM pg_proc
WHERE proname = 'create_entity_from_submission'
AND pg_function_is_visible(oid)
LOOP
EXECUTE format('DROP FUNCTION IF EXISTS %s CASCADE', func_rec.func_signature);
END LOOP;
END $$;
-- ============================================================================
-- FIX #1: Add Timeline Event Support to process_approval_transaction
-- ============================================================================
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.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,
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,
'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 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;
$$;
-- ============================================================================
-- FIX #2: Add Location Creation to create_entity_from_submission
-- ============================================================================
CREATE FUNCTION create_entity_from_submission(
p_entity_type TEXT,
p_data JSONB,
p_created_by UUID
)
RETURNS UUID
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
v_entity_id UUID;
v_fk_id UUID;
v_location_id UUID;
BEGIN
CASE p_entity_type
WHEN 'park' THEN
IF p_data->>'location_id' IS NULL AND p_data->>'location_name' IS NOT NULL THEN
INSERT INTO locations (
name, street_address, city, state_province, country,
postal_code, latitude, longitude, timezone, display_name
) VALUES (
p_data->>'location_name',
p_data->>'location_street_address',
p_data->>'location_city',
p_data->>'location_state_province',
p_data->>'location_country',
p_data->>'location_postal_code',
(p_data->>'location_latitude')::NUMERIC,
(p_data->>'location_longitude')::NUMERIC,
p_data->>'location_timezone',
p_data->>'location_display_name'
)
RETURNING id INTO v_location_id;
p_data := p_data || jsonb_build_object('location_id', v_location_id);
RAISE NOTICE 'Created new location % for park', v_location_id;
END IF;
IF p_data->>'location_id' IS NOT NULL THEN
v_fk_id := (p_data->>'location_id')::UUID;
IF NOT EXISTS (SELECT 1 FROM locations WHERE id = v_fk_id) THEN
RAISE EXCEPTION 'Invalid location_id: Location does not exist'
USING ERRCODE = '23503', HINT = 'location_id';
END IF;
END IF;
IF p_data->>'operator_id' IS NOT NULL THEN
v_fk_id := (p_data->>'operator_id')::UUID;
IF NOT EXISTS (SELECT 1 FROM companies WHERE id = v_fk_id AND company_type = 'operator') THEN
RAISE EXCEPTION 'Invalid operator_id: Company does not exist or is not an operator'
USING ERRCODE = '23503', HINT = 'operator_id';
END IF;
END IF;
IF p_data->>'property_owner_id' IS NOT NULL THEN
v_fk_id := (p_data->>'property_owner_id')::UUID;
IF NOT EXISTS (SELECT 1 FROM companies WHERE id = v_fk_id AND company_type = 'property_owner') THEN
RAISE EXCEPTION 'Invalid property_owner_id: Company does not exist or is not a property owner'
USING ERRCODE = '23503', HINT = 'property_owner_id';
END IF;
END IF;
INSERT INTO parks (
name, slug, description, park_type, status,
location_id, operator_id, property_owner_id,
opening_date, closing_date,
opening_date_precision, closing_date_precision,
website_url, phone, email,
banner_image_url, banner_image_id,
card_image_url, card_image_id
) VALUES (
p_data->>'name',
p_data->>'slug',
p_data->>'description',
p_data->>'park_type',
p_data->>'status',
(p_data->>'location_id')::UUID,
(p_data->>'operator_id')::UUID,
(p_data->>'property_owner_id')::UUID,
(p_data->>'opening_date')::DATE,
(p_data->>'closing_date')::DATE,
p_data->>'opening_date_precision',
p_data->>'closing_date_precision',
p_data->>'website_url',
p_data->>'phone',
p_data->>'email',
p_data->>'banner_image_url',
p_data->>'banner_image_id',
p_data->>'card_image_url',
p_data->>'card_image_id'
)
RETURNING id INTO v_entity_id;
WHEN 'ride' THEN
v_fk_id := (p_data->>'park_id')::UUID;
IF v_fk_id IS NULL THEN
RAISE EXCEPTION 'park_id is required for ride creation'
USING ERRCODE = '23502', HINT = 'park_id';
END IF;
IF NOT EXISTS (SELECT 1 FROM parks WHERE id = v_fk_id) THEN
RAISE EXCEPTION 'Invalid park_id: Park does not exist'
USING ERRCODE = '23503', HINT = 'park_id';
END IF;
IF p_data->>'manufacturer_id' IS NOT NULL THEN
v_fk_id := (p_data->>'manufacturer_id')::UUID;
IF NOT EXISTS (SELECT 1 FROM companies WHERE id = v_fk_id AND company_type = 'manufacturer') THEN
RAISE EXCEPTION 'Invalid manufacturer_id: Company does not exist or is not a manufacturer'
USING ERRCODE = '23503', HINT = 'manufacturer_id';
END IF;
END IF;
IF p_data->>'ride_model_id' IS NOT NULL THEN
v_fk_id := (p_data->>'ride_model_id')::UUID;
IF NOT EXISTS (SELECT 1 FROM ride_models WHERE id = v_fk_id) THEN
RAISE EXCEPTION 'Invalid ride_model_id: Ride model does not exist'
USING ERRCODE = '23503', HINT = 'ride_model_id';
END IF;
END IF;
INSERT INTO rides (
name, slug, park_id, ride_type, status,
manufacturer_id, ride_model_id,
opening_date, closing_date,
opening_date_precision, closing_date_precision,
description,
banner_image_url, banner_image_id,
card_image_url, card_image_id
) VALUES (
p_data->>'name',
p_data->>'slug',
(p_data->>'park_id')::UUID,
p_data->>'ride_type',
p_data->>'status',
(p_data->>'manufacturer_id')::UUID,
(p_data->>'ride_model_id')::UUID,
(p_data->>'opening_date')::DATE,
(p_data->>'closing_date')::DATE,
p_data->>'opening_date_precision',
p_data->>'closing_date_precision',
p_data->>'description',
p_data->>'banner_image_url',
p_data->>'banner_image_id',
p_data->>'card_image_url',
p_data->>'card_image_id'
)
RETURNING id INTO v_entity_id;
WHEN 'manufacturer', 'operator', 'property_owner', 'designer' THEN
INSERT INTO companies (
name, slug, company_type, description,
website_url, founded_year,
banner_image_url, banner_image_id,
card_image_url, card_image_id
) VALUES (
p_data->>'name',
p_data->>'slug',
p_entity_type,
p_data->>'description',
p_data->>'website_url',
(p_data->>'founded_year')::INTEGER,
p_data->>'banner_image_url',
p_data->>'banner_image_id',
p_data->>'card_image_url',
p_data->>'card_image_id'
)
RETURNING id INTO v_entity_id;
WHEN 'ride_model' THEN
v_fk_id := (p_data->>'manufacturer_id')::UUID;
IF v_fk_id IS NULL THEN
RAISE EXCEPTION 'manufacturer_id is required for ride model creation'
USING ERRCODE = '23502', HINT = 'manufacturer_id';
END IF;
IF NOT EXISTS (SELECT 1 FROM companies WHERE id = v_fk_id AND company_type = 'manufacturer') THEN
RAISE EXCEPTION 'Invalid manufacturer_id: Company does not exist or is not a manufacturer'
USING ERRCODE = '23503', HINT = 'manufacturer_id';
END IF;
INSERT INTO ride_models (
name, slug, manufacturer_id, ride_type,
description,
banner_image_url, banner_image_id,
card_image_url, card_image_id
) VALUES (
p_data->>'name',
p_data->>'slug',
(p_data->>'manufacturer_id')::UUID,
p_data->>'ride_type',
p_data->>'description',
p_data->>'banner_image_url',
p_data->>'banner_image_id',
p_data->>'card_image_url',
p_data->>'card_image_id'
)
RETURNING id INTO v_entity_id;
WHEN 'timeline_event', 'milestone' THEN
v_fk_id := (p_data->>'entity_id')::UUID;
IF v_fk_id IS NULL THEN
RAISE EXCEPTION 'entity_id is required for timeline event creation'
USING ERRCODE = '23502', HINT = 'entity_id';
END IF;
INSERT INTO entity_timeline_events (
entity_id, entity_type, event_type, event_date, event_date_precision,
title, description, from_value, to_value,
from_entity_id, to_entity_id, from_location_id, to_location_id,
created_by, approved_by
) VALUES (
(p_data->>'entity_id')::UUID,
p_data->>'entity_type',
p_data->>'event_type',
(p_data->>'event_date')::DATE,
p_data->>'event_date_precision',
p_data->>'title',
p_data->>'description',
p_data->>'from_value',
p_data->>'to_value',
(p_data->>'from_entity_id')::UUID,
(p_data->>'to_entity_id')::UUID,
(p_data->>'from_location_id')::UUID,
(p_data->>'to_location_id')::UUID,
p_created_by,
current_setting('app.moderator_id', true)::UUID
)
RETURNING id INTO v_entity_id;
ELSE
RAISE EXCEPTION 'Unsupported entity type for creation: %', p_entity_type
USING ERRCODE = '22023';
END CASE;
RETURN v_entity_id;
END;
$$;
-- Grant execute permissions
GRANT EXECUTE ON FUNCTION process_approval_transaction TO authenticated;
GRANT EXECUTE ON FUNCTION create_entity_from_submission TO authenticated;
COMMENT ON FUNCTION process_approval_transaction IS
'Atomic approval transaction with timeline event and location creation support';
COMMENT ON FUNCTION create_entity_from_submission IS
'Creates entities with automatic location creation and timeline event support';