-- Phase 1: Fix existing photo_delete submissions with missing entity_name -- Create a function to backfill missing entity names for photo_delete submissions CREATE OR REPLACE FUNCTION backfill_photo_delete_entity_names() RETURNS void LANGUAGE plpgsql SECURITY DEFINER SET search_path TO 'public' AS $$ DECLARE item_record RECORD; entity_name_value TEXT; BEGIN -- Find all photo_delete submission_items missing entity_name FOR item_record IN SELECT id, item_data FROM submission_items WHERE item_type = 'photo_delete' AND item_data->>'entity_name' IS NULL AND item_data->>'entity_id' IS NOT NULL AND item_data->>'entity_type' IS NOT NULL LOOP -- Fetch entity name based on entity_type CASE item_record.item_data->>'entity_type' WHEN 'park' THEN SELECT name INTO entity_name_value FROM parks WHERE id = (item_record.item_data->>'entity_id')::uuid; WHEN 'ride' THEN SELECT name INTO entity_name_value FROM rides WHERE id = (item_record.item_data->>'entity_id')::uuid; WHEN 'ride_model' THEN SELECT name INTO entity_name_value FROM ride_models WHERE id = (item_record.item_data->>'entity_id')::uuid; WHEN 'manufacturer', 'operator', 'designer', 'property_owner' THEN SELECT name INTO entity_name_value FROM companies WHERE id = (item_record.item_data->>'entity_id')::uuid; ELSE entity_name_value := NULL; END CASE; -- Update the item_data if we found a name IF entity_name_value IS NOT NULL THEN UPDATE submission_items SET item_data = item_data || jsonb_build_object('entity_name', entity_name_value) WHERE id = item_record.id; RAISE NOTICE 'Updated submission_item % with entity_name: %', item_record.id, entity_name_value; END IF; END LOOP; END; $$; -- Run the backfill function SELECT backfill_photo_delete_entity_names(); -- Drop the function after use (optional, but keeps things clean) DROP FUNCTION IF EXISTS backfill_photo_delete_entity_names();