-- Migration: 093_fix_mv_state_metrics.sql -- Purpose: Fix mv_state_metrics to use brand_name_raw and show correct store counts -- Issues fixed: -- 1. unique_brands used brand_id (often NULL), now uses brand_name_raw -- 2. Added out_of_stock_products column -- 3. dispensary_count now correctly named -- Drop and recreate the materialized view with correct definition DROP MATERIALIZED VIEW IF EXISTS mv_state_metrics; CREATE MATERIALIZED VIEW mv_state_metrics AS SELECT d.state, s.name AS state_name, COUNT(DISTINCT d.id) AS dispensary_count, COUNT(DISTINCT CASE WHEN d.menu_type = 'dutchie' THEN d.id END) AS dutchie_stores, COUNT(DISTINCT CASE WHEN d.crawl_enabled = true THEN d.id END) AS active_stores, COUNT(sp.id) AS total_products, COUNT(CASE WHEN COALESCE(sp.is_in_stock, true) THEN sp.id END) AS in_stock_products, COUNT(CASE WHEN sp.is_in_stock = false THEN sp.id END) AS out_of_stock_products, COUNT(CASE WHEN sp.is_on_special THEN sp.id END) AS on_special_products, COUNT(DISTINCT sp.brand_name_raw) FILTER (WHERE sp.brand_name_raw IS NOT NULL AND sp.brand_name_raw != '') AS unique_brands, COUNT(DISTINCT sp.category_raw) FILTER (WHERE sp.category_raw IS NOT NULL) AS unique_categories, ROUND(AVG(sp.price_rec) FILTER (WHERE sp.price_rec > 0)::NUMERIC, 2) AS avg_price_rec, MIN(sp.price_rec) FILTER (WHERE sp.price_rec > 0) AS min_price_rec, MAX(sp.price_rec) FILTER (WHERE sp.price_rec > 0) AS max_price_rec, NOW() AS refreshed_at FROM dispensaries d LEFT JOIN states s ON d.state = s.code LEFT JOIN store_products sp ON d.id = sp.dispensary_id WHERE d.state IS NOT NULL GROUP BY d.state, s.name; -- Create unique index for CONCURRENTLY refresh support CREATE UNIQUE INDEX idx_mv_state_metrics_state ON mv_state_metrics(state); -- Update refresh function CREATE OR REPLACE FUNCTION refresh_state_metrics() RETURNS void AS $$ BEGIN REFRESH MATERIALIZED VIEW CONCURRENTLY mv_state_metrics; END; $$ LANGUAGE plpgsql;