-- ============================================================================ -- PHASE 2: RESILIENCE IMPROVEMENTS - Foreign Key Validation -- ============================================================================ -- Update create_entity_from_submission to validate foreign keys BEFORE insert -- This provides user-friendly error messages instead of cryptic FK violations CREATE OR REPLACE 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_fk_name TEXT; BEGIN CASE p_entity_type WHEN 'park' THEN -- Validate location_id if provided 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; -- Validate operator_id if provided 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; -- Validate property_owner_id if provided 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 -- Validate park_id (REQUIRED) 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; -- Validate manufacturer_id if provided 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; -- Validate ride_model_id if provided 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 -- Companies don't have required foreign keys, but validate if provided -- (No FKs to validate for companies currently) 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 -- Validate manufacturer_id (REQUIRED) 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; 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 create_entity_from_submission TO authenticated; COMMENT ON FUNCTION create_entity_from_submission IS 'Creates entities with upfront foreign key validation for user-friendly error messages';