Files
thrilltrack-explorer/supabase/migrations/20251002120032_a30c373a-4813-4b73-b586-b9654fd068cd.sql
2025-10-02 12:02:36 +00:00

59 lines
2.4 KiB
SQL

-- ============================================
-- Phase 5: Advanced Search Performance Indexes
-- ============================================
-- Search indexes for technical specifications
CREATE INDEX IF NOT EXISTS idx_ride_tech_specs_search
ON ride_technical_specifications(ride_id, spec_name, spec_value);
CREATE INDEX IF NOT EXISTS idx_ride_tech_specs_category
ON ride_technical_specifications(category, spec_name);
-- GIN index for flexible text search on spec values
CREATE INDEX IF NOT EXISTS idx_ride_tech_specs_value_gin
ON ride_technical_specifications USING gin(to_tsvector('english', spec_value));
-- Search indexes for coaster statistics
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_value_range
ON ride_coaster_statistics(stat_name, stat_value);
-- Composite index for rides filtering
CREATE INDEX IF NOT EXISTS idx_rides_search_composite
ON rides(category, status, manufacturer_id, park_id);
CREATE INDEX IF NOT EXISTS idx_rides_speed_height
ON rides(max_speed_kmh, max_height_meters)
WHERE max_speed_kmh IS NOT NULL OR max_height_meters IS NOT NULL;
-- Ride model technical specifications indexes
CREATE INDEX IF NOT EXISTS idx_ride_model_tech_specs_search
ON ride_model_technical_specifications(ride_model_id, spec_name, spec_value);
-- Park search optimization
CREATE INDEX IF NOT EXISTS idx_parks_search_composite
ON parks(park_type, status, operator_id, property_owner_id);
CREATE INDEX IF NOT EXISTS idx_parks_location
ON parks(location_id) WHERE location_id IS NOT NULL;
-- Company search optimization
CREATE INDEX IF NOT EXISTS idx_companies_type_search
ON companies(company_type, name);
-- Text search indexes for fuzzy matching
CREATE INDEX IF NOT EXISTS idx_rides_name_gin
ON rides USING gin(to_tsvector('english', name));
CREATE INDEX IF NOT EXISTS idx_parks_name_gin
ON parks USING gin(to_tsvector('english', name));
CREATE INDEX IF NOT EXISTS idx_companies_name_gin
ON companies USING gin(to_tsvector('english', name));
COMMENT ON INDEX idx_ride_tech_specs_search IS 'Optimizes technical specification searches by ride and spec name';
COMMENT ON INDEX idx_ride_coaster_stats_search IS 'Optimizes coaster statistics searches';
COMMENT ON INDEX idx_rides_search_composite IS 'Composite index for common ride search filters';
COMMENT ON INDEX idx_rides_name_gin IS 'Full-text search index for ride names';