From d76a5fb3c5b1df55b64348bb9f16860e635d392b Mon Sep 17 00:00:00 2001 From: Kelly Date: Mon, 15 Dec 2025 11:06:23 -0700 Subject: [PATCH] feat(api): Add brand analytics API endpoints MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit Add comprehensive brand-level analytics endpoints at /api/brands: Brand Discovery: - GET /api/brands - List all brands with summary metrics - GET /api/brands/search - Search brands by name - GET /api/brands/top - Top brands by distribution Brand Overview: - GET /api/brands/:brand - Full brand intelligence dashboard - GET /api/brands/:brand/analytics - Alias for overview Sales & Velocity: - GET /api/brands/:brand/sales - Sales data (4wk, daily avg) - GET /api/brands/:brand/velocity - Units/day by SKU - GET /api/brands/:brand/trends - Weekly sales trends Inventory & Stock: - GET /api/brands/:brand/inventory - Current stock levels - GET /api/brands/:brand/oos - Out-of-stock products - GET /api/brands/:brand/low-stock - Products below threshold Pricing: - GET /api/brands/:brand/pricing - Current prices - GET /api/brands/:brand/price-history - Price changes over time Distribution: - GET /api/brands/:brand/distribution - Store count, market coverage - GET /api/brands/:brand/stores - Stores carrying brand - GET /api/brands/:brand/gaps - Whitespace opportunities Events & Alerts: - GET /api/brands/:brand/events - Visibility events - POST /api/brands/:brand/events/:id/ack - Acknowledge alert Products: - GET /api/brands/:brand/products - All SKUs with metrics - GET /api/brands/:brand/products/:sku - Single product deep dive All endpoints support ?state=XX, ?days=N, and ?category=X filters. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 --- backend/src/index.ts | 10 + backend/src/routes/brands.ts | 979 +++++++++++++++++++++++++++++++++++ 2 files changed, 989 insertions(+) create mode 100644 backend/src/routes/brands.ts diff --git a/backend/src/index.ts b/backend/src/index.ts index e5618362..27faffa2 100755 --- a/backend/src/index.ts +++ b/backend/src/index.ts @@ -105,6 +105,7 @@ import { createSystemRouter, createPrometheusRouter } from './system/routes'; import { createPortalRoutes } from './portals'; import { createStatesRouter } from './routes/states'; import { createAnalyticsV2Router } from './routes/analytics-v2'; +import { createBrandsRouter } from './routes/brands'; import { createDiscoveryRoutes } from './discovery'; import pipelineRoutes from './routes/pipeline'; @@ -229,6 +230,15 @@ try { console.warn('[AnalyticsV2] Failed to register routes:', error); } +// Brand Analytics API - Hoodie Analytics-style market intelligence +try { + const brandsRouter = createBrandsRouter(getPool()); + app.use('/api/brands', brandsRouter); + console.log('[Brands] Routes registered at /api/brands'); +} catch (error) { + console.warn('[Brands] Failed to register routes:', error); +} + // Public API v1 - External consumer endpoints (WordPress, etc.) // Uses dutchie_az data pipeline with per-dispensary API key auth app.use('/api/v1', publicApiRoutes); diff --git a/backend/src/routes/brands.ts b/backend/src/routes/brands.ts new file mode 100644 index 00000000..158f14f8 --- /dev/null +++ b/backend/src/routes/brands.ts @@ -0,0 +1,979 @@ +/** + * Brand Analytics API Routes + * + * Comprehensive brand-level analytics endpoints for Hoodie Analytics-style + * market intelligence. Provides sales velocity, inventory tracking, distribution + * metrics, and competitive insights. + * + * Routes are prefixed with /api/brands + * + * All routes require authentication via authMiddleware. + */ + +import { Router, Request, Response } from 'express'; +import { Pool } from 'pg'; +import { authMiddleware } from '../auth/middleware'; +import { BrandIntelligenceService } from '../services/analytics/BrandIntelligenceService'; +import { BrandPenetrationService } from '../services/analytics/BrandPenetrationService'; +import { PriceAnalyticsService } from '../services/analytics/PriceAnalyticsService'; +import { TimeWindow } from '../services/analytics/types'; + +function parseTimeWindow(window?: string): TimeWindow { + if (window === '7d' || window === '30d' || window === '90d' || window === 'custom') { + return window; + } + return '30d'; +} + +function parseDays(days?: string): number { + const parsed = parseInt(days || '28', 10); + return isNaN(parsed) ? 28 : Math.min(Math.max(parsed, 1), 365); +} + +function parseLimit(limit?: string, defaultLimit = 50): number { + const parsed = parseInt(limit || String(defaultLimit), 10); + return isNaN(parsed) ? defaultLimit : Math.min(Math.max(parsed, 1), 500); +} + +function parseOffset(offset?: string): number { + const parsed = parseInt(offset || '0', 10); + return isNaN(parsed) ? 0 : Math.max(parsed, 0); +} + +export function createBrandsRouter(pool: Pool): Router { + const router = Router(); + + // Apply auth middleware to all routes + router.use(authMiddleware); + + // Initialize services + const brandIntelligenceService = new BrandIntelligenceService(pool); + const brandPenetrationService = new BrandPenetrationService(pool); + const priceService = new PriceAnalyticsService(pool); + + // ============================================================ + // BRAND DISCOVERY + // ============================================================ + + /** + * GET / + * List all brands with summary metrics + */ + router.get('/', async (req: Request, res: Response) => { + try { + const limit = parseLimit(req.query.limit as string, 100); + const offset = parseOffset(req.query.offset as string); + const stateCode = req.query.state as string | undefined; + const category = req.query.category as string | undefined; + const sort = (req.query.sort as string) || 'store_count_desc'; + + // Get brands with summary stats + const result = await pool.query(` + WITH brand_stats AS ( + SELECT + sp.brand_name_raw AS brand, + COUNT(*) AS sku_count, + COUNT(DISTINCT sp.dispensary_id) AS store_count, + COUNT(*) FILTER (WHERE sp.is_in_stock = TRUE) AS in_stock_count, + AVG(sp.price_rec) AS avg_price, + COUNT(DISTINCT sp.category_raw) AS category_count + FROM store_products sp + JOIN dispensaries d ON d.id = sp.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE sp.brand_name_raw IS NOT NULL + ${stateCode ? 'AND s.code = $3' : ''} + ${category ? `AND sp.category_raw = $${stateCode ? 4 : 3}` : ''} + GROUP BY sp.brand_name_raw + ) + SELECT * + FROM brand_stats + ORDER BY ${sort === 'sku_count_desc' ? 'sku_count DESC' : + sort === 'avg_price_desc' ? 'avg_price DESC NULLS LAST' : + 'store_count DESC'} + LIMIT $1 OFFSET $2 + `, stateCode && category ? [limit, offset, stateCode, category] : + stateCode ? [limit, offset, stateCode] : + category ? [limit, offset, category] : + [limit, offset]); + + // Get total count + const countResult = await pool.query(` + SELECT COUNT(DISTINCT sp.brand_name_raw) AS total + FROM store_products sp + JOIN dispensaries d ON d.id = sp.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE sp.brand_name_raw IS NOT NULL + ${stateCode ? 'AND s.code = $1' : ''} + ${category ? `AND sp.category_raw = $${stateCode ? 2 : 1}` : ''} + `, stateCode && category ? [stateCode, category] : + stateCode ? [stateCode] : + category ? [category] : []); + + res.json({ + brands: result.rows.map(row => ({ + brand: row.brand, + sku_count: parseInt(row.sku_count), + store_count: parseInt(row.store_count), + in_stock_count: parseInt(row.in_stock_count), + avg_price: row.avg_price ? parseFloat(row.avg_price).toFixed(2) : null, + category_count: parseInt(row.category_count), + })), + pagination: { + total: parseInt(countResult.rows[0]?.total || '0'), + limit, + offset, + }, + }); + } catch (error) { + console.error('[Brands] List error:', error); + res.status(500).json({ error: 'Failed to fetch brands' }); + } + }); + + /** + * GET /search + * Search brands by name + */ + router.get('/search', async (req: Request, res: Response) => { + try { + const query = req.query.q as string; + const limit = parseLimit(req.query.limit as string, 20); + + if (!query || query.length < 2) { + return res.status(400).json({ error: 'Search query must be at least 2 characters' }); + } + + const result = await pool.query(` + SELECT + sp.brand_name_raw AS brand, + COUNT(*) AS sku_count, + COUNT(DISTINCT sp.dispensary_id) AS store_count + FROM store_products sp + WHERE sp.brand_name_raw ILIKE $1 + AND sp.brand_name_raw IS NOT NULL + GROUP BY sp.brand_name_raw + ORDER BY store_count DESC + LIMIT $2 + `, [`%${query}%`, limit]); + + res.json({ + query, + results: result.rows.map(row => ({ + brand: row.brand, + sku_count: parseInt(row.sku_count), + store_count: parseInt(row.store_count), + })), + }); + } catch (error) { + console.error('[Brands] Search error:', error); + res.status(500).json({ error: 'Failed to search brands' }); + } + }); + + /** + * GET /top + * Get top brands by sales/distribution + */ + router.get('/top', async (req: Request, res: Response) => { + try { + const limit = parseLimit(req.query.limit as string, 25); + const stateCode = req.query.state as string | undefined; + const category = req.query.category as string | undefined; + + const result = await brandPenetrationService.getTopBrandsByPenetration({ + limit, + stateCode, + category, + }); + + res.json(result); + } catch (error) { + console.error('[Brands] Top error:', error); + res.status(500).json({ error: 'Failed to fetch top brands' }); + } + }); + + // ============================================================ + // BRAND OVERVIEW (Single Brand) + // ============================================================ + + /** + * GET /:brand + * Get brand profile with all metrics combined + */ + router.get('/:brand', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const window = parseTimeWindow(req.query.window as string); + const stateCode = req.query.state as string | undefined; + const category = req.query.category as string | undefined; + + const result = await brandIntelligenceService.getBrandIntelligence(brandName, { + window, + stateCode, + category, + }); + + if (!result) { + return res.status(404).json({ error: 'Brand not found' }); + } + + res.json(result); + } catch (error) { + console.error('[Brands] Overview error:', error); + res.status(500).json({ error: 'Failed to fetch brand overview' }); + } + }); + + /** + * GET /:brand/analytics + * Full analytics (alias for /:brand) + */ + router.get('/:brand/analytics', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const window = parseTimeWindow(req.query.window as string); + const stateCode = req.query.state as string | undefined; + const category = req.query.category as string | undefined; + + const result = await brandIntelligenceService.getBrandIntelligence(brandName, { + window, + stateCode, + category, + }); + + if (!result) { + return res.status(404).json({ error: 'Brand not found' }); + } + + res.json(result); + } catch (error) { + console.error('[Brands] Analytics error:', error); + res.status(500).json({ error: 'Failed to fetch brand analytics' }); + } + }); + + // ============================================================ + // SALES & VELOCITY + // ============================================================ + + /** + * GET /:brand/sales + * Get sales data (4wk, daily avg) + */ + router.get('/:brand/sales', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const days = parseDays(req.query.days as string); + const stateCode = req.query.state as string | undefined; + + const startDate = new Date(); + startDate.setDate(startDate.getDate() - days); + + const result = await pool.query(` + WITH qty_changes AS ( + SELECT + sps.store_product_id, + sps.price_rec, + sps.stock_quantity, + LAG(sps.stock_quantity) OVER ( + PARTITION BY sps.store_product_id ORDER BY sps.captured_at + ) AS prev_qty, + DATE(sps.captured_at) AS sale_date + FROM store_product_snapshots sps + JOIN store_products sp ON sp.id = sps.store_product_id + JOIN dispensaries d ON d.id = sp.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE sps.brand_name_raw = $1 + AND sps.captured_at >= $2 + AND sps.stock_quantity IS NOT NULL + ${stateCode ? 'AND s.code = $3' : ''} + ), + daily_sales AS ( + SELECT + sale_date, + SUM(GREATEST(0, COALESCE(prev_qty, 0) - stock_quantity)) AS units_sold, + SUM(GREATEST(0, COALESCE(prev_qty, 0) - stock_quantity) * COALESCE(price_rec, 0)) AS revenue + FROM qty_changes + WHERE prev_qty IS NOT NULL + GROUP BY sale_date + ) + SELECT + SUM(units_sold) AS total_units, + SUM(revenue) AS total_revenue, + AVG(units_sold) AS avg_daily_units, + AVG(revenue) AS avg_daily_revenue, + COUNT(DISTINCT sale_date) AS days_tracked + FROM daily_sales + `, stateCode ? [brandName, startDate, stateCode] : [brandName, startDate]); + + const row = result.rows[0] || {}; + + res.json({ + brand: brandName, + period_days: days, + sales: { + total_units: parseInt(row.total_units) || 0, + total_revenue: parseFloat(row.total_revenue) || 0, + avg_daily_units: parseFloat(row.avg_daily_units)?.toFixed(1) || '0', + avg_daily_revenue: parseFloat(row.avg_daily_revenue)?.toFixed(2) || '0', + days_tracked: parseInt(row.days_tracked) || 0, + }, + }); + } catch (error) { + console.error('[Brands] Sales error:', error); + res.status(500).json({ error: 'Failed to fetch brand sales' }); + } + }); + + /** + * GET /:brand/velocity + * Get units/day breakdown by SKU + */ + router.get('/:brand/velocity', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const window = parseTimeWindow(req.query.window as string); + const stateCode = req.query.state as string | undefined; + const category = req.query.category as string | undefined; + + const result = await brandIntelligenceService.getBrandIntelligence(brandName, { + window, + stateCode, + category, + }); + + if (!result) { + return res.status(404).json({ error: 'Brand not found' }); + } + + res.json({ + brand: brandName, + window, + sku_performance: result.sku_performance, + }); + } catch (error) { + console.error('[Brands] Velocity error:', error); + res.status(500).json({ error: 'Failed to fetch brand velocity' }); + } + }); + + /** + * GET /:brand/trends + * Get weekly sales trends + */ + router.get('/:brand/trends', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const days = parseDays(req.query.days as string); + const stateCode = req.query.state as string | undefined; + + const startDate = new Date(); + startDate.setDate(startDate.getDate() - days); + + const result = await pool.query(` + WITH qty_changes AS ( + SELECT + sps.store_product_id, + sps.price_rec, + sps.stock_quantity, + LAG(sps.stock_quantity) OVER ( + PARTITION BY sps.store_product_id ORDER BY sps.captured_at + ) AS prev_qty, + DATE_TRUNC('week', sps.captured_at) AS week + FROM store_product_snapshots sps + JOIN store_products sp ON sp.id = sps.store_product_id + JOIN dispensaries d ON d.id = sp.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE sps.brand_name_raw = $1 + AND sps.captured_at >= $2 + AND sps.stock_quantity IS NOT NULL + ${stateCode ? 'AND s.code = $3' : ''} + ) + SELECT + week, + SUM(GREATEST(0, COALESCE(prev_qty, 0) - stock_quantity)) AS units_sold, + SUM(GREATEST(0, COALESCE(prev_qty, 0) - stock_quantity) * COALESCE(price_rec, 0)) AS revenue + FROM qty_changes + WHERE prev_qty IS NOT NULL + GROUP BY week + ORDER BY week + `, stateCode ? [brandName, startDate, stateCode] : [brandName, startDate]); + + res.json({ + brand: brandName, + period_days: days, + trends: result.rows.map(row => ({ + week: row.week.toISOString().split('T')[0], + units_sold: parseInt(row.units_sold) || 0, + revenue: parseFloat(row.revenue) || 0, + })), + }); + } catch (error) { + console.error('[Brands] Trends error:', error); + res.status(500).json({ error: 'Failed to fetch brand trends' }); + } + }); + + // ============================================================ + // INVENTORY & STOCK + // ============================================================ + + /** + * GET /:brand/inventory + * Get current stock levels, days of stock + */ + router.get('/:brand/inventory', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const window = parseTimeWindow(req.query.window as string); + const stateCode = req.query.state as string | undefined; + + const result = await brandIntelligenceService.getBrandIntelligence(brandName, { + window, + stateCode, + }); + + if (!result) { + return res.status(404).json({ error: 'Brand not found' }); + } + + res.json({ + brand: brandName, + inventory_health: result.inventory_health, + }); + } catch (error) { + console.error('[Brands] Inventory error:', error); + res.status(500).json({ error: 'Failed to fetch brand inventory' }); + } + }); + + /** + * GET /:brand/oos + * Get out-of-stock SKUs + days since OOS + */ + router.get('/:brand/oos', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const limit = parseLimit(req.query.limit as string, 100); + const stateCode = req.query.state as string | undefined; + + const result = await pool.query(` + SELECT + sp.id AS store_product_id, + sp.name_raw AS product_name, + d.name AS store_name, + s.code AS state_code, + sp.last_seen_at, + EXTRACT(DAY FROM NOW() - sp.last_seen_at)::INT AS days_since_oos, + sp.price_rec AS last_price + FROM store_products sp + JOIN dispensaries d ON d.id = sp.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE sp.brand_name_raw = $1 + AND sp.is_in_stock = FALSE + ${stateCode ? 'AND s.code = $3' : ''} + ORDER BY sp.last_seen_at DESC + LIMIT $2 + `, stateCode ? [brandName, limit, stateCode] : [brandName, limit]); + + res.json({ + brand: brandName, + oos_count: result.rows.length, + products: result.rows.map(row => ({ + store_product_id: row.store_product_id, + product_name: row.product_name, + store_name: row.store_name, + state_code: row.state_code, + last_seen_at: row.last_seen_at, + days_since_oos: row.days_since_oos, + last_price: row.last_price ? parseFloat(row.last_price) : null, + })), + }); + } catch (error) { + console.error('[Brands] OOS error:', error); + res.status(500).json({ error: 'Failed to fetch OOS products' }); + } + }); + + /** + * GET /:brand/low-stock + * Get products below threshold + */ + router.get('/:brand/low-stock', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const limit = parseLimit(req.query.limit as string, 100); + const stateCode = req.query.state as string | undefined; + const threshold = parseInt(req.query.threshold as string) || 10; + + const result = await pool.query(` + SELECT + sp.id AS store_product_id, + sp.name_raw AS product_name, + d.name AS store_name, + s.code AS state_code, + sp.stock_quantity, + sp.price_rec + FROM store_products sp + JOIN dispensaries d ON d.id = sp.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE sp.brand_name_raw = $1 + AND sp.is_in_stock = TRUE + AND sp.stock_quantity IS NOT NULL + AND sp.stock_quantity < $3 + ${stateCode ? 'AND s.code = $4' : ''} + ORDER BY sp.stock_quantity ASC + LIMIT $2 + `, stateCode ? [brandName, limit, threshold, stateCode] : [brandName, limit, threshold]); + + res.json({ + brand: brandName, + threshold, + low_stock_count: result.rows.length, + products: result.rows.map(row => ({ + store_product_id: row.store_product_id, + product_name: row.product_name, + store_name: row.store_name, + state_code: row.state_code, + stock_quantity: parseInt(row.stock_quantity), + price: row.price_rec ? parseFloat(row.price_rec) : null, + })), + }); + } catch (error) { + console.error('[Brands] Low stock error:', error); + res.status(500).json({ error: 'Failed to fetch low stock products' }); + } + }); + + // ============================================================ + // PRICING + // ============================================================ + + /** + * GET /:brand/pricing + * Get current prices by SKU/store + */ + router.get('/:brand/pricing', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const stateCode = req.query.state as string | undefined; + + const result = await priceService.getBrandPriceByState(brandName, { stateCode }); + res.json(result); + } catch (error) { + console.error('[Brands] Pricing error:', error); + res.status(500).json({ error: 'Failed to fetch brand pricing' }); + } + }); + + /** + * GET /:brand/price-history + * Get price changes over time + */ + router.get('/:brand/price-history', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const days = parseDays(req.query.days as string); + const limit = parseLimit(req.query.limit as string, 100); + + const startDate = new Date(); + startDate.setDate(startDate.getDate() - days); + + const result = await pool.query(` + SELECT + pve.id, + pve.product_id, + pve.product_name, + d.name AS store_name, + s.code AS state_code, + pve.detected_at, + pve.previous_price, + pve.new_price, + pve.price_change_pct + FROM product_visibility_events pve + JOIN dispensaries d ON d.id = pve.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE pve.brand_name = $1 + AND pve.event_type = 'price_change' + AND pve.detected_at >= $2 + ORDER BY pve.detected_at DESC + LIMIT $3 + `, [brandName, startDate, limit]); + + res.json({ + brand: brandName, + period_days: days, + price_changes: result.rows.map(row => ({ + id: row.id, + product_id: row.product_id, + product_name: row.product_name, + store_name: row.store_name, + state_code: row.state_code, + detected_at: row.detected_at, + previous_price: row.previous_price ? parseFloat(row.previous_price) : null, + new_price: row.new_price ? parseFloat(row.new_price) : null, + price_change_pct: row.price_change_pct ? parseFloat(row.price_change_pct) : null, + })), + }); + } catch (error) { + console.error('[Brands] Price history error:', error); + res.status(500).json({ error: 'Failed to fetch price history' }); + } + }); + + // ============================================================ + // DISTRIBUTION + // ============================================================ + + /** + * GET /:brand/distribution + * Get store count, % market coverage + */ + router.get('/:brand/distribution', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const window = parseTimeWindow(req.query.window as string); + + const result = await brandPenetrationService.getBrandPenetration(brandName, { window }); + + if (!result) { + return res.status(404).json({ error: 'Brand not found' }); + } + + res.json(result); + } catch (error) { + console.error('[Brands] Distribution error:', error); + res.status(500).json({ error: 'Failed to fetch brand distribution' }); + } + }); + + /** + * GET /:brand/stores + * Get list of stores carrying brand + */ + router.get('/:brand/stores', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const limit = parseLimit(req.query.limit as string, 100); + const offset = parseOffset(req.query.offset as string); + const stateCode = req.query.state as string | undefined; + + const result = await pool.query(` + SELECT + d.id AS store_id, + d.name AS store_name, + s.code AS state_code, + d.city, + COUNT(*) AS sku_count, + COUNT(*) FILTER (WHERE sp.is_in_stock = TRUE) AS in_stock_count, + AVG(sp.price_rec) AS avg_price + FROM store_products sp + JOIN dispensaries d ON d.id = sp.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE sp.brand_name_raw = $1 + ${stateCode ? 'AND s.code = $4' : ''} + GROUP BY d.id, d.name, s.code, d.city + ORDER BY sku_count DESC + LIMIT $2 OFFSET $3 + `, stateCode ? [brandName, limit, offset, stateCode] : [brandName, limit, offset]); + + res.json({ + brand: brandName, + stores: result.rows.map(row => ({ + store_id: row.store_id, + store_name: row.store_name, + state_code: row.state_code, + city: row.city, + sku_count: parseInt(row.sku_count), + in_stock_count: parseInt(row.in_stock_count), + avg_price: row.avg_price ? parseFloat(row.avg_price).toFixed(2) : null, + })), + }); + } catch (error) { + console.error('[Brands] Stores error:', error); + res.status(500).json({ error: 'Failed to fetch brand stores' }); + } + }); + + /** + * GET /:brand/gaps + * Get stores NOT carrying brand (whitespace opportunities) + */ + router.get('/:brand/gaps', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const window = parseTimeWindow(req.query.window as string); + const stateCode = req.query.state as string | undefined; + + const result = await brandIntelligenceService.getBrandIntelligence(brandName, { + window, + stateCode, + }); + + if (!result) { + return res.status(404).json({ error: 'Brand not found' }); + } + + res.json({ + brand: brandName, + whitespace_stores: result.retail_footprint.whitespace_stores, + }); + } catch (error) { + console.error('[Brands] Gaps error:', error); + res.status(500).json({ error: 'Failed to fetch brand gaps' }); + } + }); + + // ============================================================ + // EVENTS & ALERTS + // ============================================================ + + /** + * GET /:brand/events + * Get all visibility events (OOS, price changes, etc.) + */ + router.get('/:brand/events', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const days = parseDays(req.query.days as string); + const limit = parseLimit(req.query.limit as string, 100); + const eventType = req.query.type as string | undefined; + + const startDate = new Date(); + startDate.setDate(startDate.getDate() - days); + + const result = await pool.query(` + SELECT + pve.id, + pve.dispensary_id, + d.name AS store_name, + s.code AS state_code, + pve.product_id, + pve.product_name, + pve.event_type, + pve.detected_at, + pve.previous_price, + pve.new_price, + pve.price_change_pct, + pve.previous_quantity, + pve.notified, + pve.acknowledged_at + FROM product_visibility_events pve + JOIN dispensaries d ON d.id = pve.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE pve.brand_name = $1 + AND pve.detected_at >= $2 + ${eventType ? 'AND pve.event_type = $4' : ''} + ORDER BY pve.detected_at DESC + LIMIT $3 + `, eventType ? [brandName, startDate, limit, eventType] : [brandName, startDate, limit]); + + res.json({ + brand: brandName, + period_days: days, + events: result.rows.map(row => ({ + id: row.id, + dispensary_id: row.dispensary_id, + store_name: row.store_name, + state_code: row.state_code, + product_id: row.product_id, + product_name: row.product_name, + event_type: row.event_type, + detected_at: row.detected_at, + previous_price: row.previous_price ? parseFloat(row.previous_price) : null, + new_price: row.new_price ? parseFloat(row.new_price) : null, + price_change_pct: row.price_change_pct ? parseFloat(row.price_change_pct) : null, + previous_quantity: row.previous_quantity, + notified: row.notified, + acknowledged_at: row.acknowledged_at, + })), + }); + } catch (error) { + console.error('[Brands] Events error:', error); + res.status(500).json({ error: 'Failed to fetch brand events' }); + } + }); + + /** + * POST /:brand/events/:id/ack + * Acknowledge an alert + */ + router.post('/:brand/events/:id/ack', async (req: Request, res: Response) => { + try { + const eventId = parseInt(req.params.id); + const acknowledgedBy = (req as any).user?.email || 'unknown'; + + await pool.query(` + UPDATE product_visibility_events + SET acknowledged_at = NOW(), + acknowledged_by = $2 + WHERE id = $1 + `, [eventId, acknowledgedBy]); + + res.json({ success: true, event_id: eventId }); + } catch (error) { + console.error('[Brands] Ack error:', error); + res.status(500).json({ error: 'Failed to acknowledge event' }); + } + }); + + // ============================================================ + // PRODUCTS + // ============================================================ + + /** + * GET /:brand/products + * Get all SKUs with full metrics + */ + router.get('/:brand/products', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const limit = parseLimit(req.query.limit as string, 100); + const offset = parseOffset(req.query.offset as string); + const stateCode = req.query.state as string | undefined; + const category = req.query.category as string | undefined; + const inStock = req.query.in_stock as string | undefined; + + let stockFilter = ''; + if (inStock === 'true') stockFilter = 'AND sp.is_in_stock = TRUE'; + if (inStock === 'false') stockFilter = 'AND sp.is_in_stock = FALSE'; + + const result = await pool.query(` + SELECT + sp.id AS store_product_id, + sp.provider_product_id, + sp.name_raw AS product_name, + sp.category_raw AS category, + d.name AS store_name, + s.code AS state_code, + sp.is_in_stock, + sp.stock_quantity, + sp.price_rec, + sp.price_med, + sp.is_on_special, + sp.first_seen_at, + sp.last_seen_at, + sp.updated_at + FROM store_products sp + JOIN dispensaries d ON d.id = sp.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE sp.brand_name_raw = $1 + ${stateCode ? 'AND s.code = $4' : ''} + ${category ? `AND sp.category_raw = $${stateCode ? 5 : 4}` : ''} + ${stockFilter} + ORDER BY sp.updated_at DESC + LIMIT $2 OFFSET $3 + `, stateCode && category ? [brandName, limit, offset, stateCode, category] : + stateCode ? [brandName, limit, offset, stateCode] : + category ? [brandName, limit, offset, category] : + [brandName, limit, offset]); + + res.json({ + brand: brandName, + products: result.rows.map(row => ({ + store_product_id: row.store_product_id, + provider_product_id: row.provider_product_id, + product_name: row.product_name, + category: row.category, + store_name: row.store_name, + state_code: row.state_code, + is_in_stock: row.is_in_stock, + stock_quantity: row.stock_quantity ? parseInt(row.stock_quantity) : null, + price_rec: row.price_rec ? parseFloat(row.price_rec) : null, + price_med: row.price_med ? parseFloat(row.price_med) : null, + is_on_special: row.is_on_special, + first_seen_at: row.first_seen_at, + last_seen_at: row.last_seen_at, + updated_at: row.updated_at, + })), + }); + } catch (error) { + console.error('[Brands] Products error:', error); + res.status(500).json({ error: 'Failed to fetch brand products' }); + } + }); + + /** + * GET /:brand/products/:sku + * Get single product deep dive + */ + router.get('/:brand/products/:sku', async (req: Request, res: Response) => { + try { + const brandName = decodeURIComponent(req.params.brand); + const sku = decodeURIComponent(req.params.sku); + + // Get product across all stores + const productResult = await pool.query(` + SELECT + sp.id AS store_product_id, + sp.provider_product_id, + sp.name_raw AS product_name, + sp.category_raw AS category, + d.id AS store_id, + d.name AS store_name, + s.code AS state_code, + sp.is_in_stock, + sp.stock_quantity, + sp.price_rec, + sp.price_med, + sp.is_on_special, + sp.first_seen_at, + sp.last_seen_at + FROM store_products sp + JOIN dispensaries d ON d.id = sp.dispensary_id + LEFT JOIN states s ON s.id = d.state_id + WHERE sp.brand_name_raw = $1 + AND (sp.provider_product_id = $2 OR sp.name_raw ILIKE $2) + ORDER BY sp.updated_at DESC + `, [brandName, sku]); + + if (productResult.rows.length === 0) { + return res.status(404).json({ error: 'Product not found' }); + } + + // Get price history for this product + const priceHistoryResult = await pool.query(` + SELECT + captured_at, + price_rec, + stock_quantity + FROM store_product_snapshots + WHERE store_product_id = $1 + ORDER BY captured_at DESC + LIMIT 100 + `, [productResult.rows[0].store_product_id]); + + res.json({ + brand: brandName, + sku, + stores: productResult.rows.map(row => ({ + store_product_id: row.store_product_id, + provider_product_id: row.provider_product_id, + product_name: row.product_name, + category: row.category, + store_id: row.store_id, + store_name: row.store_name, + state_code: row.state_code, + is_in_stock: row.is_in_stock, + stock_quantity: row.stock_quantity ? parseInt(row.stock_quantity) : null, + price_rec: row.price_rec ? parseFloat(row.price_rec) : null, + price_med: row.price_med ? parseFloat(row.price_med) : null, + is_on_special: row.is_on_special, + first_seen_at: row.first_seen_at, + last_seen_at: row.last_seen_at, + })), + price_history: priceHistoryResult.rows.map(row => ({ + captured_at: row.captured_at, + price_rec: row.price_rec ? parseFloat(row.price_rec) : null, + stock_quantity: row.stock_quantity ? parseInt(row.stock_quantity) : null, + })), + }); + } catch (error) { + console.error('[Brands] Product detail error:', error); + res.status(500).json({ error: 'Failed to fetch product details' }); + } + }); + + return router; +}