/** * BrandPenetrationService * * Analytics for brand market presence and penetration trends. * * Data Sources: * - store_products: Current brand presence by dispensary * - store_product_snapshots: Historical brand tracking * - states: Rec/med segmentation * * Key Metrics: * - Dispensary count carrying brand (by state) * - SKU count per dispensary * - Market share within category * - Penetration trends over time * - Rec vs Med footprint comparison */ import { Pool } from 'pg'; import { TimeWindow, DateRange, getDateRangeFromWindow, BrandPenetrationResult, BrandStateBreakdown, PenetrationDataPoint, BrandMarketPosition, BrandRecVsMedFootprint, BrandPromotionalSummary, BrandPromotionalEvent, } from './types'; export class BrandPenetrationService { constructor(private pool: Pool) {} /** * Get brand penetration metrics */ async getBrandPenetration( brandName: string, options: { window?: TimeWindow; customRange?: DateRange } = {} ): Promise { const { window = '30d', customRange } = options; const { start, end } = getDateRangeFromWindow(window, customRange); // Get current brand presence const currentResult = await this.pool.query(` SELECT sp.brand_name_raw AS brand_name, COUNT(DISTINCT sp.dispensary_id) AS total_dispensaries, COUNT(*) AS total_skus, ROUND(COUNT(*)::NUMERIC / NULLIF(COUNT(DISTINCT sp.dispensary_id), 0), 2) AS avg_skus_per_dispensary, ARRAY_AGG(DISTINCT s.code) FILTER (WHERE s.code IS NOT NULL) AS states_present 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 GROUP BY sp.brand_name_raw `, [brandName]); if (currentResult.rows.length === 0) { return null; } const current = currentResult.rows[0]; // Get state breakdown const stateBreakdown = await this.getBrandStateBreakdown(brandName); // Get penetration trend const trendResult = await this.pool.query(` WITH daily_presence AS ( SELECT DATE(sps.captured_at) AS date, COUNT(DISTINCT sps.dispensary_id) AS dispensary_count FROM store_product_snapshots sps WHERE sps.brand_name_raw = $1 AND sps.captured_at >= $2 AND sps.captured_at <= $3 AND sps.is_in_stock = TRUE GROUP BY DATE(sps.captured_at) ORDER BY date ) SELECT date, dispensary_count, dispensary_count - LAG(dispensary_count) OVER (ORDER BY date) AS new_dispensaries FROM daily_presence `, [brandName, start, end]); const penetrationTrend: PenetrationDataPoint[] = trendResult.rows.map((row: any) => ({ date: row.date.toISOString().split('T')[0], dispensary_count: parseInt(row.dispensary_count), new_dispensaries: row.new_dispensaries ? parseInt(row.new_dispensaries) : 0, dropped_dispensaries: row.new_dispensaries && row.new_dispensaries < 0 ? Math.abs(parseInt(row.new_dispensaries)) : 0, })); return { brand_name: brandName, total_dispensaries: parseInt(current.total_dispensaries), total_skus: parseInt(current.total_skus), avg_skus_per_dispensary: parseFloat(current.avg_skus_per_dispensary) || 0, states_present: current.states_present || [], state_breakdown: stateBreakdown, penetration_trend: penetrationTrend, }; } /** * Get brand breakdown by state */ async getBrandStateBreakdown(brandName: string): Promise { const result = await this.pool.query(` WITH brand_state AS ( SELECT s.code AS state_code, s.name AS state_name, CASE WHEN s.recreational_legal = TRUE THEN 'recreational' WHEN s.medical_legal = TRUE THEN 'medical_only' ELSE 'no_program' END AS legal_type, COUNT(DISTINCT sp.dispensary_id) AS dispensary_count, COUNT(*) AS sku_count 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 AND sp.is_in_stock = TRUE GROUP BY s.code, s.name, s.recreational_legal, s.medical_legal ), state_totals AS ( SELECT s.code AS state_code, COUNT(DISTINCT sp.dispensary_id) AS total_dispensaries FROM store_products sp JOIN dispensaries d ON d.id = sp.dispensary_id JOIN states s ON s.id = d.state_id WHERE sp.is_in_stock = TRUE GROUP BY s.code ) SELECT bs.*, ROUND(bs.sku_count::NUMERIC / NULLIF(bs.dispensary_count, 0), 2) AS avg_skus_per_dispensary, ROUND(bs.dispensary_count::NUMERIC * 100 / NULLIF(st.total_dispensaries, 0), 2) AS market_share_percent FROM brand_state bs LEFT JOIN state_totals st ON st.state_code = bs.state_code ORDER BY bs.dispensary_count DESC `, [brandName]); return result.rows.map((row: any) => ({ state_code: row.state_code, state_name: row.state_name, legal_type: row.legal_type, dispensary_count: parseInt(row.dispensary_count), sku_count: parseInt(row.sku_count), avg_skus_per_dispensary: parseFloat(row.avg_skus_per_dispensary) || 0, market_share_percent: row.market_share_percent ? parseFloat(row.market_share_percent) : null, })); } /** * Get brand market position within a category */ async getBrandMarketPosition( brandName: string, options: { category?: string; stateCode?: string } = {} ): Promise { const params: any[] = [brandName]; let paramIdx = 2; let filters = ''; if (options.category) { filters += ` AND sp.category_raw = $${paramIdx}`; params.push(options.category); paramIdx++; } if (options.stateCode) { filters += ` AND s.code = $${paramIdx}`; params.push(options.stateCode); paramIdx++; } const result = await this.pool.query(` WITH brand_metrics AS ( SELECT sp.brand_name_raw AS brand_name, sp.category_raw AS category, s.code AS state_code, COUNT(*) AS sku_count, COUNT(DISTINCT sp.dispensary_id) AS dispensary_count, AVG(sp.price_rec) AS avg_price 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 AND sp.is_in_stock = TRUE AND sp.category_raw IS NOT NULL ${filters} GROUP BY sp.brand_name_raw, sp.category_raw, s.code ), category_totals AS ( SELECT sp.category_raw AS category, s.code AS state_code, COUNT(*) AS total_skus, AVG(sp.price_rec) AS category_avg_price FROM store_products sp JOIN dispensaries d ON d.id = sp.dispensary_id JOIN states s ON s.id = d.state_id WHERE sp.is_in_stock = TRUE AND sp.category_raw IS NOT NULL GROUP BY sp.category_raw, s.code ) SELECT bm.*, ROUND(bm.sku_count::NUMERIC * 100 / NULLIF(ct.total_skus, 0), 2) AS category_share_percent, ct.category_avg_price, ROUND((bm.avg_price - ct.category_avg_price) / NULLIF(ct.category_avg_price, 0) * 100, 2) AS price_vs_category_avg FROM brand_metrics bm LEFT JOIN category_totals ct ON ct.category = bm.category AND ct.state_code = bm.state_code ORDER BY bm.sku_count DESC `, params); return result.rows.map((row: any) => ({ brand_name: row.brand_name, category: row.category, state_code: row.state_code, sku_count: parseInt(row.sku_count), dispensary_count: parseInt(row.dispensary_count), category_share_percent: row.category_share_percent ? parseFloat(row.category_share_percent) : 0, avg_price: row.avg_price ? parseFloat(row.avg_price) : null, price_vs_category_avg: row.price_vs_category_avg ? parseFloat(row.price_vs_category_avg) : null, })); } /** * Get brand presence in rec vs med-only states */ async getBrandRecVsMedFootprint(brandName: string): Promise { const result = await this.pool.query(` WITH rec_presence AS ( SELECT COUNT(DISTINCT s.code) AS state_count, ARRAY_AGG(DISTINCT s.code) AS states, COUNT(DISTINCT sp.dispensary_id) AS dispensary_count, ROUND(COUNT(*)::NUMERIC / NULLIF(COUNT(DISTINCT sp.dispensary_id), 0), 2) AS avg_skus 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 AND sp.is_in_stock = TRUE AND s.recreational_legal = TRUE ), med_presence AS ( SELECT COUNT(DISTINCT s.code) AS state_count, ARRAY_AGG(DISTINCT s.code) AS states, COUNT(DISTINCT sp.dispensary_id) AS dispensary_count, ROUND(COUNT(*)::NUMERIC / NULLIF(COUNT(DISTINCT sp.dispensary_id), 0), 2) AS avg_skus 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 AND sp.is_in_stock = TRUE AND s.medical_legal = TRUE AND (s.recreational_legal = FALSE OR s.recreational_legal IS NULL) ) SELECT rp.state_count AS rec_states_count, rp.states AS rec_states, rp.dispensary_count AS rec_dispensary_count, rp.avg_skus AS rec_avg_skus, mp.state_count AS med_only_states_count, mp.states AS med_only_states, mp.dispensary_count AS med_only_dispensary_count, mp.avg_skus AS med_only_avg_skus FROM rec_presence rp, med_presence mp `, [brandName]); const row = result.rows[0]; return { brand_name: brandName, rec_states_count: parseInt(row.rec_states_count) || 0, rec_states: row.rec_states || [], rec_dispensary_count: parseInt(row.rec_dispensary_count) || 0, rec_avg_skus: parseFloat(row.rec_avg_skus) || 0, med_only_states_count: parseInt(row.med_only_states_count) || 0, med_only_states: row.med_only_states || [], med_only_dispensary_count: parseInt(row.med_only_dispensary_count) || 0, med_only_avg_skus: parseFloat(row.med_only_avg_skus) || 0, }; } /** * Get top brands by penetration */ async getTopBrandsByPenetration( options: { limit?: number; stateCode?: string; category?: string } = {} ): Promise> { const { limit = 25, stateCode, category } = options; const params: any[] = [limit]; 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++; } const result = await this.pool.query(` SELECT sp.brand_name_raw AS brand_name, COUNT(DISTINCT sp.dispensary_id) AS dispensary_count, COUNT(*) AS sku_count, COUNT(DISTINCT s.code) AS state_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 AND sp.is_in_stock = TRUE ${filters} GROUP BY sp.brand_name_raw ORDER BY dispensary_count DESC, sku_count DESC LIMIT $1 `, params); return result.rows.map((row: any) => ({ brand_name: row.brand_name, dispensary_count: parseInt(row.dispensary_count), sku_count: parseInt(row.sku_count), state_count: parseInt(row.state_count), })); } /** * Get brands that have expanded/contracted in the window */ async getBrandExpansionContraction( options: { window?: TimeWindow; customRange?: DateRange; limit?: number } = {} ): Promise> { const { window = '30d', customRange, limit = 25 } = options; const { start, end } = getDateRangeFromWindow(window, customRange); const result = await this.pool.query(` WITH start_counts AS ( SELECT brand_name_raw AS brand_name, COUNT(DISTINCT dispensary_id) AS dispensary_count FROM store_product_snapshots WHERE captured_at >= $1 AND captured_at < $1 + INTERVAL '1 day' AND brand_name_raw IS NOT NULL AND is_in_stock = TRUE GROUP BY brand_name_raw ), end_counts AS ( SELECT brand_name_raw AS brand_name, COUNT(DISTINCT dispensary_id) AS dispensary_count FROM store_product_snapshots WHERE captured_at >= $2 - INTERVAL '1 day' AND captured_at <= $2 AND brand_name_raw IS NOT NULL AND is_in_stock = TRUE GROUP BY brand_name_raw ) SELECT COALESCE(sc.brand_name, ec.brand_name) AS brand_name, COALESCE(sc.dispensary_count, 0) AS start_dispensaries, COALESCE(ec.dispensary_count, 0) AS end_dispensaries, COALESCE(ec.dispensary_count, 0) - COALESCE(sc.dispensary_count, 0) AS change, ROUND( (COALESCE(ec.dispensary_count, 0) - COALESCE(sc.dispensary_count, 0))::NUMERIC * 100 / NULLIF(COALESCE(sc.dispensary_count, 0), 0), 2 ) AS change_percent FROM start_counts sc FULL OUTER JOIN end_counts ec ON ec.brand_name = sc.brand_name WHERE COALESCE(ec.dispensary_count, 0) != COALESCE(sc.dispensary_count, 0) ORDER BY ABS(COALESCE(ec.dispensary_count, 0) - COALESCE(sc.dispensary_count, 0)) DESC LIMIT $3 `, [start, end, limit]); return result.rows.map((row: any) => ({ brand_name: row.brand_name, start_dispensaries: parseInt(row.start_dispensaries), end_dispensaries: parseInt(row.end_dispensaries), change: parseInt(row.change), change_percent: row.change_percent ? parseFloat(row.change_percent) : 0, })); } /** * Get brand promotional history * * Tracks when products went on special, how long, what discount, * and estimated quantity sold during the promotion. */ async getBrandPromotionalHistory( brandName: string, options: { window?: TimeWindow; customRange?: DateRange; stateCode?: string; category?: string } = {} ): Promise { const { window = '90d', customRange, stateCode, category } = options; const { start, end } = getDateRangeFromWindow(window, customRange); // Build filters 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++; } // Find promotional events by detecting when is_on_special transitions to TRUE // and tracking until it transitions back to FALSE const eventsResult = await this.pool.query(` WITH snapshot_with_lag AS ( SELECT sps.id, sps.store_product_id, sps.dispensary_id, sps.brand_name_raw, sps.name_raw, sps.category_raw, sps.is_on_special, sps.price_rec, sps.price_rec_special, sps.stock_quantity, sps.captured_at, LAG(sps.is_on_special) OVER ( PARTITION BY sps.store_product_id ORDER BY sps.captured_at ) AS prev_is_on_special, LAG(sps.stock_quantity) OVER ( PARTITION BY sps.store_product_id ORDER BY sps.captured_at ) AS prev_stock_quantity FROM store_product_snapshots sps JOIN store_products sp ON sp.id = sps.store_product_id JOIN dispensaries dd ON dd.id = sp.dispensary_id LEFT JOIN states s ON s.id = dd.state_id WHERE sps.brand_name_raw = $1 AND sps.captured_at >= $2 AND sps.captured_at <= $3 ${filters} ), special_starts AS ( -- Find when specials START (transition from not-on-special to on-special) SELECT store_product_id, dispensary_id, name_raw, category_raw, captured_at AS special_start, price_rec AS regular_price, price_rec_special AS special_price, stock_quantity AS quantity_at_start FROM snapshot_with_lag WHERE is_on_special = TRUE AND (prev_is_on_special = FALSE OR prev_is_on_special IS NULL) AND price_rec_special IS NOT NULL AND price_rec IS NOT NULL ), special_ends AS ( -- Find when specials END (transition from on-special to not-on-special) SELECT store_product_id, captured_at AS special_end, prev_stock_quantity AS quantity_at_end FROM snapshot_with_lag WHERE is_on_special = FALSE AND prev_is_on_special = TRUE ), matched_events AS ( SELECT ss.store_product_id, ss.dispensary_id, ss.name_raw AS product_name, ss.category_raw AS category, ss.special_start, se.special_end, ss.regular_price, ss.special_price, ss.quantity_at_start, COALESCE(se.quantity_at_end, ss.quantity_at_start) AS quantity_at_end FROM special_starts ss LEFT JOIN special_ends se ON se.store_product_id = ss.store_product_id AND se.special_end > ss.special_start AND se.special_end = ( SELECT MIN(se2.special_end) FROM special_ends se2 WHERE se2.store_product_id = ss.store_product_id AND se2.special_end > ss.special_start ) ) SELECT me.store_product_id, me.dispensary_id, d.name AS dispensary_name, s.code AS state_code, me.product_name, me.category, me.special_start, me.special_end, EXTRACT(DAY FROM COALESCE(me.special_end, NOW()) - me.special_start)::INT AS duration_days, me.regular_price, me.special_price, ROUND(((me.regular_price - me.special_price) / NULLIF(me.regular_price, 0)) * 100, 1) AS discount_percent, me.quantity_at_start, me.quantity_at_end, GREATEST(0, COALESCE(me.quantity_at_start, 0) - COALESCE(me.quantity_at_end, 0)) AS quantity_sold_estimate FROM matched_events me JOIN dispensaries d ON d.id = me.dispensary_id LEFT JOIN states s ON s.id = d.state_id ORDER BY me.special_start DESC `, params); const events: BrandPromotionalEvent[] = eventsResult.rows.map((row: any) => ({ product_name: row.product_name, store_product_id: parseInt(row.store_product_id), dispensary_id: parseInt(row.dispensary_id), dispensary_name: row.dispensary_name, state_code: row.state_code || 'Unknown', category: row.category, special_start: row.special_start.toISOString().split('T')[0], special_end: row.special_end ? row.special_end.toISOString().split('T')[0] : null, duration_days: row.duration_days ? parseInt(row.duration_days) : null, regular_price: parseFloat(row.regular_price) || 0, special_price: parseFloat(row.special_price) || 0, discount_percent: parseFloat(row.discount_percent) || 0, quantity_at_start: row.quantity_at_start ? parseInt(row.quantity_at_start) : null, quantity_at_end: row.quantity_at_end ? parseInt(row.quantity_at_end) : null, quantity_sold_estimate: row.quantity_sold_estimate ? parseInt(row.quantity_sold_estimate) : null, })); // Calculate summary stats const totalEvents = events.length; const uniqueProducts = new Set(events.map(e => e.store_product_id)).size; const uniqueDispensaries = new Set(events.map(e => e.dispensary_id)).size; const uniqueStates = [...new Set(events.map(e => e.state_code))]; const avgDiscount = totalEvents > 0 ? events.reduce((sum, e) => sum + e.discount_percent, 0) / totalEvents : 0; const durations = events.filter(e => e.duration_days !== null).map(e => e.duration_days!); const avgDuration = durations.length > 0 ? durations.reduce((sum, d) => sum + d, 0) / durations.length : null; const totalQuantitySold = events .filter(e => e.quantity_sold_estimate !== null) .reduce((sum, e) => sum + (e.quantity_sold_estimate || 0), 0); // Calculate frequency const windowDays = Math.ceil((end.getTime() - start.getTime()) / (1000 * 60 * 60 * 24)); const weeklyAvg = windowDays > 0 ? (totalEvents / windowDays) * 7 : 0; const monthlyAvg = windowDays > 0 ? (totalEvents / windowDays) * 30 : 0; // Group by category const categoryMap = new Map(); for (const event of events) { const cat = event.category || 'Uncategorized'; if (!categoryMap.has(cat)) { categoryMap.set(cat, { count: 0, discounts: [], quantity: 0 }); } const entry = categoryMap.get(cat)!; entry.count++; entry.discounts.push(event.discount_percent); if (event.quantity_sold_estimate !== null) { entry.quantity += event.quantity_sold_estimate; } } const byCategory = Array.from(categoryMap.entries()).map(([category, data]) => ({ category, event_count: data.count, avg_discount_percent: data.discounts.length > 0 ? Math.round((data.discounts.reduce((a, b) => a + b, 0) / data.discounts.length) * 10) / 10 : 0, quantity_sold_estimate: data.quantity > 0 ? data.quantity : null, })).sort((a, b) => b.event_count - a.event_count); return { brand_name: brandName, window, total_promotional_events: totalEvents, total_products_on_special: uniqueProducts, total_dispensaries_with_specials: uniqueDispensaries, states_with_specials: uniqueStates, avg_discount_percent: Math.round(avgDiscount * 10) / 10, avg_duration_days: avgDuration !== null ? Math.round(avgDuration * 10) / 10 : null, total_quantity_sold_estimate: totalQuantitySold > 0 ? totalQuantitySold : null, promotional_frequency: { weekly_avg: Math.round(weeklyAvg * 10) / 10, monthly_avg: Math.round(monthlyAvg * 10) / 10, }, by_category: byCategory, events, }; } } export default BrandPenetrationService;