/** * BrandIntelligenceService * * Comprehensive B2B Brand Intelligence dashboard endpoint. * Aggregates all brand metrics into a single unified response. * * Sections: * 1. Performance Snapshot - Summary cards with key metrics * 2. Alerts/Slippage - Issues requiring attention * 3. Product Velocity - SKU sell-through rates * 4. Retail Footprint - Store placement and coverage * 5. Competitive Landscape - Market positioning vs competitors * 6. Inventory Health - Stock projections and risk levels * 7. Promotion Effectiveness - Promo ROI and lift metrics */ import { Pool } from 'pg'; import { TimeWindow, DateRange, getDateRangeFromWindow, } from './types'; // ============================================================ // BRAND INTELLIGENCE TYPES // ============================================================ export type VelocityStatus = 'hot' | 'steady' | 'slow' | 'stale'; export type PricePosition = 'premium' | 'value' | 'competitive'; export type RiskLevel = 'critical' | 'elevated' | 'moderate' | 'healthy'; export type PromoStatus = 'active' | 'scheduled' | 'ended'; export type AlertSeverity = 'critical' | 'warning'; export interface BrandIntelligenceResult { brand_name: string; window: TimeWindow; generated_at: string; // Section 1: Performance Snapshot performance_snapshot: { active_skus: number; total_revenue_30d: number | null; // Estimated from qty × price total_stores: number; new_stores_30d: number; market_share: number | null; // % of category avg_wholesale_price: number | null; price_position: PricePosition; }; // Section 2: Alerts/Slippage alerts: { lost_stores_30d_count: number; lost_skus_30d_count: number; competitor_takeover_count: number; avg_oos_duration_days: number | null; avg_reorder_lag_days: number | null; items: Array<{ type: 'lost_store' | 'delisted_sku' | 'shelf_loss' | 'extended_oos'; severity: AlertSeverity; store_name?: string; product_name?: string; competitor_brand?: string; days_since?: number; state_code?: string; }>; }; // Section 3: Product Velocity sku_performance: Array<{ store_product_id: number; product_name: string; category: string | null; daily_velocity: number; // Units/day estimate velocity_status: VelocityStatus; retail_price: number | null; on_sale: boolean; stores_carrying: number; stock_status: 'in_stock' | 'low_stock' | 'out_of_stock'; }>; // Section 4: Retail Footprint retail_footprint: { total_stores: number; in_stock_count: number; out_of_stock_count: number; penetration_by_region: Array<{ state_code: string; store_count: number; percent_reached: number; in_stock: number; out_of_stock: number; }>; whitespace_stores: Array<{ store_id: number; store_name: string; state_code: string; city: string | null; category_fit: number; // How many competing brands they carry competitor_brands: string[]; }>; }; // Section 5: Competitive Landscape competitive_landscape: { brand_price_position: PricePosition; market_share_trend: Array<{ date: string; share_percent: number; }>; competitors: Array<{ brand_name: string; store_overlap_percent: number; price_position: PricePosition; avg_price: number | null; sku_count: number; }>; head_to_head_skus: Array<{ product_name: string; brand_price: number; competitor_brand: string; competitor_price: number; price_diff_percent: number; }>; }; // Section 6: Inventory Health inventory_health: { critical_count: number; // <7 days stock warning_count: number; // 7-14 days stock healthy_count: number; // 14+ days stock overstocked_count: number; // >90 days stock skus: Array<{ store_product_id: number; product_name: string; store_name: string; days_of_stock: number | null; risk_level: RiskLevel; current_quantity: number | null; daily_sell_rate: number | null; }>; overstock_alert: Array<{ product_name: string; store_name: string; excess_units: number; days_of_stock: number; }>; }; // Section 7: Promotion Effectiveness promo_performance: { avg_baseline_velocity: number | null; avg_promo_velocity: number | null; avg_velocity_lift: number | null; // % increase during promo avg_efficiency_score: number | null; // ROI proxy promotions: Array<{ product_name: string; store_name: string; status: PromoStatus; start_date: string; end_date: string | null; regular_price: number; promo_price: number; discount_percent: number; baseline_velocity: number | null; promo_velocity: number | null; velocity_lift: number | null; efficiency_score: number | null; }>; }; } export class BrandIntelligenceService { constructor(private pool: Pool) {} /** * Get comprehensive brand intelligence dashboard data */ async getBrandIntelligence( brandName: string, options: { window?: TimeWindow; customRange?: DateRange; stateCode?: string; category?: string } = {} ): Promise { const { window = '30d', customRange, stateCode, category } = options; const { start, end } = getDateRangeFromWindow(window, customRange); // Verify brand exists const brandCheck = await this.pool.query(` SELECT COUNT(*) AS count FROM store_products WHERE brand_name_raw = $1 `, [brandName]); if (parseInt(brandCheck.rows[0].count) === 0) { return null; } // Fetch all sections in parallel for performance const [ performanceSnapshot, alerts, skuPerformance, retailFootprint, competitiveLandscape, inventoryHealth, promoPerformance, ] = await Promise.all([ this.getPerformanceSnapshot(brandName, { start, end, stateCode, category }), this.getAlerts(brandName, { start, end, stateCode }), this.getSkuPerformance(brandName, { start, end, stateCode, category }), this.getRetailFootprint(brandName, { stateCode }), this.getCompetitiveLandscape(brandName, { start, end, stateCode, category }), this.getInventoryHealth(brandName, { start, end, stateCode }), this.getPromoPerformance(brandName, { start, end, stateCode, category }), ]); return { brand_name: brandName, window, generated_at: new Date().toISOString(), performance_snapshot: performanceSnapshot, alerts, sku_performance: skuPerformance, retail_footprint: retailFootprint, competitive_landscape: competitiveLandscape, inventory_health: inventoryHealth, promo_performance: promoPerformance, }; } /** * Section 1: Performance Snapshot */ private async getPerformanceSnapshot( brandName: string, options: { start: Date; end: Date; stateCode?: string; category?: string } ): Promise { const { start, end, stateCode, category } = options; const params: any[] = [brandName]; let paramIdx = 2; let filters = ''; if (stateCode) { filters += ` AND s.code = $${paramIdx}`; params.push(stateCode); paramIdx++; } if (category) { filters += ` AND sp.category_raw = $${paramIdx}`; params.push(category); paramIdx++; } // Current metrics const currentResult = await this.pool.query(` SELECT COUNT(*) AS active_skus, COUNT(DISTINCT sp.dispensary_id) AS total_stores, 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 AND sp.is_in_stock = TRUE ${filters} `, params); const current = currentResult.rows[0]; // New stores in last 30 days (stores that started carrying the brand) const newStoresResult = await this.pool.query(` WITH brand_stores_start AS ( SELECT DISTINCT dispensary_id FROM store_product_snapshots WHERE brand_name_raw = $1 AND captured_at >= $2 AND captured_at < $2 + INTERVAL '1 day' ), brand_stores_now AS ( SELECT DISTINCT sp.dispensary_id FROM store_products sp WHERE sp.brand_name_raw = $1 AND sp.is_in_stock = TRUE ) SELECT COUNT(*) AS new_stores FROM brand_stores_now bsn WHERE NOT EXISTS ( SELECT 1 FROM brand_stores_start bss WHERE bss.dispensary_id = bsn.dispensary_id ) `, [brandName, start]); // Market share (brand's share of category SKUs) const marketShareResult = await this.pool.query(` WITH brand_skus AS ( SELECT COUNT(*) AS brand_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 = $1 AND sp.is_in_stock = TRUE ${filters} ), total_skus AS ( SELECT COUNT(*) AS total_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.is_in_stock = TRUE ${filters.replace(/\$1/g, '$999')} -- Skip brand filter ) SELECT CASE WHEN ts.total_count > 0 THEN ROUND(bs.brand_count::NUMERIC * 100 / ts.total_count, 2) ELSE 0 END AS market_share FROM brand_skus bs, total_skus ts `, params); // Estimate revenue from quantity decreases (sales proxy) const revenueResult = await this.pool.query(` WITH qty_decreases AS ( SELECT sps.price_rec, LAG(sps.stock_quantity) OVER w - sps.stock_quantity AS units_sold FROM store_product_snapshots sps WHERE sps.brand_name_raw = $1 AND sps.captured_at >= $2 AND sps.captured_at <= $3 AND sps.stock_quantity IS NOT NULL WINDOW w AS (PARTITION BY sps.store_product_id ORDER BY sps.captured_at) ) SELECT COALESCE(SUM(units_sold * price_rec), 0) AS estimated_revenue FROM qty_decreases WHERE units_sold > 0 AND price_rec IS NOT NULL `, [brandName, start, end]); // Determine price position const avgPrice = current.avg_price ? parseFloat(current.avg_price) : null; const pricePosition = await this.determinePricePosition(brandName, avgPrice, category); return { active_skus: parseInt(current.active_skus) || 0, total_revenue_30d: revenueResult.rows[0]?.estimated_revenue ? parseFloat(revenueResult.rows[0].estimated_revenue) : null, total_stores: parseInt(current.total_stores) || 0, new_stores_30d: parseInt(newStoresResult.rows[0]?.new_stores) || 0, market_share: marketShareResult.rows[0]?.market_share ? parseFloat(marketShareResult.rows[0].market_share) : null, avg_wholesale_price: avgPrice, price_position: pricePosition, }; } /** * Section 2: Alerts/Slippage */ private async getAlerts( brandName: string, options: { start: Date; end: Date; stateCode?: string } ): Promise { const { start, end, stateCode } = options; const alerts: BrandIntelligenceResult['alerts']['items'] = []; // Lost stores (stores that dropped the brand) const lostStoresResult = await this.pool.query(` WITH brand_stores_start AS ( SELECT DISTINCT sps.dispensary_id, d.name AS store_name, s.code AS state_code FROM store_product_snapshots sps JOIN dispensaries d ON d.id = sps.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.captured_at < $2 + INTERVAL '1 day' AND sps.is_in_stock = TRUE ${stateCode ? 'AND s.code = $3' : ''} ), brand_stores_now AS ( SELECT DISTINCT sp.dispensary_id FROM store_products sp WHERE sp.brand_name_raw = $1 AND sp.is_in_stock = TRUE ) SELECT bss.dispensary_id, bss.store_name, bss.state_code FROM brand_stores_start bss WHERE NOT EXISTS ( SELECT 1 FROM brand_stores_now bsn WHERE bsn.dispensary_id = bss.dispensary_id ) LIMIT 50 `, stateCode ? [brandName, start, stateCode] : [brandName, start]); for (const row of lostStoresResult.rows) { alerts.push({ type: 'lost_store', severity: 'critical', store_name: row.store_name, state_code: row.state_code, }); } // Lost SKUs (products that were delisted) const lostSkusResult = await this.pool.query(` SELECT sp.name_raw AS product_name, d.name AS store_name, s.code AS state_code, EXTRACT(DAY FROM NOW() - sp.last_seen_at)::INT AS days_since 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 AND sp.last_seen_at >= $2 AND sp.last_seen_at <= $3 ${stateCode ? 'AND s.code = $4' : ''} ORDER BY sp.last_seen_at DESC LIMIT 50 `, stateCode ? [brandName, start, end, stateCode] : [brandName, start, end]); for (const row of lostSkusResult.rows) { alerts.push({ type: 'delisted_sku', severity: row.days_since < 7 ? 'critical' : 'warning', product_name: row.product_name, store_name: row.store_name, state_code: row.state_code, days_since: row.days_since, }); } // Competitor takeovers (stores that dropped brand but added competitor) const takeoverResult = await this.pool.query(` WITH brand_lost_stores AS ( SELECT DISTINCT sps.dispensary_id FROM store_product_snapshots sps WHERE sps.brand_name_raw = $1 AND sps.captured_at >= $2 AND sps.captured_at < $2 + INTERVAL '1 day' AND sps.is_in_stock = TRUE EXCEPT SELECT DISTINCT sp.dispensary_id FROM store_products sp WHERE sp.brand_name_raw = $1 AND sp.is_in_stock = TRUE ), new_competitor_products AS ( SELECT sp.dispensary_id, d.name AS store_name, s.code AS state_code, sp.brand_name_raw AS competitor_brand 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.dispensary_id IN (SELECT dispensary_id FROM brand_lost_stores) AND sp.brand_name_raw != $1 AND sp.first_seen_at >= $2 AND sp.is_in_stock = TRUE GROUP BY sp.dispensary_id, d.name, s.code, sp.brand_name_raw ) SELECT * FROM new_competitor_products LIMIT 20 `, [brandName, start]); for (const row of takeoverResult.rows) { alerts.push({ type: 'shelf_loss', severity: 'critical', store_name: row.store_name, state_code: row.state_code, competitor_brand: row.competitor_brand, }); } // Calculate OOS duration average const oosDurationResult = await this.pool.query(` WITH oos_events AS ( SELECT store_product_id, captured_at AS oos_start, LEAD(captured_at) OVER (PARTITION BY store_product_id ORDER BY captured_at) AS oos_end FROM store_product_snapshots WHERE brand_name_raw = $1 AND captured_at >= $2 AND captured_at <= $3 AND is_in_stock = FALSE ) SELECT AVG(EXTRACT(DAY FROM COALESCE(oos_end, NOW()) - oos_start)) AS avg_oos_days FROM oos_events WHERE oos_end IS NOT NULL OR oos_start >= $2 `, [brandName, start, end]); // Calculate reorder lag (time between OOS and restock) const reorderLagResult = await this.pool.query(` WITH stock_transitions AS ( SELECT store_product_id, captured_at, is_in_stock, LAG(is_in_stock) OVER w AS prev_stock, LAG(captured_at) OVER w AS prev_time FROM store_product_snapshots WHERE brand_name_raw = $1 AND captured_at >= $2 AND captured_at <= $3 WINDOW w AS (PARTITION BY store_product_id ORDER BY captured_at) ) SELECT AVG(EXTRACT(DAY FROM captured_at - prev_time)) AS avg_reorder_lag FROM stock_transitions WHERE is_in_stock = TRUE AND prev_stock = FALSE `, [brandName, start, end]); return { lost_stores_30d_count: lostStoresResult.rows.length, lost_skus_30d_count: lostSkusResult.rows.length, competitor_takeover_count: takeoverResult.rows.length, avg_oos_duration_days: oosDurationResult.rows[0]?.avg_oos_days ? parseFloat(oosDurationResult.rows[0].avg_oos_days) : null, avg_reorder_lag_days: reorderLagResult.rows[0]?.avg_reorder_lag ? parseFloat(reorderLagResult.rows[0].avg_reorder_lag) : null, items: alerts, }; } /** * Section 3: SKU Performance (Velocity) */ private async getSkuPerformance( brandName: string, options: { start: Date; end: Date; stateCode?: string; category?: string } ): Promise { const { start, end, stateCode, category } = options; const params: any[] = [brandName, start, end]; let paramIdx = 4; let filters = ''; if (stateCode) { filters += ` AND s.code = $${paramIdx}`; params.push(stateCode); paramIdx++; } if (category) { filters += ` AND sp.category_raw = $${paramIdx}`; params.push(category); paramIdx++; } const result = await this.pool.query(` WITH sku_qty_changes AS ( SELECT sps.store_product_id, sps.stock_quantity, sps.captured_at, LAG(sps.stock_quantity) OVER (PARTITION BY sps.store_product_id ORDER BY sps.captured_at) AS prev_qty 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.captured_at <= $3 AND sps.stock_quantity IS NOT NULL ${filters} ), sku_sales AS ( SELECT store_product_id, SUM(GREATEST(0, COALESCE(prev_qty, 0) - stock_quantity)) AS units_sold, COUNT(DISTINCT DATE(captured_at)) AS days_tracked FROM sku_qty_changes WHERE prev_qty IS NOT NULL GROUP BY store_product_id ) SELECT sp.id AS store_product_id, sp.name_raw AS product_name, sp.category_raw AS category, COALESCE(ss.units_sold, 0) AS units_sold, COALESCE(ss.days_tracked, 1) AS days_tracked, ROUND(COALESCE(ss.units_sold::NUMERIC / NULLIF(ss.days_tracked, 0), 0), 2) AS daily_velocity, sp.price_rec AS retail_price, sp.is_on_special AS on_sale, ( SELECT COUNT(DISTINCT sp2.dispensary_id) FROM store_products sp2 WHERE sp2.name_raw = sp.name_raw AND sp2.brand_name_raw = sp.brand_name_raw AND sp2.is_in_stock = TRUE ) AS stores_carrying, CASE WHEN sp.is_in_stock = FALSE THEN 'out_of_stock' WHEN sp.stock_quantity IS NOT NULL AND sp.stock_quantity < 10 THEN 'low_stock' ELSE 'in_stock' END AS stock_status FROM store_products sp JOIN dispensaries d ON d.id = sp.dispensary_id LEFT JOIN states s ON s.id = d.state_id LEFT JOIN sku_sales ss ON ss.store_product_id = sp.id WHERE sp.brand_name_raw = $1 ${filters} ORDER BY COALESCE(ss.units_sold, 0) DESC LIMIT 100 `, params); return result.rows.map((row: any) => { const dailyVelocity = parseFloat(row.daily_velocity) || 0; let velocityStatus: VelocityStatus; if (dailyVelocity >= 5) velocityStatus = 'hot'; else if (dailyVelocity >= 1) velocityStatus = 'steady'; else if (dailyVelocity >= 0.1) velocityStatus = 'slow'; else velocityStatus = 'stale'; return { store_product_id: row.store_product_id, product_name: row.product_name, category: row.category, daily_velocity: dailyVelocity, velocity_status: velocityStatus, retail_price: row.retail_price ? parseFloat(row.retail_price) : null, on_sale: row.on_sale === true, stores_carrying: parseInt(row.stores_carrying) || 0, stock_status: row.stock_status, }; }); } /** * Section 4: Retail Footprint */ private async getRetailFootprint( brandName: string, options: { stateCode?: string } ): Promise { const { stateCode } = options; // Get store counts const storeCountResult = await this.pool.query(` SELECT COUNT(DISTINCT sp.dispensary_id) AS total_stores, COUNT(DISTINCT sp.dispensary_id) FILTER (WHERE sp.is_in_stock = TRUE) AS in_stock_stores, COUNT(DISTINCT sp.dispensary_id) FILTER (WHERE sp.is_in_stock = FALSE) AS oos_stores FROM store_products sp WHERE sp.brand_name_raw = $1 `, [brandName]); const counts = storeCountResult.rows[0]; // Penetration by region const regionResult = await this.pool.query(` WITH brand_stores AS ( SELECT s.code AS state_code, COUNT(DISTINCT sp.dispensary_id) AS brand_stores, COUNT(DISTINCT sp.dispensary_id) FILTER (WHERE sp.is_in_stock = TRUE) AS in_stock, COUNT(DISTINCT sp.dispensary_id) FILTER (WHERE sp.is_in_stock = FALSE) AS out_of_stock FROM store_products sp JOIN dispensaries d ON d.id = sp.dispensary_id JOIN states s ON s.id = d.state_id WHERE sp.brand_name_raw = $1 GROUP BY s.code ), total_stores AS ( SELECT s.code AS state_code, COUNT(DISTINCT d.id) AS total_stores FROM dispensaries d JOIN states s ON s.id = d.state_id GROUP BY s.code ) SELECT bs.state_code, bs.brand_stores AS store_count, ROUND(bs.brand_stores::NUMERIC * 100 / NULLIF(ts.total_stores, 0), 2) AS percent_reached, bs.in_stock, bs.out_of_stock FROM brand_stores bs JOIN total_stores ts ON ts.state_code = bs.state_code ORDER BY bs.brand_stores DESC `, [brandName]); // Whitespace stores (carry competitors but not this brand) const whitespaceResult = await this.pool.query(` WITH brand_categories AS ( SELECT DISTINCT category_raw FROM store_products WHERE brand_name_raw = $1 AND category_raw IS NOT NULL ), brand_stores AS ( SELECT DISTINCT dispensary_id FROM store_products WHERE brand_name_raw = $1 ), competitor_stores AS ( SELECT d.id AS store_id, d.name AS store_name, s.code AS state_code, d.city, ARRAY_AGG(DISTINCT sp.brand_name_raw) AS competitor_brands, COUNT(DISTINCT sp.brand_name_raw) AS category_fit 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.category_raw IN (SELECT category_raw FROM brand_categories) AND sp.brand_name_raw != $1 AND sp.is_in_stock = TRUE AND sp.dispensary_id NOT IN (SELECT dispensary_id FROM brand_stores) GROUP BY d.id, d.name, s.code, d.city ) SELECT * FROM competitor_stores ORDER BY category_fit DESC LIMIT 50 `, [brandName]); return { total_stores: parseInt(counts.total_stores) || 0, in_stock_count: parseInt(counts.in_stock_stores) || 0, out_of_stock_count: parseInt(counts.oos_stores) || 0, penetration_by_region: regionResult.rows.map((row: any) => ({ state_code: row.state_code, store_count: parseInt(row.store_count) || 0, percent_reached: parseFloat(row.percent_reached) || 0, in_stock: parseInt(row.in_stock) || 0, out_of_stock: parseInt(row.out_of_stock) || 0, })), whitespace_stores: whitespaceResult.rows.map((row: any) => ({ store_id: row.store_id, store_name: row.store_name, state_code: row.state_code, city: row.city, category_fit: parseInt(row.category_fit) || 0, competitor_brands: row.competitor_brands || [], })), }; } /** * Section 5: Competitive Landscape */ private async getCompetitiveLandscape( brandName: string, options: { start: Date; end: Date; stateCode?: string; category?: string } ): Promise { const { start, end, stateCode, category } = options; // Get brand's categories const categoriesResult = await this.pool.query(` SELECT DISTINCT category_raw FROM store_products WHERE brand_name_raw = $1 AND category_raw IS NOT NULL `, [brandName]); const brandCategories = categoriesResult.rows.map((r: any) => r.category_raw); // Get competitors (brands in same categories with store overlap) const competitorsResult = await this.pool.query(` WITH brand_stores AS ( SELECT DISTINCT dispensary_id FROM store_products WHERE brand_name_raw = $1 ), competitor_brands AS ( SELECT sp.brand_name_raw AS brand_name, COUNT(DISTINCT sp.dispensary_id) FILTER ( WHERE sp.dispensary_id IN (SELECT dispensary_id FROM brand_stores) ) AS overlapping_stores, COUNT(DISTINCT sp.dispensary_id) AS total_stores, AVG(sp.price_rec) AS avg_price, COUNT(*) AS sku_count FROM store_products sp WHERE sp.category_raw = ANY($2) AND sp.brand_name_raw != $1 AND sp.is_in_stock = TRUE GROUP BY sp.brand_name_raw HAVING COUNT(DISTINCT sp.dispensary_id) >= 3 ) SELECT brand_name, overlapping_stores, total_stores, ROUND(overlapping_stores::NUMERIC * 100 / NULLIF(total_stores, 0), 2) AS store_overlap_percent, avg_price, sku_count FROM competitor_brands ORDER BY overlapping_stores DESC LIMIT 20 `, [brandName, brandCategories]); // Head-to-head SKU comparison const headToHeadResult = await this.pool.query(` WITH brand_products AS ( SELECT sp.name_raw AS product_name, sp.category_raw, AVG(sp.price_rec) AS brand_price FROM store_products sp WHERE sp.brand_name_raw = $1 AND sp.is_in_stock = TRUE AND sp.price_rec IS NOT NULL GROUP BY sp.name_raw, sp.category_raw ), competitor_products AS ( SELECT sp.brand_name_raw AS competitor_brand, sp.category_raw, AVG(sp.price_rec) AS competitor_price FROM store_products sp WHERE sp.brand_name_raw != $1 AND sp.is_in_stock = TRUE AND sp.price_rec IS NOT NULL AND sp.category_raw IN (SELECT category_raw FROM brand_products) GROUP BY sp.brand_name_raw, sp.category_raw ) SELECT bp.product_name, bp.brand_price, cp.competitor_brand, cp.competitor_price, ROUND(((bp.brand_price - cp.competitor_price) / NULLIF(cp.competitor_price, 0) * 100)::NUMERIC, 2) AS price_diff_percent FROM brand_products bp JOIN competitor_products cp ON cp.category_raw = bp.category_raw ORDER BY ABS(bp.brand_price - cp.competitor_price) DESC LIMIT 20 `, [brandName]); // Market share trend over time const trendResult = await this.pool.query(` WITH daily_shares AS ( SELECT DATE(sps.captured_at) AS date, COUNT(*) FILTER (WHERE sps.brand_name_raw = $1) AS brand_skus, COUNT(*) AS total_skus FROM store_product_snapshots sps WHERE sps.captured_at >= $2 AND sps.captured_at <= $3 AND sps.is_in_stock = TRUE AND sps.category_raw = ANY($4) GROUP BY DATE(sps.captured_at) ) SELECT date, ROUND(brand_skus::NUMERIC * 100 / NULLIF(total_skus, 0), 2) AS share_percent FROM daily_shares ORDER BY date `, [brandName, start, end, brandCategories]); // Determine price position const avgPriceResult = await this.pool.query(` SELECT AVG(price_rec) AS avg_price FROM store_products WHERE brand_name_raw = $1 AND is_in_stock = TRUE AND price_rec IS NOT NULL `, [brandName]); const avgPrice = avgPriceResult.rows[0]?.avg_price ? parseFloat(avgPriceResult.rows[0].avg_price) : null; const pricePosition = await this.determinePricePosition(brandName, avgPrice, category); return { brand_price_position: pricePosition, market_share_trend: trendResult.rows.map((row: any) => ({ date: row.date.toISOString().split('T')[0], share_percent: parseFloat(row.share_percent) || 0, })), competitors: competitorsResult.rows.map((row: any) => ({ brand_name: row.brand_name, store_overlap_percent: parseFloat(row.store_overlap_percent) || 0, price_position: this.classifyPricePosition( row.avg_price ? parseFloat(row.avg_price) : null, avgPrice ), avg_price: row.avg_price ? parseFloat(row.avg_price) : null, sku_count: parseInt(row.sku_count) || 0, })), head_to_head_skus: headToHeadResult.rows.map((row: any) => ({ product_name: row.product_name, brand_price: parseFloat(row.brand_price), competitor_brand: row.competitor_brand, competitor_price: parseFloat(row.competitor_price), price_diff_percent: parseFloat(row.price_diff_percent) || 0, })), }; } /** * Section 6: Inventory Health */ private async getInventoryHealth( brandName: string, options: { start: Date; end: Date; stateCode?: string } ): Promise { const { start, end, stateCode } = options; // Calculate days of stock based on sell rate const inventoryResult = await this.pool.query(` WITH sku_qty_changes AS ( SELECT sps.store_product_id, sps.stock_quantity, sps.captured_at, LAG(sps.stock_quantity) OVER (PARTITION BY sps.store_product_id ORDER BY sps.captured_at) AS prev_qty FROM store_product_snapshots sps WHERE sps.brand_name_raw = $1 AND sps.captured_at >= $2 AND sps.captured_at <= $3 AND sps.stock_quantity IS NOT NULL ), sku_velocity AS ( SELECT store_product_id, SUM(GREATEST(0, COALESCE(prev_qty, 0) - stock_quantity)) AS units_sold, COUNT(DISTINCT DATE(captured_at)) AS days_tracked FROM sku_qty_changes WHERE prev_qty IS NOT NULL GROUP BY store_product_id ) SELECT sp.id AS store_product_id, sp.name_raw AS product_name, d.name AS store_name, sp.stock_quantity AS current_quantity, sv.units_sold, sv.days_tracked, CASE WHEN sv.days_tracked > 0 AND sv.units_sold > 0 THEN ROUND(sv.units_sold::NUMERIC / sv.days_tracked, 2) ELSE NULL END AS daily_sell_rate, CASE WHEN sv.days_tracked > 0 AND sv.units_sold > 0 AND sp.stock_quantity IS NOT NULL THEN ROUND(sp.stock_quantity::NUMERIC / (sv.units_sold::NUMERIC / sv.days_tracked), 0) ELSE NULL END AS days_of_stock FROM store_products sp JOIN dispensaries d ON d.id = sp.dispensary_id LEFT JOIN sku_velocity sv ON sv.store_product_id = sp.id WHERE sp.brand_name_raw = $1 AND sp.is_in_stock = TRUE AND sp.stock_quantity IS NOT NULL ORDER BY CASE WHEN sv.days_tracked > 0 AND sv.units_sold > 0 AND sp.stock_quantity IS NOT NULL THEN sp.stock_quantity::NUMERIC / (sv.units_sold::NUMERIC / sv.days_tracked) ELSE 9999 END ASC LIMIT 100 `, [brandName, start, end]); let criticalCount = 0; let warningCount = 0; let healthyCount = 0; let overstockedCount = 0; const skus: BrandIntelligenceResult['inventory_health']['skus'] = []; const overstockAlert: BrandIntelligenceResult['inventory_health']['overstock_alert'] = []; for (const row of inventoryResult.rows) { const daysOfStock = row.days_of_stock ? parseInt(row.days_of_stock) : null; let riskLevel: RiskLevel; if (daysOfStock === null) { riskLevel = 'moderate'; } else if (daysOfStock < 7) { riskLevel = 'critical'; criticalCount++; } else if (daysOfStock < 14) { riskLevel = 'elevated'; warningCount++; } else if (daysOfStock > 90) { riskLevel = 'healthy'; overstockedCount++; const dailySellRate = row.daily_sell_rate ? parseFloat(row.daily_sell_rate) : 0; const optimalStock = dailySellRate * 30; // 30 days optimal const excessUnits = Math.max(0, (row.current_quantity || 0) - optimalStock); if (excessUnits > 0) { overstockAlert.push({ product_name: row.product_name, store_name: row.store_name, excess_units: Math.round(excessUnits), days_of_stock: daysOfStock, }); } } else { riskLevel = 'healthy'; healthyCount++; } skus.push({ store_product_id: row.store_product_id, product_name: row.product_name, store_name: row.store_name, days_of_stock: daysOfStock, risk_level: riskLevel, current_quantity: row.current_quantity ? parseInt(row.current_quantity) : null, daily_sell_rate: row.daily_sell_rate ? parseFloat(row.daily_sell_rate) : null, }); } return { critical_count: criticalCount, warning_count: warningCount, healthy_count: healthyCount, overstocked_count: overstockedCount, skus, overstock_alert: overstockAlert.slice(0, 20), }; } /** * Section 7: Promotion Effectiveness */ private async getPromoPerformance( brandName: string, options: { start: Date; end: Date; stateCode?: string; category?: string } ): Promise { const { start, end, stateCode, category } = options; // Find promotional events with before/during velocity comparison const promoResult = await this.pool.query(` WITH promo_periods AS ( SELECT sps.store_product_id, MIN(sps.captured_at) AS promo_start, MAX(sps.captured_at) AS promo_end, AVG(sps.price_rec) AS regular_price, AVG(sps.price_rec_special) AS promo_price FROM store_product_snapshots sps WHERE sps.brand_name_raw = $1 AND sps.is_on_special = TRUE AND sps.captured_at >= $2 AND sps.captured_at <= $3 AND sps.price_rec_special IS NOT NULL GROUP BY sps.store_product_id ), baseline_qty_changes AS ( SELECT sps.store_product_id, sps.stock_quantity, sps.captured_at, LAG(sps.stock_quantity) OVER (PARTITION BY sps.store_product_id ORDER BY sps.captured_at) AS prev_qty FROM store_product_snapshots sps JOIN promo_periods pp ON pp.store_product_id = sps.store_product_id WHERE sps.brand_name_raw = $1 AND sps.captured_at < pp.promo_start AND sps.captured_at >= pp.promo_start - INTERVAL '14 days' AND sps.is_on_special = FALSE AND sps.stock_quantity IS NOT NULL ), baseline_velocity AS ( SELECT store_product_id, SUM(GREATEST(0, COALESCE(prev_qty, 0) - stock_quantity))::NUMERIC / NULLIF(COUNT(DISTINCT DATE(captured_at)), 0) AS daily_velocity FROM baseline_qty_changes WHERE prev_qty IS NOT NULL GROUP BY store_product_id ), promo_qty_changes AS ( SELECT sps.store_product_id, sps.stock_quantity, sps.captured_at, LAG(sps.stock_quantity) OVER (PARTITION BY sps.store_product_id ORDER BY sps.captured_at) AS prev_qty FROM store_product_snapshots sps JOIN promo_periods pp ON pp.store_product_id = sps.store_product_id WHERE sps.brand_name_raw = $1 AND sps.captured_at >= pp.promo_start AND sps.captured_at <= pp.promo_end AND sps.is_on_special = TRUE AND sps.stock_quantity IS NOT NULL ), promo_velocity AS ( SELECT store_product_id, SUM(GREATEST(0, COALESCE(prev_qty, 0) - stock_quantity))::NUMERIC / NULLIF(COUNT(DISTINCT DATE(captured_at)), 0) AS daily_velocity FROM promo_qty_changes WHERE prev_qty IS NOT NULL GROUP BY store_product_id ) SELECT sp.name_raw AS product_name, d.name AS store_name, pp.promo_start AS start_date, pp.promo_end AS end_date, pp.regular_price, pp.promo_price, ROUND(((pp.regular_price - pp.promo_price) / NULLIF(pp.regular_price, 0) * 100)::NUMERIC, 1) AS discount_percent, ROUND(bv.daily_velocity::NUMERIC, 2) AS baseline_velocity, ROUND(pv.daily_velocity::NUMERIC, 2) AS promo_velocity, CASE WHEN bv.daily_velocity > 0 THEN ROUND(((pv.daily_velocity - bv.daily_velocity) / bv.daily_velocity * 100)::NUMERIC, 1) ELSE NULL END AS velocity_lift, CASE WHEN pp.regular_price > 0 AND pp.promo_price > 0 AND bv.daily_velocity > 0 THEN ROUND(( (pv.daily_velocity - bv.daily_velocity) * pp.promo_price / (bv.daily_velocity * (pp.regular_price - pp.promo_price)) )::NUMERIC, 2) ELSE NULL END AS efficiency_score, CASE WHEN pp.promo_end >= NOW() - INTERVAL '1 day' THEN 'active' ELSE 'ended' END AS status FROM promo_periods pp JOIN store_products sp ON sp.id = pp.store_product_id JOIN dispensaries d ON d.id = sp.dispensary_id LEFT JOIN baseline_velocity bv ON bv.store_product_id = pp.store_product_id LEFT JOIN promo_velocity pv ON pv.store_product_id = pp.store_product_id ORDER BY pp.promo_end DESC LIMIT 50 `, [brandName, start, end]); // Calculate averages const validPromos = promoResult.rows.filter( (r: any) => r.baseline_velocity !== null && r.promo_velocity !== null ); const avgBaselineVelocity = validPromos.length > 0 ? validPromos.reduce((sum: number, r: any) => sum + parseFloat(r.baseline_velocity), 0) / validPromos.length : null; const avgPromoVelocity = validPromos.length > 0 ? validPromos.reduce((sum: number, r: any) => sum + parseFloat(r.promo_velocity), 0) / validPromos.length : null; const promosWithLift = validPromos.filter((r: any) => r.velocity_lift !== null); const avgVelocityLift = promosWithLift.length > 0 ? promosWithLift.reduce((sum: number, r: any) => sum + parseFloat(r.velocity_lift), 0) / promosWithLift.length : null; const promosWithEfficiency = validPromos.filter((r: any) => r.efficiency_score !== null); const avgEfficiencyScore = promosWithEfficiency.length > 0 ? promosWithEfficiency.reduce((sum: number, r: any) => sum + parseFloat(r.efficiency_score), 0) / promosWithEfficiency.length : null; return { avg_baseline_velocity: avgBaselineVelocity, avg_promo_velocity: avgPromoVelocity, avg_velocity_lift: avgVelocityLift, avg_efficiency_score: avgEfficiencyScore, promotions: promoResult.rows.map((row: any) => ({ product_name: row.product_name, store_name: row.store_name, status: row.status as PromoStatus, start_date: row.start_date?.toISOString().split('T')[0] || '', end_date: row.end_date?.toISOString().split('T')[0] || null, regular_price: parseFloat(row.regular_price) || 0, promo_price: parseFloat(row.promo_price) || 0, discount_percent: parseFloat(row.discount_percent) || 0, baseline_velocity: row.baseline_velocity ? parseFloat(row.baseline_velocity) : null, promo_velocity: row.promo_velocity ? parseFloat(row.promo_velocity) : null, velocity_lift: row.velocity_lift ? parseFloat(row.velocity_lift) : null, efficiency_score: row.efficiency_score ? parseFloat(row.efficiency_score) : null, })), }; } /** * Helper: Determine price position relative to category */ private async determinePricePosition( brandName: string, brandAvgPrice: number | null, category?: string ): Promise { if (brandAvgPrice === null) return 'competitive'; const categoryFilter = category ? 'AND sp.category_raw = $2' : ''; const params = category ? [brandName, category] : [brandName]; const result = await this.pool.query(` WITH brand_categories AS ( SELECT DISTINCT category_raw FROM store_products WHERE brand_name_raw = $1 AND category_raw IS NOT NULL ) SELECT AVG(sp.price_rec) AS category_avg_price FROM store_products sp WHERE sp.is_in_stock = TRUE AND sp.price_rec IS NOT NULL AND sp.category_raw IN (SELECT category_raw FROM brand_categories) ${categoryFilter} `, params); const categoryAvg = result.rows[0]?.category_avg_price ? parseFloat(result.rows[0].category_avg_price) : null; if (categoryAvg === null) return 'competitive'; const priceDiffPercent = ((brandAvgPrice - categoryAvg) / categoryAvg) * 100; if (priceDiffPercent > 15) return 'premium'; if (priceDiffPercent < -15) return 'value'; return 'competitive'; } /** * Helper: Classify a competitor's price position relative to brand */ private classifyPricePosition( competitorPrice: number | null, brandPrice: number | null ): PricePosition { if (competitorPrice === null || brandPrice === null) return 'competitive'; const priceDiffPercent = ((competitorPrice - brandPrice) / brandPrice) * 100; if (priceDiffPercent > 15) return 'premium'; if (priceDiffPercent < -15) return 'value'; return 'competitive'; } } export default BrandIntelligenceService;