Files
thrilltrack-explorer/supabase/migrations/20251002163959_f69b9728-a8da-476b-a2ed-aa809c67b3d4.sql
2025-10-02 16:40:37 +00:00

87 lines
2.6 KiB
PL/PgSQL

-- Function to update ride counts for a specific park
CREATE OR REPLACE FUNCTION public.update_park_ride_counts(target_park_id UUID)
RETURNS void AS $$
DECLARE
total_rides INTEGER;
total_coasters INTEGER;
BEGIN
-- Count all operating rides
SELECT COUNT(*) INTO total_rides
FROM public.rides
WHERE park_id = target_park_id
AND status = 'operating';
-- Count all operating roller coasters
SELECT COUNT(*) INTO total_coasters
FROM public.rides
WHERE park_id = target_park_id
AND status = 'operating'
AND category = 'roller_coaster';
-- Update park counts
UPDATE public.parks
SET
ride_count = total_rides,
coaster_count = total_coasters,
updated_at = now()
WHERE id = target_park_id;
RAISE NOTICE 'Updated park % - Rides: %, Coasters: %', target_park_id, total_rides, total_coasters;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;
-- Trigger function to update counts when rides change
CREATE OR REPLACE FUNCTION public.update_park_counts_for_ride()
RETURNS trigger AS $$
BEGIN
IF TG_OP = 'DELETE' THEN
-- Update the old park when ride is deleted
IF OLD.park_id IS NOT NULL THEN
PERFORM public.update_park_ride_counts(OLD.park_id);
END IF;
RETURN OLD;
ELSIF TG_OP = 'UPDATE' THEN
-- If ride moved to different park, update both parks
IF OLD.park_id IS DISTINCT FROM NEW.park_id THEN
IF OLD.park_id IS NOT NULL THEN
PERFORM public.update_park_ride_counts(OLD.park_id);
END IF;
IF NEW.park_id IS NOT NULL THEN
PERFORM public.update_park_ride_counts(NEW.park_id);
END IF;
ELSE
-- Same park, but status or category might have changed
IF NEW.park_id IS NOT NULL THEN
PERFORM public.update_park_ride_counts(NEW.park_id);
END IF;
END IF;
RETURN NEW;
ELSE -- INSERT
IF NEW.park_id IS NOT NULL THEN
PERFORM public.update_park_ride_counts(NEW.park_id);
END IF;
RETURN NEW;
END IF;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;
-- Create trigger
DROP TRIGGER IF EXISTS rides_count_update_trigger ON public.rides;
CREATE TRIGGER rides_count_update_trigger
AFTER INSERT OR UPDATE OR DELETE ON public.rides
FOR EACH ROW
EXECUTE FUNCTION public.update_park_counts_for_ride();
-- Recalculate all existing park counts
DO $$
DECLARE
park_record RECORD;
BEGIN
FOR park_record IN SELECT id FROM public.parks LOOP
PERFORM public.update_park_ride_counts(park_record.id);
END LOOP;
END $$;
-- Grant permissions
GRANT EXECUTE ON FUNCTION public.update_park_ride_counts(UUID) TO authenticated;
GRANT EXECUTE ON FUNCTION public.update_park_counts_for_ride() TO authenticated;