-- Create core tables for ThrillWiki platform -- Companies table (manufacturers, operators, designers, property owners) CREATE TABLE public.companies ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, name TEXT NOT NULL, slug TEXT NOT NULL UNIQUE, description TEXT, company_type TEXT NOT NULL CHECK (company_type IN ('manufacturer', 'operator', 'designer', 'property_owner')), website_url TEXT, founded_year INTEGER, headquarters_location TEXT, logo_url TEXT, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now() ); -- Locations table for geographic data CREATE TABLE public.locations ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, name TEXT NOT NULL, country TEXT NOT NULL, state_province TEXT, city TEXT, postal_code TEXT, latitude DECIMAL(10, 8), longitude DECIMAL(11, 8), timezone TEXT, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now() ); -- Parks table CREATE TABLE public.parks ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, name TEXT NOT NULL, slug TEXT NOT NULL UNIQUE, description TEXT, status TEXT NOT NULL DEFAULT 'operating' CHECK (status IN ('operating', 'closed', 'under_construction', 'seasonal')), park_type TEXT NOT NULL CHECK (park_type IN ('theme_park', 'amusement_park', 'water_park', 'family_entertainment')), opening_date DATE, closing_date DATE, website_url TEXT, phone TEXT, email TEXT, location_id UUID REFERENCES public.locations(id), operator_id UUID REFERENCES public.companies(id), property_owner_id UUID REFERENCES public.companies(id), banner_image_url TEXT, card_image_url TEXT, average_rating DECIMAL(3, 2) DEFAULT 0, review_count INTEGER DEFAULT 0, ride_count INTEGER DEFAULT 0, coaster_count INTEGER DEFAULT 0, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now() ); -- Operating hours for parks CREATE TABLE public.park_operating_hours ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, park_id UUID NOT NULL REFERENCES public.parks(id) ON DELETE CASCADE, day_of_week INTEGER NOT NULL CHECK (day_of_week >= 0 AND day_of_week <= 6), -- 0 = Sunday opening_time TIME, closing_time TIME, is_closed BOOLEAN DEFAULT false, season_start DATE, season_end DATE, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now() ); -- Ride models (templates created by manufacturers) CREATE TABLE public.ride_models ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, name TEXT NOT NULL, slug TEXT NOT NULL UNIQUE, manufacturer_id UUID NOT NULL REFERENCES public.companies(id), category TEXT NOT NULL CHECK (category IN ('roller_coaster', 'flat_ride', 'water_ride', 'dark_ride', 'kiddie_ride', 'transportation')), ride_type TEXT NOT NULL, description TEXT, technical_specs JSONB, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now() ); -- Rides table CREATE TABLE public.rides ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, name TEXT NOT NULL, slug TEXT NOT NULL, description TEXT, park_id UUID NOT NULL REFERENCES public.parks(id) ON DELETE CASCADE, ride_model_id UUID REFERENCES public.ride_models(id), manufacturer_id UUID REFERENCES public.companies(id), designer_id UUID REFERENCES public.companies(id), category TEXT NOT NULL CHECK (category IN ('roller_coaster', 'flat_ride', 'water_ride', 'dark_ride', 'kiddie_ride', 'transportation')), status TEXT NOT NULL DEFAULT 'operating' CHECK (status IN ('operating', 'closed', 'under_construction', 'maintenance', 'sbno')), opening_date DATE, closing_date DATE, height_requirement INTEGER, -- in centimeters age_requirement INTEGER, capacity_per_hour INTEGER, duration_seconds INTEGER, max_speed_kmh DECIMAL(5, 2), max_height_meters DECIMAL(6, 2), length_meters DECIMAL(8, 2), inversions INTEGER DEFAULT 0, coaster_stats JSONB, -- Additional roller coaster specific stats technical_specs JSONB, average_rating DECIMAL(3, 2) DEFAULT 0, review_count INTEGER DEFAULT 0, image_url TEXT, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), UNIQUE(park_id, slug) ); -- User profiles CREATE TABLE public.profiles ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, user_id UUID NOT NULL UNIQUE REFERENCES auth.users(id) ON DELETE CASCADE, username TEXT NOT NULL UNIQUE, display_name TEXT, bio TEXT, avatar_url TEXT, location_id UUID REFERENCES public.locations(id), date_of_birth DATE, privacy_level TEXT NOT NULL DEFAULT 'public' CHECK (privacy_level IN ('public', 'friends', 'private')), theme_preference TEXT NOT NULL DEFAULT 'system' CHECK (theme_preference IN ('light', 'dark', 'system')), ride_count INTEGER DEFAULT 0, coaster_count INTEGER DEFAULT 0, park_count INTEGER DEFAULT 0, review_count INTEGER DEFAULT 0, reputation_score INTEGER DEFAULT 0, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now() ); -- Reviews table CREATE TABLE public.reviews ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, park_id UUID REFERENCES public.parks(id) ON DELETE CASCADE, ride_id UUID REFERENCES public.rides(id) ON DELETE CASCADE, rating INTEGER NOT NULL CHECK (rating >= 1 AND rating <= 5), title TEXT, content TEXT, visit_date DATE, wait_time_minutes INTEGER, photos JSONB, -- Array of photo URLs and metadata helpful_votes INTEGER DEFAULT 0, total_votes INTEGER DEFAULT 0, moderation_status TEXT NOT NULL DEFAULT 'pending' CHECK (moderation_status IN ('pending', 'approved', 'rejected', 'flagged')), moderated_at TIMESTAMP WITH TIME ZONE, moderated_by UUID REFERENCES auth.users(id), created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), CHECK ((park_id IS NOT NULL AND ride_id IS NULL) OR (park_id IS NULL AND ride_id IS NOT NULL)) ); -- User ride credits (tracking which rides users have been on) CREATE TABLE public.user_ride_credits ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, ride_id UUID NOT NULL REFERENCES public.rides(id) ON DELETE CASCADE, first_ride_date DATE, ride_count INTEGER DEFAULT 1, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), UNIQUE(user_id, ride_id) ); -- User top lists CREATE TABLE public.user_top_lists ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, title TEXT NOT NULL, description TEXT, list_type TEXT NOT NULL CHECK (list_type IN ('parks', 'rides', 'coasters')), items JSONB NOT NULL, -- Array of {id, position, notes} is_public BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now() ); -- Content submissions for moderation CREATE TABLE public.content_submissions ( id UUID NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, submission_type TEXT NOT NULL CHECK (submission_type IN ('park', 'ride', 'review', 'photo')), content JSONB NOT NULL, status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'approved', 'rejected', 'needs_revision')), reviewer_id UUID REFERENCES auth.users(id), reviewer_notes TEXT, reviewed_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now() ); -- Enable Row Level Security on all tables ALTER TABLE public.companies ENABLE ROW LEVEL SECURITY; ALTER TABLE public.locations ENABLE ROW LEVEL SECURITY; ALTER TABLE public.parks ENABLE ROW LEVEL SECURITY; ALTER TABLE public.park_operating_hours ENABLE ROW LEVEL SECURITY; ALTER TABLE public.ride_models ENABLE ROW LEVEL SECURITY; ALTER TABLE public.rides ENABLE ROW LEVEL SECURITY; ALTER TABLE public.profiles ENABLE ROW LEVEL SECURITY; ALTER TABLE public.reviews ENABLE ROW LEVEL SECURITY; ALTER TABLE public.user_ride_credits ENABLE ROW LEVEL SECURITY; ALTER TABLE public.user_top_lists ENABLE ROW LEVEL SECURITY; ALTER TABLE public.content_submissions ENABLE ROW LEVEL SECURITY; -- RLS Policies for public read access to core content CREATE POLICY "Public read access to companies" ON public.companies FOR SELECT USING (true); CREATE POLICY "Public read access to locations" ON public.locations FOR SELECT USING (true); CREATE POLICY "Public read access to parks" ON public.parks FOR SELECT USING (true); CREATE POLICY "Public read access to operating hours" ON public.park_operating_hours FOR SELECT USING (true); CREATE POLICY "Public read access to ride models" ON public.ride_models FOR SELECT USING (true); CREATE POLICY "Public read access to rides" ON public.rides FOR SELECT USING (true); CREATE POLICY "Public read access to approved reviews" ON public.reviews FOR SELECT USING (moderation_status = 'approved'); -- Profiles policies CREATE POLICY "Public read access to public profiles" ON public.profiles FOR SELECT USING (privacy_level = 'public'); CREATE POLICY "Users can update their own profile" ON public.profiles FOR UPDATE USING (auth.uid() = user_id); CREATE POLICY "Users can insert their own profile" ON public.profiles FOR INSERT WITH CHECK (auth.uid() = user_id); -- User content policies CREATE POLICY "Users can view their own ride credits" ON public.user_ride_credits FOR SELECT USING (auth.uid() = user_id); CREATE POLICY "Users can manage their own ride credits" ON public.user_ride_credits FOR ALL USING (auth.uid() = user_id); CREATE POLICY "Users can view public top lists" ON public.user_top_lists FOR SELECT USING (is_public = true OR auth.uid() = user_id); CREATE POLICY "Users can manage their own top lists" ON public.user_top_lists FOR ALL USING (auth.uid() = user_id); CREATE POLICY "Users can view their own reviews" ON public.reviews FOR SELECT USING (auth.uid() = user_id); CREATE POLICY "Users can create reviews" ON public.reviews FOR INSERT WITH CHECK (auth.uid() = user_id); CREATE POLICY "Users can update their own reviews" ON public.reviews FOR UPDATE USING (auth.uid() = user_id); CREATE POLICY "Users can view their own submissions" ON public.content_submissions FOR SELECT USING (auth.uid() = user_id); CREATE POLICY "Users can create submissions" ON public.content_submissions FOR INSERT WITH CHECK (auth.uid() = user_id); -- Function to update timestamps CREATE OR REPLACE FUNCTION public.update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = now(); RETURN NEW; END; $$ LANGUAGE plpgsql SET search_path = public; -- Triggers for automatic timestamp updates CREATE TRIGGER update_companies_updated_at BEFORE UPDATE ON public.companies FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column(); CREATE TRIGGER update_parks_updated_at BEFORE UPDATE ON public.parks FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column(); CREATE TRIGGER update_ride_models_updated_at BEFORE UPDATE ON public.ride_models FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column(); CREATE TRIGGER update_rides_updated_at BEFORE UPDATE ON public.rides FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column(); CREATE TRIGGER update_profiles_updated_at BEFORE UPDATE ON public.profiles FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column(); CREATE TRIGGER update_reviews_updated_at BEFORE UPDATE ON public.reviews FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column(); CREATE TRIGGER update_user_ride_credits_updated_at BEFORE UPDATE ON public.user_ride_credits FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column(); CREATE TRIGGER update_user_top_lists_updated_at BEFORE UPDATE ON public.user_top_lists FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column(); CREATE TRIGGER update_content_submissions_updated_at BEFORE UPDATE ON public.content_submissions FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column(); -- Function to handle new user profile creation CREATE OR REPLACE FUNCTION public.handle_new_user() RETURNS TRIGGER AS $$ BEGIN INSERT INTO public.profiles (user_id, username, display_name) VALUES ( NEW.id, COALESCE(NEW.raw_user_meta_data ->> 'username', 'user_' || substring(NEW.id::text, 1, 8)), COALESCE(NEW.raw_user_meta_data ->> 'display_name', NEW.raw_user_meta_data ->> 'name') ); RETURN NEW; END; $$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public; -- Trigger for automatic profile creation CREATE TRIGGER on_auth_user_created AFTER INSERT ON auth.users FOR EACH ROW EXECUTE FUNCTION public.handle_new_user(); -- Indexes for better performance CREATE INDEX idx_parks_slug ON public.parks(slug); CREATE INDEX idx_parks_location ON public.parks(location_id); CREATE INDEX idx_parks_status ON public.parks(status); CREATE INDEX idx_parks_park_type ON public.parks(park_type); CREATE INDEX idx_rides_park ON public.rides(park_id); CREATE INDEX idx_rides_slug ON public.rides(park_id, slug); CREATE INDEX idx_rides_category ON public.rides(category); CREATE INDEX idx_rides_status ON public.rides(status); CREATE INDEX idx_reviews_park ON public.reviews(park_id) WHERE park_id IS NOT NULL; CREATE INDEX idx_reviews_ride ON public.reviews(ride_id) WHERE ride_id IS NOT NULL; CREATE INDEX idx_reviews_user ON public.reviews(user_id); CREATE INDEX idx_reviews_moderation_status ON public.reviews(moderation_status); CREATE INDEX idx_profiles_username ON public.profiles(username); CREATE INDEX idx_user_ride_credits_user ON public.user_ride_credits(user_id); CREATE INDEX idx_user_top_lists_user ON public.user_top_lists(user_id);