/** * Intelligence API Routes * * Brand and pricing intelligence endpoints for the CannaiQ admin dashboard. * Uses canonical store_products table for aggregated analytics. */ import { Router, Request, Response } from 'express'; import { authMiddleware } from '../auth/middleware'; import { pool } from '../db/pool'; const router = Router(); router.use(authMiddleware); /** * GET /api/admin/intelligence/brands * List all brands with state presence, store counts, and pricing */ router.get('/brands', async (req: Request, res: Response) => { try { const { limit = '500', offset = '0' } = req.query; const limitNum = Math.min(parseInt(limit as string, 10), 1000); const offsetNum = parseInt(offset as string, 10); const { rows } = await pool.query(` SELECT sp.brand_name_raw as brand_name, array_agg(DISTINCT d.state) FILTER (WHERE d.state IS NOT NULL) as states, COUNT(DISTINCT d.id) as store_count, COUNT(DISTINCT sp.id) as sku_count, ROUND(AVG(sp.price_rec) FILTER (WHERE sp.price_rec > 0)::numeric, 2) as avg_price_rec, ROUND(AVG(sp.price_med) FILTER (WHERE sp.price_med > 0)::numeric, 2) as avg_price_med FROM store_products sp JOIN dispensaries d ON sp.dispensary_id = d.id WHERE sp.brand_name_raw IS NOT NULL AND sp.brand_name_raw != '' GROUP BY sp.brand_name_raw ORDER BY store_count DESC, sku_count DESC LIMIT $1 OFFSET $2 `, [limitNum, offsetNum]); // Get total count const { rows: countRows } = await pool.query(` SELECT COUNT(DISTINCT brand_name_raw) as total FROM store_products WHERE brand_name_raw IS NOT NULL AND brand_name_raw != '' `); res.json({ brands: rows.map((r: any) => ({ brandName: r.brand_name, states: r.states || [], storeCount: parseInt(r.store_count, 10), skuCount: parseInt(r.sku_count, 10), avgPriceRec: r.avg_price_rec ? parseFloat(r.avg_price_rec) : null, avgPriceMed: r.avg_price_med ? parseFloat(r.avg_price_med) : null, })), total: parseInt(countRows[0]?.total || '0', 10), limit: limitNum, offset: offsetNum, }); } catch (error: any) { console.error('[Intelligence] Error fetching brands:', error.message); res.status(500).json({ error: error.message }); } }); /** * GET /api/admin/intelligence/brands/:brandName/penetration * Get state-by-state penetration for a specific brand */ router.get('/brands/:brandName/penetration', async (req: Request, res: Response) => { try { const { brandName } = req.params; const { rows } = await pool.query(` WITH state_totals AS ( SELECT d.state, s.name AS state_name, COUNT(DISTINCT d.id) AS total_stores FROM dispensaries d JOIN states s ON d.state = s.code WHERE d.state IS NOT NULL GROUP BY d.state, s.name ), brand_presence AS ( SELECT d.state, COUNT(DISTINCT d.id) AS stores_with_brand, COUNT(DISTINCT sp.id) AS product_count, ROUND(AVG(sp.price_rec)::numeric, 2) AS avg_price FROM store_products sp JOIN dispensaries d ON sp.dispensary_id = d.id WHERE sp.brand_name_raw ILIKE $1 AND d.state IS NOT NULL GROUP BY d.state ) SELECT st.state, st.state_name AS "stateName", st.total_stores AS "totalStores", COALESCE(bp.stores_with_brand, 0) AS "storesWithBrand", CASE WHEN st.total_stores > 0 THEN ROUND((COALESCE(bp.stores_with_brand, 0)::numeric / st.total_stores) * 100, 2) ELSE 0 END AS "penetrationPct", COALESCE(bp.product_count, 0) AS "productCount", bp.avg_price AS "avgPrice" FROM state_totals st LEFT JOIN brand_presence bp ON st.state = bp.state WHERE COALESCE(bp.stores_with_brand, 0) > 0 ORDER BY COALESCE(bp.stores_with_brand, 0) DESC `, [brandName]); // Calculate national metrics const { rows: nationalRows } = await pool.query(` SELECT COUNT(DISTINCT d.id) AS total_stores, COUNT(DISTINCT CASE WHEN sp.brand_name_raw ILIKE $1 THEN d.id END) AS stores_with_brand, AVG(sp.price_rec) FILTER (WHERE sp.brand_name_raw ILIKE $1) AS avg_price FROM dispensaries d LEFT JOIN store_products sp ON d.id = sp.dispensary_id WHERE d.state IS NOT NULL `, [brandName]); const national = nationalRows[0]; const nationalPenetration = national.total_stores > 0 ? (national.stores_with_brand / national.total_stores) * 100 : 0; res.json({ brandName, states: rows, nationalPenetration: Math.round(nationalPenetration * 100) / 100, nationalAvgPrice: national.avg_price ? Math.round(parseFloat(national.avg_price) * 100) / 100 : null, bestPerformingState: rows[0]?.state || null, worstPerformingState: rows[rows.length - 1]?.state || null, }); } catch (error: any) { console.error('[Intelligence] Error fetching brand penetration:', error.message); res.status(500).json({ error: error.message }); } }); /** * GET /api/admin/intelligence/pricing * Get pricing analytics by category */ router.get('/pricing', async (req: Request, res: Response) => { try { const { rows: categoryRows } = await pool.query(` SELECT sp.category_raw as category, ROUND(AVG(sp.price_rec)::numeric, 2) as avg_price, MIN(sp.price_rec) as min_price, MAX(sp.price_rec) as max_price, ROUND(PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY sp.price_rec)::numeric, 2) as median_price, COUNT(*) as product_count FROM store_products sp WHERE sp.category_raw IS NOT NULL AND sp.price_rec > 0 GROUP BY sp.category_raw ORDER BY product_count DESC `); const { rows: stateRows } = await pool.query(` SELECT d.state, ROUND(AVG(sp.price_rec)::numeric, 2) as avg_price, MIN(sp.price_rec) as min_price, MAX(sp.price_rec) as max_price, COUNT(DISTINCT sp.id) as product_count FROM store_products sp JOIN dispensaries d ON sp.dispensary_id = d.id WHERE d.state IS NOT NULL AND sp.price_rec > 0 GROUP BY d.state ORDER BY avg_price DESC `); res.json({ byCategory: categoryRows.map((r: any) => ({ category: r.category, avgPrice: r.avg_price ? parseFloat(r.avg_price) : null, minPrice: r.min_price ? parseFloat(r.min_price) : null, maxPrice: r.max_price ? parseFloat(r.max_price) : null, medianPrice: r.median_price ? parseFloat(r.median_price) : null, productCount: parseInt(r.product_count, 10), })), byState: stateRows.map((r: any) => ({ state: r.state, avgPrice: r.avg_price ? parseFloat(r.avg_price) : null, minPrice: r.min_price ? parseFloat(r.min_price) : null, maxPrice: r.max_price ? parseFloat(r.max_price) : null, productCount: parseInt(r.product_count, 10), })), }); } catch (error: any) { console.error('[Intelligence] Error fetching pricing:', error.message); res.status(500).json({ error: error.message }); } }); /** * GET /api/admin/intelligence/stores * Get store intelligence summary */ router.get('/stores', async (req: Request, res: Response) => { try { const { rows: storeRows } = await pool.query(` SELECT d.id, d.name, d.dba_name, d.city, d.state, d.menu_type, d.crawl_enabled, COUNT(DISTINCT sp.id) as product_count, COUNT(DISTINCT sp.brand_name_raw) as brand_count, ROUND(AVG(sp.price_rec)::numeric, 2) as avg_price, MAX(sp.updated_at) as last_product_update FROM dispensaries d LEFT JOIN store_products sp ON sp.dispensary_id = d.id WHERE d.state IS NOT NULL GROUP BY d.id, d.name, d.dba_name, d.city, d.state, d.menu_type, d.crawl_enabled ORDER BY product_count DESC LIMIT 200 `); res.json({ stores: storeRows.map((r: any) => ({ id: r.id, name: r.name, dbaName: r.dba_name, city: r.city, state: r.state, menuType: r.menu_type, crawlEnabled: r.crawl_enabled, productCount: parseInt(r.product_count || '0', 10), brandCount: parseInt(r.brand_count || '0', 10), avgPrice: r.avg_price ? parseFloat(r.avg_price) : null, lastProductUpdate: r.last_product_update, })), total: storeRows.length, }); } catch (error: any) { console.error('[Intelligence] Error fetching stores:', error.message); res.status(500).json({ error: error.message }); } }); export default router;