feat: Add v2 architecture with multi-state support and orchestrator services
Major additions: - Multi-state expansion: states table, StateSelector, NationalDashboard, StateHeatmap, CrossStateCompare - Orchestrator services: trace service, error taxonomy, retry manager, proxy rotator - Discovery system: dutchie discovery service, geo validation, city seeding scripts - Analytics infrastructure: analytics v2 routes, brand/pricing/stores intelligence pages - Local development: setup-local.sh starts all 5 services (postgres, backend, cannaiq, findadispo, findagram) - Migrations 037-056: crawler profiles, states, analytics indexes, worker metadata Frontend pages added: - Discovery, ChainsDashboard, IntelligenceBrands, IntelligencePricing, IntelligenceStores - StateHeatmap, CrossStateCompare, SyncInfoPanel Components added: - StateSelector, OrchestratorTraceModal, WorkflowStepper 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
406
backend/src/services/analytics/BrandPenetrationService.ts
Normal file
406
backend/src/services/analytics/BrandPenetrationService.ts
Normal file
@@ -0,0 +1,406 @@
|
||||
/**
|
||||
* 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,
|
||||
} from './types';
|
||||
|
||||
export class BrandPenetrationService {
|
||||
constructor(private pool: Pool) {}
|
||||
|
||||
/**
|
||||
* Get brand penetration metrics
|
||||
*/
|
||||
async getBrandPenetration(
|
||||
brandName: string,
|
||||
options: { window?: TimeWindow; customRange?: DateRange } = {}
|
||||
): Promise<BrandPenetrationResult | null> {
|
||||
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,
|
||||
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
|
||||
LEFT JOIN states s ON s.id = sp.state_id
|
||||
WHERE sp.brand_name = $1
|
||||
AND sp.is_in_stock = TRUE
|
||||
GROUP BY sp.brand_name
|
||||
`, [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 = $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<BrandStateBreakdown[]> {
|
||||
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 states s ON s.id = sp.state_id
|
||||
WHERE sp.brand_name = $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 states s ON s.id = sp.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<BrandMarketPosition[]> {
|
||||
const params: any[] = [brandName];
|
||||
let paramIdx = 2;
|
||||
let filters = '';
|
||||
|
||||
if (options.category) {
|
||||
filters += ` AND sp.category = $${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,
|
||||
sp.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 states s ON s.id = sp.state_id
|
||||
WHERE sp.brand_name = $1
|
||||
AND sp.is_in_stock = TRUE
|
||||
AND sp.category IS NOT NULL
|
||||
${filters}
|
||||
GROUP BY sp.brand_name, sp.category, s.code
|
||||
),
|
||||
category_totals AS (
|
||||
SELECT
|
||||
sp.category,
|
||||
s.code AS state_code,
|
||||
COUNT(*) AS total_skus,
|
||||
AVG(sp.price_rec) AS category_avg_price
|
||||
FROM store_products sp
|
||||
JOIN states s ON s.id = sp.state_id
|
||||
WHERE sp.is_in_stock = TRUE
|
||||
AND sp.category IS NOT NULL
|
||||
GROUP BY sp.category, 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<BrandRecVsMedFootprint> {
|
||||
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 states s ON s.id = sp.state_id
|
||||
WHERE sp.brand_name = $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 states s ON s.id = sp.state_id
|
||||
WHERE sp.brand_name = $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<Array<{
|
||||
brand_name: string;
|
||||
dispensary_count: number;
|
||||
sku_count: number;
|
||||
state_count: number;
|
||||
}>> {
|
||||
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 = $${paramIdx}`;
|
||||
params.push(category);
|
||||
paramIdx++;
|
||||
}
|
||||
|
||||
const result = await this.pool.query(`
|
||||
SELECT
|
||||
sp.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
|
||||
LEFT JOIN states s ON s.id = sp.state_id
|
||||
WHERE sp.brand_name IS NOT NULL
|
||||
AND sp.is_in_stock = TRUE
|
||||
${filters}
|
||||
GROUP BY sp.brand_name
|
||||
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<Array<{
|
||||
brand_name: string;
|
||||
start_dispensaries: number;
|
||||
end_dispensaries: number;
|
||||
change: number;
|
||||
change_percent: number;
|
||||
}>> {
|
||||
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,
|
||||
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 IS NOT NULL
|
||||
AND is_in_stock = TRUE
|
||||
GROUP BY brand_name
|
||||
),
|
||||
end_counts AS (
|
||||
SELECT
|
||||
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 IS NOT NULL
|
||||
AND is_in_stock = TRUE
|
||||
GROUP BY brand_name
|
||||
)
|
||||
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,
|
||||
}));
|
||||
}
|
||||
}
|
||||
|
||||
export default BrandPenetrationService;
|
||||
Reference in New Issue
Block a user