-- Comprehensive fix: Add SET search_path to all remaining SECURITY DEFINER functions -- This prevents search_path injection attacks -- ============================================================================ -- RATING SYSTEM FUNCTIONS (from migration 20250920125706) -- ============================================================================ -- 1. Fix update_park_ratings 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. Fix update_ride_ratings 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. Fix update_company_ratings 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. Fix update_all_ratings_for_review (trigger function) 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; -- Update company ratings for 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; 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; -- Update company ratings for 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; 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; -- Update company ratings for 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; 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; -- Update company ratings for 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; END IF; RETURN NEW; END IF; END; $$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = 'public'; -- ============================================================================ -- TICKET SYSTEM FUNCTIONS (from migration 20251028183015) -- ============================================================================ -- 5. Fix generate_ticket_number CREATE OR REPLACE FUNCTION public.generate_ticket_number() RETURNS TEXT AS $$ BEGIN RETURN 'TW-' || LPAD(nextval('contact_ticket_number_seq')::TEXT, 6, '0'); END; $$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = 'public'; -- 6. Fix set_ticket_number (trigger function) CREATE OR REPLACE FUNCTION public.set_ticket_number() RETURNS TRIGGER AS $$ BEGIN IF NEW.ticket_number IS NULL THEN NEW.ticket_number := generate_ticket_number(); END IF; RETURN NEW; END; $$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = 'public'; -- ============================================================================ -- MODERATION QUEUE FUNCTION (from migration 20251103162832) -- ============================================================================ -- 7. Fix get_submission_item_entity_data CREATE OR REPLACE FUNCTION public.get_submission_item_entity_data( p_item_type text, p_item_data_id uuid ) RETURNS jsonb AS $$ DECLARE v_result jsonb; BEGIN CASE p_item_type WHEN 'park' THEN SELECT to_jsonb(ps.*) INTO v_result FROM park_submissions ps WHERE ps.id = p_item_data_id; WHEN 'ride' THEN SELECT to_jsonb(rs.*) INTO v_result FROM ride_submissions rs WHERE rs.id = p_item_data_id; WHEN 'manufacturer', 'operator', 'designer', 'property_owner' THEN SELECT to_jsonb(cs.*) INTO v_result FROM company_submissions cs WHERE cs.id = p_item_data_id; WHEN 'ride_model' THEN SELECT to_jsonb(rms.*) INTO v_result FROM ride_model_submissions rms WHERE rms.id = p_item_data_id; WHEN 'photo' THEN SELECT to_jsonb(ps.*) INTO v_result FROM photo_submissions ps WHERE ps.id = p_item_data_id; ELSE v_result := NULL; END CASE; RETURN v_result; END; $$ LANGUAGE plpgsql STABLE SECURITY DEFINER SET search_path = 'public'; -- ============================================================================ -- VERIFICATION COMMENTS -- ============================================================================ COMMENT ON FUNCTION public.update_park_ratings IS 'Recalculates park ratings from approved reviews. Protected with SET search_path.'; COMMENT ON FUNCTION public.update_ride_ratings IS 'Recalculates ride ratings from approved reviews. Protected with SET search_path.'; COMMENT ON FUNCTION public.update_company_ratings IS 'Recalculates company ratings from associated parks/rides. Protected with SET search_path.'; COMMENT ON FUNCTION public.update_all_ratings_for_review IS 'Trigger to update all entity ratings when a review changes. Protected with SET search_path.'; COMMENT ON FUNCTION public.generate_ticket_number IS 'Generates unique ticket numbers for contact submissions. Protected with SET search_path.'; COMMENT ON FUNCTION public.set_ticket_number IS 'Trigger to auto-assign ticket numbers. Protected with SET search_path.'; COMMENT ON FUNCTION public.get_submission_item_entity_data IS 'Retrieves entity data for moderation queue items. Protected with SET search_path.';