-- Migration 052: Add provider_data JSONB and frequently-queried columns -- -- Adds hybrid storage for legacy data: -- 1. provider_data JSONB on both tables for all extra fields -- 2. Specific columns for frequently-queried fields -- ============================================================================ -- store_products: Add provider_data and queryable columns -- ============================================================================ -- JSONB for all extra provider-specific data ALTER TABLE store_products ADD COLUMN IF NOT EXISTS provider_data JSONB; -- Frequently-queried columns ALTER TABLE store_products ADD COLUMN IF NOT EXISTS strain_type TEXT; ALTER TABLE store_products ADD COLUMN IF NOT EXISTS medical_only BOOLEAN DEFAULT FALSE; ALTER TABLE store_products ADD COLUMN IF NOT EXISTS rec_only BOOLEAN DEFAULT FALSE; ALTER TABLE store_products ADD COLUMN IF NOT EXISTS brand_logo_url TEXT; ALTER TABLE store_products ADD COLUMN IF NOT EXISTS platform_dispensary_id TEXT; -- Index for strain_type queries CREATE INDEX IF NOT EXISTS idx_store_products_strain_type ON store_products(strain_type) WHERE strain_type IS NOT NULL; -- Index for medical/rec filtering CREATE INDEX IF NOT EXISTS idx_store_products_medical_rec ON store_products(medical_only, rec_only); -- GIN index for provider_data JSONB queries CREATE INDEX IF NOT EXISTS idx_store_products_provider_data ON store_products USING GIN (provider_data); -- ============================================================================ -- store_product_snapshots: Add provider_data and queryable columns -- ============================================================================ -- JSONB for all extra provider-specific data ALTER TABLE store_product_snapshots ADD COLUMN IF NOT EXISTS provider_data JSONB; -- Frequently-queried columns ALTER TABLE store_product_snapshots ADD COLUMN IF NOT EXISTS featured BOOLEAN DEFAULT FALSE; ALTER TABLE store_product_snapshots ADD COLUMN IF NOT EXISTS is_below_threshold BOOLEAN DEFAULT FALSE; ALTER TABLE store_product_snapshots ADD COLUMN IF NOT EXISTS is_below_kiosk_threshold BOOLEAN DEFAULT FALSE; -- Index for featured products CREATE INDEX IF NOT EXISTS idx_snapshots_featured ON store_product_snapshots(dispensary_id, featured) WHERE featured = TRUE; -- Index for low stock alerts CREATE INDEX IF NOT EXISTS idx_snapshots_below_threshold ON store_product_snapshots(dispensary_id, is_below_threshold) WHERE is_below_threshold = TRUE; -- GIN index for provider_data JSONB queries CREATE INDEX IF NOT EXISTS idx_snapshots_provider_data ON store_product_snapshots USING GIN (provider_data); -- ============================================================================ -- Comments for documentation -- ============================================================================ COMMENT ON COLUMN store_products.provider_data IS 'JSONB blob containing all provider-specific fields not in canonical columns (effects, terpenes, cannabinoids_v2, etc.)'; COMMENT ON COLUMN store_products.strain_type IS 'Cannabis strain type: Indica, Sativa, Hybrid, Indica-Hybrid, Sativa-Hybrid'; COMMENT ON COLUMN store_products.platform_dispensary_id IS 'Provider platform dispensary ID (e.g., Dutchie MongoDB ObjectId)'; COMMENT ON COLUMN store_product_snapshots.provider_data IS 'JSONB blob containing all provider-specific snapshot fields (options, kiosk data, etc.)'; COMMENT ON COLUMN store_product_snapshots.featured IS 'Whether product was featured/highlighted at capture time'; COMMENT ON COLUMN store_product_snapshots.is_below_threshold IS 'Whether product was below inventory threshold at capture time';