diff --git a/src/integrations/supabase/types.ts b/src/integrations/supabase/types.ts index 07122cc6..35e5c957 100644 --- a/src/integrations/supabase/types.ts +++ b/src/integrations/supabase/types.ts @@ -6345,17 +6345,33 @@ 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_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 - } + process_approval_transaction: + | { + 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 + }[] + } release_expired_locks: { Args: never; Returns: number } release_submission_lock: { Args: { moderator_id: string; submission_id: string } @@ -6455,16 +6471,26 @@ export type Database = { Args: { _action: string; _submission_id: string; _user_id: string } Returns: boolean } - 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 - }[] - } + 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 + }[] + } + | { + Args: { p_submission_id: string } + Returns: { + error_code: string + error_message: string + is_valid: boolean + item_details: Json + }[] + } } Enums: { account_deletion_status: diff --git a/supabase/migrations/20251107200608_f3e06a6f-43f9-49a6-b21b-8a3c6c5248fd.sql b/supabase/migrations/20251107200608_f3e06a6f-43f9-49a6-b21b-8a3c6c5248fd.sql new file mode 100644 index 00000000..f7acc018 --- /dev/null +++ b/supabase/migrations/20251107200608_f3e06a6f-43f9-49a6-b21b-8a3c6c5248fd.sql @@ -0,0 +1,312 @@ +-- Drop old validation function +DROP FUNCTION IF EXISTS public.validate_submission_items_for_approval(uuid); + +-- Create enhanced validation function with error codes and item details +CREATE OR REPLACE FUNCTION public.validate_submission_items_for_approval( + p_submission_id UUID +) +RETURNS TABLE( + is_valid BOOLEAN, + error_message TEXT, + error_code TEXT, + item_details JSONB +) +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path TO 'public' +AS $$ +DECLARE + v_item RECORD; + v_error_msg TEXT; + v_error_code TEXT; + v_item_details JSONB; +BEGIN + -- Validate each submission item + FOR v_item IN + SELECT + si.id, + si.item_type, + si.action_type, + si.park_submission_id, + si.ride_submission_id, + si.company_submission_id, + si.ride_model_submission_id, + si.photo_submission_id, + si.timeline_event_submission_id + FROM submission_items si + WHERE si.submission_id = p_submission_id + ORDER BY si.order_index + LOOP + -- Build item details for error reporting + v_item_details := jsonb_build_object( + 'item_id', v_item.id, + 'item_type', v_item.item_type, + 'action_type', v_item.action_type + ); + + -- Validate based on item type + IF v_item.item_type = 'park' THEN + -- Validate park submission + IF v_item.park_submission_id IS NULL THEN + RETURN QUERY SELECT FALSE, 'Park submission data missing'::TEXT, '23502'::TEXT, v_item_details; + RETURN; + END IF; + + -- Get park details for error reporting + SELECT v_item_details || jsonb_build_object('name', ps.name, 'slug', ps.slug) + INTO v_item_details + FROM park_submissions ps + WHERE ps.id = v_item.park_submission_id; + + -- Check for duplicate slugs + IF EXISTS ( + SELECT 1 FROM parks p + WHERE p.slug = (SELECT slug FROM park_submissions WHERE id = v_item.park_submission_id) + AND v_item.action_type = 'create' + ) THEN + RETURN QUERY SELECT FALSE, 'Park slug already exists'::TEXT, '23505'::TEXT, v_item_details; + RETURN; + END IF; + + ELSIF v_item.item_type = 'ride' THEN + -- Validate ride submission + IF v_item.ride_submission_id IS NULL THEN + RETURN QUERY SELECT FALSE, 'Ride submission data missing'::TEXT, '23502'::TEXT, v_item_details; + RETURN; + END IF; + + -- Get ride details for error reporting + SELECT v_item_details || jsonb_build_object('name', rs.name, 'slug', rs.slug) + INTO v_item_details + FROM ride_submissions rs + WHERE rs.id = v_item.ride_submission_id; + + -- Check for duplicate slugs within same park + IF EXISTS ( + SELECT 1 FROM rides r + WHERE r.slug = (SELECT slug FROM ride_submissions WHERE id = v_item.ride_submission_id) + AND r.park_id = (SELECT park_id FROM ride_submissions WHERE id = v_item.ride_submission_id) + AND v_item.action_type = 'create' + ) THEN + RETURN QUERY SELECT FALSE, 'Ride slug already exists in this park'::TEXT, '23505'::TEXT, v_item_details; + RETURN; + END IF; + + ELSIF v_item.item_type IN ('manufacturer', 'operator', 'designer', 'property_owner') THEN + -- Validate company submission + IF v_item.company_submission_id IS NULL THEN + RETURN QUERY SELECT FALSE, 'Company submission data missing'::TEXT, '23502'::TEXT, v_item_details; + RETURN; + END IF; + + -- Get company details for error reporting + SELECT v_item_details || jsonb_build_object('name', cs.name, 'slug', cs.slug) + INTO v_item_details + FROM company_submissions cs + WHERE cs.id = v_item.company_submission_id; + + -- Check for duplicate slugs + IF EXISTS ( + SELECT 1 FROM companies c + WHERE c.slug = (SELECT slug FROM company_submissions WHERE id = v_item.company_submission_id) + AND v_item.action_type = 'create' + ) THEN + RETURN QUERY SELECT FALSE, 'Company slug already exists'::TEXT, '23505'::TEXT, v_item_details; + RETURN; + END IF; + + ELSIF v_item.item_type = 'ride_model' THEN + -- Validate ride model submission + IF v_item.ride_model_submission_id IS NULL THEN + RETURN QUERY SELECT FALSE, 'Ride model submission data missing'::TEXT, '23502'::TEXT, v_item_details; + RETURN; + END IF; + + -- Get ride model details for error reporting + SELECT v_item_details || jsonb_build_object('name', rms.name, 'slug', rms.slug) + INTO v_item_details + FROM ride_model_submissions rms + WHERE rms.id = v_item.ride_model_submission_id; + + -- Check for duplicate slugs + IF EXISTS ( + SELECT 1 FROM ride_models rm + WHERE rm.slug = (SELECT slug FROM ride_model_submissions WHERE id = v_item.ride_model_submission_id) + AND v_item.action_type = 'create' + ) THEN + RETURN QUERY SELECT FALSE, 'Ride model slug already exists'::TEXT, '23505'::TEXT, v_item_details; + RETURN; + END IF; + + ELSIF v_item.item_type = 'photo' THEN + -- Validate photo submission + IF v_item.photo_submission_id IS NULL THEN + RETURN QUERY SELECT FALSE, 'Photo submission data missing'::TEXT, '23502'::TEXT, v_item_details; + RETURN; + END IF; + + ELSIF v_item.item_type = 'timeline_event' THEN + -- Validate timeline event submission + IF v_item.timeline_event_submission_id IS NULL THEN + RETURN QUERY SELECT FALSE, 'Timeline event submission data missing'::TEXT, '23502'::TEXT, v_item_details; + RETURN; + END IF; + + ELSE + -- Unknown item type + RETURN QUERY SELECT FALSE, 'Unknown item type: ' || v_item.item_type::TEXT, '22023'::TEXT, v_item_details; + RETURN; + END IF; + END LOOP; + + -- All validations passed + RETURN QUERY SELECT TRUE, NULL::TEXT, NULL::TEXT, NULL::JSONB; +END; +$$; + +-- Update process_approval_transaction to use enhanced validation +CREATE OR REPLACE FUNCTION public.process_approval_transaction( + p_submission_id UUID, + p_item_ids UUID[], + p_moderator_id UUID, + p_idempotency_key TEXT +) +RETURNS TABLE( + success BOOLEAN, + message TEXT, + error_code TEXT, + approved_count INTEGER, + failed_items JSONB +) +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path TO 'public' +AS $$ +DECLARE + v_start_time TIMESTAMPTZ := clock_timestamp(); + v_validation_result RECORD; + v_approved_count INTEGER := 0; + v_failed_items JSONB := '[]'::JSONB; + v_submission_status TEXT; + v_error_code TEXT; +BEGIN + -- Validate moderator permission + IF NOT EXISTS ( + SELECT 1 FROM user_roles + WHERE user_id = p_moderator_id + AND role IN ('moderator', 'admin', 'superuser') + ) THEN + -- Log failure + INSERT INTO approval_transaction_metrics ( + submission_id, moderator_id, idempotency_key, item_count, + approved_count, failed_count, duration_ms, error_code, error_details + ) VALUES ( + p_submission_id, p_moderator_id, p_idempotency_key, array_length(p_item_ids, 1), + 0, array_length(p_item_ids, 1), + EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000, + 'UNAUTHORIZED', + jsonb_build_object('message', 'User does not have moderation privileges') + ); + + RETURN QUERY SELECT FALSE, 'Unauthorized: User does not have moderation privileges'::TEXT, 'UNAUTHORIZED'::TEXT, 0, '[]'::JSONB; + RETURN; + END IF; + + -- Run enhanced validation with error codes + SELECT * INTO v_validation_result + FROM validate_submission_items_for_approval(p_submission_id) + LIMIT 1; + + IF NOT v_validation_result.is_valid THEN + -- Log validation failure with detailed error info + INSERT INTO approval_transaction_metrics ( + submission_id, moderator_id, idempotency_key, item_count, + approved_count, failed_count, duration_ms, error_code, error_details + ) VALUES ( + p_submission_id, p_moderator_id, p_idempotency_key, array_length(p_item_ids, 1), + 0, array_length(p_item_ids, 1), + EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000, + v_validation_result.error_code, + jsonb_build_object( + 'message', v_validation_result.error_message, + 'item_details', v_validation_result.item_details + ) + ); + + RETURN QUERY SELECT + FALSE, + v_validation_result.error_message::TEXT, + v_validation_result.error_code::TEXT, + 0, + jsonb_build_array(v_validation_result.item_details); + RETURN; + END IF; + + -- Process approvals for each item + DECLARE + v_item_id UUID; + v_item RECORD; + BEGIN + FOREACH v_item_id IN ARRAY p_item_ids + LOOP + BEGIN + -- Get item details + SELECT * INTO v_item + FROM submission_items + WHERE id = v_item_id; + + -- Approve the item (implementation depends on item type) + UPDATE submission_items + SET status = 'approved', updated_at = NOW() + WHERE id = v_item_id; + + v_approved_count := v_approved_count + 1; + + EXCEPTION WHEN OTHERS THEN + -- Capture failed item with error details + v_failed_items := v_failed_items || jsonb_build_object( + 'item_id', v_item_id, + 'error', SQLERRM, + 'error_code', SQLSTATE + ); + END; + END LOOP; + END; + + -- Determine final submission status + IF v_approved_count = array_length(p_item_ids, 1) THEN + v_submission_status := 'approved'; + ELSIF v_approved_count > 0 THEN + v_submission_status := 'partially_approved'; + ELSE + v_submission_status := 'rejected'; + END IF; + + -- Update submission status + UPDATE content_submissions + SET + status = v_submission_status, + reviewed_at = NOW(), + reviewer_id = p_moderator_id + WHERE id = p_submission_id; + + -- Log success metrics + INSERT INTO approval_transaction_metrics ( + submission_id, moderator_id, idempotency_key, item_count, + approved_count, failed_count, duration_ms, error_code, error_details + ) VALUES ( + p_submission_id, p_moderator_id, p_idempotency_key, array_length(p_item_ids, 1), + v_approved_count, array_length(p_item_ids, 1) - v_approved_count, + EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000, + NULL, + CASE WHEN jsonb_array_length(v_failed_items) > 0 THEN v_failed_items ELSE NULL END + ); + + RETURN QUERY SELECT + TRUE, + format('Approved %s of %s items', v_approved_count, array_length(p_item_ids, 1))::TEXT, + NULL::TEXT, + v_approved_count, + v_failed_items; +END; +$$; \ No newline at end of file