From bbf6bec9db999852bff799e4ca6b5ea8c704215d Mon Sep 17 00:00:00 2001 From: "gpt-engineer-app[bot]" <159125892+gpt-engineer-app[bot]@users.noreply.github.com> Date: Sat, 20 Sep 2025 12:57:00 +0000 Subject: [PATCH] Refactor reviews system --- src/types/database.ts | 2 + ...1_e5f4e826-a2a8-46f9-9896-7f95c8f598d5.sql | 169 ++++++++++++++++++ 2 files changed, 171 insertions(+) create mode 100644 supabase/migrations/20250920125631_e5f4e826-a2a8-46f9-9896-7f95c8f598d5.sql diff --git a/src/types/database.ts b/src/types/database.ts index 92b1e681..d53e3c1d 100644 --- a/src/types/database.ts +++ b/src/types/database.ts @@ -21,6 +21,8 @@ export interface Company { founded_year?: number; headquarters_location?: string; logo_url?: string; + average_rating: number; + review_count: number; } export interface Park { diff --git a/supabase/migrations/20250920125631_e5f4e826-a2a8-46f9-9896-7f95c8f598d5.sql b/supabase/migrations/20250920125631_e5f4e826-a2a8-46f9-9896-7f95c8f598d5.sql new file mode 100644 index 00000000..4aa28dd3 --- /dev/null +++ b/supabase/migrations/20250920125631_e5f4e826-a2a8-46f9-9896-7f95c8f598d5.sql @@ -0,0 +1,169 @@ +-- Fix security warnings by setting proper search_path for all functions + +-- 1. Update park ratings function with proper search path +CREATE OR REPLACE FUNCTION public.update_park_ratings(target_park_id UUID) +RETURNS void AS $$ +DECLARE + avg_rating DECIMAL(3,2); + review_cnt INTEGER; +BEGIN + SELECT + COALESCE(AVG(rating), 0)::DECIMAL(3,2), + COUNT(*) + INTO avg_rating, review_cnt + FROM public.reviews + WHERE park_id = target_park_id AND moderation_status = 'approved'; + + UPDATE public.parks + SET + average_rating = avg_rating, + review_count = review_cnt, + updated_at = now() + WHERE id = target_park_id; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = 'public'; + +-- 2. Update ride ratings function with proper search path +CREATE OR REPLACE FUNCTION public.update_ride_ratings(target_ride_id UUID) +RETURNS void AS $$ +DECLARE + avg_rating DECIMAL(3,2); + review_cnt INTEGER; +BEGIN + SELECT + COALESCE(AVG(rating), 0)::DECIMAL(3,2), + COUNT(*) + INTO avg_rating, review_cnt + FROM public.reviews + WHERE ride_id = target_ride_id AND moderation_status = 'approved'; + + UPDATE public.rides + SET + average_rating = avg_rating, + review_count = review_cnt, + updated_at = now() + WHERE id = target_ride_id; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = 'public'; + +-- 3. Update company ratings function with proper search path +CREATE OR REPLACE FUNCTION public.update_company_ratings(target_company_id UUID) +RETURNS void AS $$ +DECLARE + avg_rating DECIMAL(3,2); + review_cnt INTEGER; +BEGIN + -- Calculate ratings from parks operated by this company + WITH park_reviews AS ( + SELECT r.rating + FROM public.reviews r + JOIN public.parks p ON r.park_id = p.id + WHERE (p.operator_id = target_company_id OR p.property_owner_id = target_company_id) + AND r.moderation_status = 'approved' + ), + -- Calculate ratings from rides manufactured/designed by this company + ride_reviews AS ( + SELECT r.rating + FROM public.reviews r + JOIN public.rides rd ON r.ride_id = rd.id + WHERE (rd.manufacturer_id = target_company_id OR rd.designer_id = target_company_id) + AND r.moderation_status = 'approved' + ), + -- Combine all reviews + all_reviews AS ( + SELECT rating FROM park_reviews + UNION ALL + SELECT rating FROM ride_reviews + ) + SELECT + COALESCE(AVG(rating), 0)::DECIMAL(3,2), + COUNT(*) + INTO avg_rating, review_cnt + FROM all_reviews; + + UPDATE public.companies + SET + average_rating = avg_rating, + review_count = review_cnt, + updated_at = now() + WHERE id = target_company_id; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = 'public'; + +-- 4. Update trigger function with proper search path +CREATE OR REPLACE FUNCTION public.update_all_ratings_for_review() +RETURNS trigger AS $$ +DECLARE + company_ids UUID[]; +BEGIN + -- Handle both INSERT/UPDATE and DELETE cases + IF TG_OP = 'DELETE' THEN + -- Update park rating if this was a park review + IF OLD.park_id IS NOT NULL THEN + PERFORM public.update_park_ratings(OLD.park_id); + + -- Update related company ratings + SELECT ARRAY[p.operator_id, p.property_owner_id] + INTO company_ids + FROM public.parks p + WHERE p.id = OLD.park_id; + END IF; + + -- Update ride rating if this was a ride review + IF OLD.ride_id IS NOT NULL THEN + PERFORM public.update_ride_ratings(OLD.ride_id); + + -- Update related company ratings + SELECT ARRAY[r.manufacturer_id, r.designer_id] + INTO company_ids + FROM public.rides r + WHERE r.id = OLD.ride_id; + END IF; + + -- Update company ratings for all related companies + IF company_ids IS NOT NULL THEN + FOR i IN 1..array_length(company_ids, 1) LOOP + IF company_ids[i] IS NOT NULL THEN + PERFORM public.update_company_ratings(company_ids[i]); + END IF; + END LOOP; + END IF; + + RETURN OLD; + ELSE + -- Handle INSERT/UPDATE + -- Update park rating if this is a park review + IF NEW.park_id IS NOT NULL THEN + PERFORM public.update_park_ratings(NEW.park_id); + + -- Update related company ratings + SELECT ARRAY[p.operator_id, p.property_owner_id] + INTO company_ids + FROM public.parks p + WHERE p.id = NEW.park_id; + END IF; + + -- Update ride rating if this is a ride review + IF NEW.ride_id IS NOT NULL THEN + PERFORM public.update_ride_ratings(NEW.ride_id); + + -- Update related company ratings + SELECT ARRAY[r.manufacturer_id, r.designer_id] + INTO company_ids + FROM public.rides r + WHERE r.id = NEW.ride_id; + END IF; + + -- Update company ratings for all related companies + IF company_ids IS NOT NULL THEN + FOR i IN 1..array_length(company_ids, 1) LOOP + IF company_ids[i] IS NOT NULL THEN + PERFORM public.update_company_ratings(company_ids[i]); + END IF; + END LOOP; + END IF; + + RETURN NEW; + END IF; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = 'public'; \ No newline at end of file