-- ============================================================================ -- Migration 053: Analytics Engine Indexes -- ============================================================================ -- -- Purpose: Add indexes optimized for analytics queries on canonical tables. -- These indexes support price trends, brand penetration, category -- growth, and state-level analytics. -- -- SAFETY RULES: -- - Uses CREATE INDEX IF NOT EXISTS (idempotent) -- - Uses ADD COLUMN IF NOT EXISTS for helper columns -- - NO DROP, DELETE, TRUNCATE, or destructive operations -- - Safe to run multiple times -- -- Run with: -- psql "$DATABASE_URL" -f migrations/053_analytics_indexes.sql -- -- ============================================================================ -- ============================================================================ -- SECTION 1: Helper columns for analytics (if missing) -- ============================================================================ -- Ensure store_products has brand_id for faster brand analytics joins -- (brand_name exists, but a normalized brand_id helps) ALTER TABLE store_products ADD COLUMN IF NOT EXISTS brand_id INTEGER; -- Ensure snapshots have category for time-series category analytics ALTER TABLE store_product_snapshots ADD COLUMN IF NOT EXISTS category VARCHAR(100); -- ============================================================================ -- SECTION 2: Price Analytics Indexes -- ============================================================================ -- Price trends by store_product over time CREATE INDEX IF NOT EXISTS idx_snapshots_product_price_time ON store_product_snapshots(store_product_id, captured_at DESC, price_rec, price_med) WHERE store_product_id IS NOT NULL; -- Price by category over time (for category price trends) CREATE INDEX IF NOT EXISTS idx_snapshots_category_price_time ON store_product_snapshots(category, captured_at DESC, price_rec) WHERE category IS NOT NULL; -- Price changes detection (for volatility analysis) CREATE INDEX IF NOT EXISTS idx_products_price_change ON store_products(last_price_change_at DESC) WHERE last_price_change_at IS NOT NULL; -- ============================================================================ -- SECTION 3: Brand Penetration Indexes -- ============================================================================ -- Brand by dispensary (for penetration counts) CREATE INDEX IF NOT EXISTS idx_products_brand_dispensary ON store_products(brand_name, dispensary_id) WHERE brand_name IS NOT NULL; -- Brand by state (for state-level brand analytics) CREATE INDEX IF NOT EXISTS idx_products_brand_state ON store_products(brand_name, state_id) WHERE brand_name IS NOT NULL AND state_id IS NOT NULL; -- Brand first/last seen (for penetration trends) CREATE INDEX IF NOT EXISTS idx_products_brand_first_seen ON store_products(brand_name, first_seen_at) WHERE brand_name IS NOT NULL; -- ============================================================================ -- SECTION 4: Category Analytics Indexes -- ============================================================================ -- Category by state (for state-level category analytics) CREATE INDEX IF NOT EXISTS idx_products_category_state ON store_products(category, state_id) WHERE category IS NOT NULL; -- Category by dispensary CREATE INDEX IF NOT EXISTS idx_products_category_dispensary ON store_products(category, dispensary_id) WHERE category IS NOT NULL; -- Category first seen (for growth tracking) CREATE INDEX IF NOT EXISTS idx_products_category_first_seen ON store_products(category, first_seen_at) WHERE category IS NOT NULL; -- ============================================================================ -- SECTION 5: Store Analytics Indexes -- ============================================================================ -- Products added/removed by dispensary CREATE INDEX IF NOT EXISTS idx_products_dispensary_first_seen ON store_products(dispensary_id, first_seen_at DESC); CREATE INDEX IF NOT EXISTS idx_products_dispensary_last_seen ON store_products(dispensary_id, last_seen_at DESC); -- Stock status changes CREATE INDEX IF NOT EXISTS idx_products_stock_change ON store_products(dispensary_id, last_stock_change_at DESC) WHERE last_stock_change_at IS NOT NULL; -- ============================================================================ -- SECTION 6: State Analytics Indexes -- ============================================================================ -- Dispensary count by state CREATE INDEX IF NOT EXISTS idx_dispensaries_state_active ON dispensaries(state_id) WHERE state_id IS NOT NULL; -- Products by state CREATE INDEX IF NOT EXISTS idx_products_state_active ON store_products(state_id, is_in_stock) WHERE state_id IS NOT NULL; -- Snapshots by state for time-series CREATE INDEX IF NOT EXISTS idx_snapshots_state_time ON store_product_snapshots(state_id, captured_at DESC) WHERE state_id IS NOT NULL; -- ============================================================================ -- SECTION 7: Composite indexes for common analytics queries -- ============================================================================ -- Brand + Category + State (for market share calculations) CREATE INDEX IF NOT EXISTS idx_products_brand_category_state ON store_products(brand_name, category, state_id) WHERE brand_name IS NOT NULL AND category IS NOT NULL; -- Dispensary + Category + Brand (for store-level brand analysis) CREATE INDEX IF NOT EXISTS idx_products_disp_cat_brand ON store_products(dispensary_id, category, brand_name) WHERE category IS NOT NULL; -- Special pricing by category (for promo analysis) CREATE INDEX IF NOT EXISTS idx_products_special_category ON store_products(category, is_on_special) WHERE is_on_special = TRUE; -- ============================================================================ -- SECTION 8: Verification -- ============================================================================ SELECT 'Migration 053 completed successfully.' AS status, (SELECT COUNT(*) FROM pg_indexes WHERE indexname LIKE 'idx_products_%') AS product_indexes, (SELECT COUNT(*) FROM pg_indexes WHERE indexname LIKE 'idx_snapshots_%') AS snapshot_indexes;