diff --git a/src/integrations/supabase/types.ts b/src/integrations/supabase/types.ts index c43c0e94..07122cc6 100644 --- a/src/integrations/supabase/types.ts +++ b/src/integrations/supabase/types.ts @@ -6458,9 +6458,11 @@ export type Database = { validate_submission_items_for_approval: { Args: { p_item_ids: string[] } Returns: { + error_code: string error_message: string invalid_item_id: string is_valid: boolean + item_details: Json }[] } } diff --git a/supabase/migrations/20251107194039_a99752a6-4662-457a-b4ea-8f5c3d68c153.sql b/supabase/migrations/20251107194039_a99752a6-4662-457a-b4ea-8f5c3d68c153.sql new file mode 100644 index 00000000..5280cf96 --- /dev/null +++ b/supabase/migrations/20251107194039_a99752a6-4662-457a-b4ea-8f5c3d68c153.sql @@ -0,0 +1,249 @@ +-- ============================================================================ +-- Phase 4.3: Enhanced DB Validation with Specific Error Codes and Item Details +-- ============================================================================ +-- Drop existing function first since we're changing the return type +DROP FUNCTION IF EXISTS validate_submission_items_for_approval(UUID[]); + +-- Create enhanced validation function with specific error codes and item details +CREATE OR REPLACE FUNCTION validate_submission_items_for_approval( + p_item_ids UUID[] +) +RETURNS TABLE ( + is_valid BOOLEAN, + error_message TEXT, + error_code TEXT, -- ✅ NEW: Specific PostgreSQL error code + invalid_item_id UUID, + item_details JSONB -- ✅ NEW: Item context for debugging +) +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_item RECORD; + v_item_data JSONB; + v_name TEXT; + v_slug TEXT; + v_opening_date DATE; + v_closing_date DATE; + v_item_details JSONB; +BEGIN + -- Validate each item + FOR v_item IN + SELECT si.* + FROM submission_items si + WHERE si.id = ANY(p_item_ids) + ORDER BY si.order_index + LOOP + v_item_data := v_item.item_data; + v_name := v_item_data->>'name'; + v_slug := v_item_data->>'slug'; + + -- Build item details for debugging + v_item_details := jsonb_build_object( + 'item_type', v_item.item_type, + 'action_type', v_item.action_type, + 'name', v_name, + 'slug', v_slug, + 'submission_id', v_item.submission_id + ); + + -- Basic validation: Check for required fields based on item type + CASE v_item.item_type + WHEN 'park' THEN + -- Required fields validation + IF v_name IS NULL OR TRIM(v_name) = '' THEN + RETURN QUERY SELECT + false, + format('Park name is required for "%s"', COALESCE(v_slug, 'unknown')), + '23502', -- NOT NULL violation + v_item.id, + v_item_details; + RETURN; + END IF; + + IF v_slug IS NULL OR TRIM(v_slug) = '' THEN + RETURN QUERY SELECT + false, + format('Park slug is required for "%s"', COALESCE(v_name, 'unknown')), + '23502', -- NOT NULL violation + v_item.id, + v_item_details; + RETURN; + END IF; + + -- Date logic validation + v_opening_date := (v_item_data->>'opening_date')::DATE; + v_closing_date := (v_item_data->>'closing_date')::DATE; + + IF v_opening_date IS NOT NULL AND v_closing_date IS NOT NULL THEN + IF v_closing_date < v_opening_date THEN + RETURN QUERY SELECT + false, + format('Park "%s": Closing date (%s) cannot be before opening date (%s)', + v_name, v_closing_date::TEXT, v_opening_date::TEXT), + '23514', -- CHECK constraint violation + v_item.id, + v_item_details || jsonb_build_object( + 'opening_date', v_opening_date, + 'closing_date', v_closing_date + ); + RETURN; + END IF; + END IF; + + -- Duplicate slug check + IF EXISTS (SELECT 1 FROM parks WHERE slug = v_slug) THEN + RETURN QUERY SELECT + false, + format('Park slug "%s" already exists (name: "%s")', v_slug, v_name), + '23505', -- UNIQUE violation + v_item.id, + v_item_details || jsonb_build_object('existing_slug', v_slug); + RETURN; + END IF; + + WHEN 'ride' THEN + -- Required fields validation + IF v_name IS NULL OR TRIM(v_name) = '' THEN + RETURN QUERY SELECT + false, + format('Ride name is required for "%s"', COALESCE(v_slug, 'unknown')), + '23502', -- NOT NULL violation + v_item.id, + v_item_details; + RETURN; + END IF; + + IF v_slug IS NULL OR TRIM(v_slug) = '' THEN + RETURN QUERY SELECT + false, + format('Ride slug is required for "%s"', COALESCE(v_name, 'unknown')), + '23502', -- NOT NULL violation + v_item.id, + v_item_details; + RETURN; + END IF; + + -- Duplicate slug check + IF EXISTS (SELECT 1 FROM rides WHERE slug = v_slug) THEN + RETURN QUERY SELECT + false, + format('Ride slug "%s" already exists (name: "%s")', v_slug, v_name), + '23505', -- UNIQUE violation + v_item.id, + v_item_details || jsonb_build_object('existing_slug', v_slug); + RETURN; + END IF; + + WHEN 'manufacturer', 'operator', 'designer', 'property_owner' THEN + -- Required fields validation + IF v_name IS NULL OR TRIM(v_name) = '' THEN + RETURN QUERY SELECT + false, + format('%s name is required for "%s"', + INITCAP(v_item.item_type), + COALESCE(v_slug, 'unknown')), + '23502', -- NOT NULL violation + v_item.id, + v_item_details; + RETURN; + END IF; + + IF v_slug IS NULL OR TRIM(v_slug) = '' THEN + RETURN QUERY SELECT + false, + format('%s slug is required for "%s"', + INITCAP(v_item.item_type), + COALESCE(v_name, 'unknown')), + '23502', -- NOT NULL violation + v_item.id, + v_item_details; + RETURN; + END IF; + + -- Duplicate slug check + IF EXISTS (SELECT 1 FROM companies WHERE slug = v_slug) THEN + RETURN QUERY SELECT + false, + format('%s slug "%s" already exists (name: "%s")', + INITCAP(v_item.item_type), v_slug, v_name), + '23505', -- UNIQUE violation + v_item.id, + v_item_details || jsonb_build_object('existing_slug', v_slug); + RETURN; + END IF; + + WHEN 'photo' THEN + -- Photo validation + IF v_item_data->>'cloudflare_image_id' IS NULL THEN + RETURN QUERY SELECT + false, + 'Photo cloudflare_image_id is required', + '23502', -- NOT NULL violation + v_item.id, + v_item_details || jsonb_build_object( + 'cloudflare_image_url', v_item_data->>'cloudflare_image_url' + ); + RETURN; + END IF; + + IF v_item_data->>'cloudflare_image_url' IS NULL THEN + RETURN QUERY SELECT + false, + 'Photo cloudflare_image_url is required', + '23502', -- NOT NULL violation + v_item.id, + v_item_details || jsonb_build_object( + 'cloudflare_image_id', v_item_data->>'cloudflare_image_id' + ); + RETURN; + END IF; + + WHEN 'timeline_event' THEN + -- Timeline event validation + IF v_item_data->>'entity_type' IS NULL THEN + RETURN QUERY SELECT + false, + 'Timeline event entity_type is required', + '23502', -- NOT NULL violation + v_item.id, + v_item_details; + RETURN; + END IF; + + IF v_item_data->>'entity_id' IS NULL THEN + RETURN QUERY SELECT + false, + 'Timeline event entity_id is required', + '23502', -- NOT NULL violation + v_item.id, + v_item_details; + RETURN; + END IF; + + ELSE + RETURN QUERY SELECT + false, + format('Unknown item type: "%s"', v_item.item_type), + '22023', -- Invalid parameter value + v_item.id, + v_item_details; + RETURN; + END CASE; + END LOOP; + + -- All items valid + RETURN QUERY SELECT + true, + NULL::TEXT, + NULL::TEXT, + NULL::UUID, + NULL::JSONB; +END; +$$; + +COMMENT ON FUNCTION validate_submission_items_for_approval IS +'✅ Phase 4.3: Enhanced validation with specific error codes (23502=NOT NULL, 23505=UNIQUE, 23514=CHECK) and detailed item information for debugging'; + +GRANT EXECUTE ON FUNCTION validate_submission_items_for_approval TO authenticated; \ No newline at end of file