diff --git a/src/integrations/supabase/types.ts b/src/integrations/supabase/types.ts index c7ececa0..2c60255b 100644 --- a/src/integrations/supabase/types.ts +++ b/src/integrations/supabase/types.ts @@ -6632,6 +6632,7 @@ export type Database = { Args: { target_user_id: string } Returns: undefined } + backfill_park_locations: { Args: never; Returns: Json } backfill_sort_orders: { Args: never; Returns: undefined } block_aal1_with_mfa: { Args: never; Returns: boolean } can_approve_submission_item: { diff --git a/supabase/migrations/20251111153852_5a97a905-0e6d-42a5-b2b4-d97e0cd73050.sql b/supabase/migrations/20251111153852_5a97a905-0e6d-42a5-b2b4-d97e0cd73050.sql new file mode 100644 index 00000000..95a7ee74 --- /dev/null +++ b/supabase/migrations/20251111153852_5a97a905-0e6d-42a5-b2b4-d97e0cd73050.sql @@ -0,0 +1,77 @@ +-- Function to backfill missing park locations from submission data +CREATE OR REPLACE FUNCTION backfill_park_locations() +RETURNS jsonb +LANGUAGE plpgsql +SECURITY DEFINER +AS $$ +DECLARE + v_parks_updated INTEGER := 0; + v_locations_created INTEGER := 0; + v_park RECORD; + v_submission RECORD; + v_location_id UUID; +BEGIN + -- Find parks without locations that have approved submissions with location data + FOR v_park IN + SELECT DISTINCT p.id, p.name, p.slug + FROM parks p + WHERE p.location_id IS NULL + LOOP + -- Find the most recent approved submission for this park with location data + SELECT + psl.country, + psl.state_province, + psl.city, + psl.street_address, + psl.postal_code, + psl.latitude, + psl.longitude + INTO v_submission + FROM park_submissions ps + JOIN park_submission_locations psl ON ps.id = psl.park_submission_id + WHERE ps.park_id = v_park.id + AND ps.status = 'approved' + AND psl.country IS NOT NULL + ORDER BY ps.created_at DESC + LIMIT 1; + + -- If we found location data, create a location record + IF FOUND THEN + INSERT INTO locations ( + country, + state_province, + city, + street_address, + postal_code, + latitude, + longitude + ) VALUES ( + v_submission.country, + v_submission.state_province, + v_submission.city, + v_submission.street_address, + v_submission.postal_code, + v_submission.latitude, + v_submission.longitude + ) + RETURNING id INTO v_location_id; + + -- Update the park with the new location + UPDATE parks + SET location_id = v_location_id + WHERE id = v_park.id; + + v_parks_updated := v_parks_updated + 1; + v_locations_created := v_locations_created + 1; + + RAISE NOTICE 'Backfilled location for park: % (id: %)', v_park.name, v_park.id; + END IF; + END LOOP; + + RETURN jsonb_build_object( + 'success', true, + 'parks_updated', v_parks_updated, + 'locations_created', v_locations_created + ); +END; +$$; \ No newline at end of file