Files
thrilltrack-explorer/supabase/migrations/20251002012418_6ec24f6e-7c27-49f8-b001-0900aab69a2b.sql
gpt-engineer-app[bot] 7df81a6ba0 Add advanced form editors
2025-10-02 01:26:03 +00:00

115 lines
4.2 KiB
SQL

-- Phase 3B: Performance Optimizations - Add Database Indexes
-- Full-Text Search Indexes (GIN indexes for fast text search)
CREATE INDEX IF NOT EXISTS idx_parks_search
ON parks USING gin(to_tsvector('english', name || ' ' || COALESCE(description, '')));
CREATE INDEX IF NOT EXISTS idx_rides_search
ON rides USING gin(to_tsvector('english', name || ' ' || COALESCE(description, '')));
CREATE INDEX IF NOT EXISTS idx_companies_search
ON companies USING gin(to_tsvector('english', name || ' ' || COALESCE(description, '')));
-- Technical Specifications Search Indexes
CREATE INDEX IF NOT EXISTS idx_ride_technical_specs_search
ON ride_technical_specifications (ride_id, spec_name, spec_value);
CREATE INDEX IF NOT EXISTS idx_ride_technical_specs_category
ON ride_technical_specifications (category) WHERE category IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_ride_coaster_stats_search
ON ride_coaster_statistics (ride_id, stat_name, stat_value);
CREATE INDEX IF NOT EXISTS idx_ride_coaster_stats_category
ON ride_coaster_statistics (category) WHERE category IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_ride_name_history_ride
ON ride_name_history (ride_id, date_changed DESC);
CREATE INDEX IF NOT EXISTS idx_ride_model_technical_specs_search
ON ride_model_technical_specifications (ride_model_id, spec_name, spec_value);
-- Filtering and Sorting Indexes
CREATE INDEX IF NOT EXISTS idx_parks_status
ON parks (status) WHERE status IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_parks_country
ON parks (location_id) WHERE location_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_parks_type
ON parks (park_type);
CREATE INDEX IF NOT EXISTS idx_rides_category_status
ON rides (category, status);
CREATE INDEX IF NOT EXISTS idx_rides_park
ON rides (park_id, status);
CREATE INDEX IF NOT EXISTS idx_rides_manufacturer
ON rides (manufacturer_id) WHERE manufacturer_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_rides_designer
ON rides (designer_id) WHERE designer_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_rides_model
ON rides (ride_model_id) WHERE ride_model_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_companies_type
ON companies (company_type);
-- Rating and Review Indexes
CREATE INDEX IF NOT EXISTS idx_parks_rating
ON parks (average_rating DESC) WHERE average_rating > 0;
CREATE INDEX IF NOT EXISTS idx_rides_rating
ON rides (average_rating DESC) WHERE average_rating > 0;
CREATE INDEX IF NOT EXISTS idx_companies_rating
ON companies (average_rating DESC) WHERE average_rating > 0;
-- Location-based Indexes
CREATE INDEX IF NOT EXISTS idx_locations_country_city
ON locations (country, city);
CREATE INDEX IF NOT EXISTS idx_locations_coordinates
ON locations (latitude, longitude) WHERE latitude IS NOT NULL AND longitude IS NOT NULL;
-- Performance Specs for Range Queries
CREATE INDEX IF NOT EXISTS idx_rides_speed
ON rides (max_speed_kmh) WHERE max_speed_kmh IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_rides_height
ON rides (max_height_meters) WHERE max_height_meters IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_rides_length
ON rides (length_meters) WHERE length_meters IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_rides_inversions
ON rides (inversions) WHERE inversions > 0;
-- Review Indexes
CREATE INDEX IF NOT EXISTS idx_reviews_park
ON reviews (park_id, moderation_status) WHERE park_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_reviews_ride
ON reviews (ride_id, moderation_status) WHERE ride_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_reviews_user
ON reviews (user_id, moderation_status);
-- Submission System Indexes
CREATE INDEX IF NOT EXISTS idx_submission_items_status
ON submission_items (status, created_at DESC);
CREATE INDEX IF NOT EXISTS idx_submission_items_type
ON submission_items (item_type, status);
CREATE INDEX IF NOT EXISTS idx_content_submissions_user_status
ON content_submissions (user_id, status, created_at DESC);
-- Composite indexes for common query patterns
CREATE INDEX IF NOT EXISTS idx_rides_park_category
ON rides (park_id, category, status);
CREATE INDEX IF NOT EXISTS idx_rides_manufacturer_category
ON rides (manufacturer_id, category) WHERE manufacturer_id IS NOT NULL;