From 197c82f921d77c322dc623e91eacafe4a2e62260 Mon Sep 17 00:00:00 2001 From: Kelly Date: Wed, 10 Dec 2025 12:18:10 -0700 Subject: [PATCH] fix: Join states through dispensaries in BrandPenetrationService MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit The store_products table doesn't have a state_id column - must join through dispensaries to get state info. Also fixed column references to use brand_name_raw and category_raw. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 --- .../analytics/BrandPenetrationService.ts | 65 +++++++++++-------- 1 file changed, 37 insertions(+), 28 deletions(-) diff --git a/backend/src/services/analytics/BrandPenetrationService.ts b/backend/src/services/analytics/BrandPenetrationService.ts index bce6e975..64aff02c 100644 --- a/backend/src/services/analytics/BrandPenetrationService.ts +++ b/backend/src/services/analytics/BrandPenetrationService.ts @@ -46,16 +46,17 @@ export class BrandPenetrationService { // Get current brand presence const currentResult = await this.pool.query(` SELECT - sp.brand_name, + 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 - LEFT JOIN states s ON s.id = sp.state_id - WHERE sp.brand_name = $1 + 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 + GROUP BY sp.brand_name_raw `, [brandName]); if (currentResult.rows.length === 0) { @@ -125,8 +126,9 @@ export class BrandPenetrationService { 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 + 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 ), @@ -135,7 +137,8 @@ export class BrandPenetrationService { 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 + 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 ) @@ -171,7 +174,7 @@ export class BrandPenetrationService { let filters = ''; if (options.category) { - filters += ` AND sp.category = $${paramIdx}`; + filters += ` AND sp.category_raw = $${paramIdx}`; params.push(options.category); paramIdx++; } @@ -185,31 +188,33 @@ export class BrandPenetrationService { const result = await this.pool.query(` WITH brand_metrics AS ( SELECT - sp.brand_name, - sp.category, + 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 states s ON s.id = sp.state_id - WHERE sp.brand_name = $1 + 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 IS NOT NULL + AND sp.category_raw IS NOT NULL ${filters} - GROUP BY sp.brand_name, sp.category, s.code + GROUP BY sp.brand_name_raw, sp.category_raw, s.code ), category_totals AS ( SELECT - sp.category, + 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 states s ON s.id = sp.state_id + 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 IS NOT NULL - GROUP BY sp.category, s.code + AND sp.category_raw IS NOT NULL + GROUP BY sp.category_raw, s.code ) SELECT bm.*, @@ -245,8 +250,9 @@ export class BrandPenetrationService { 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 + 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 ), @@ -257,8 +263,9 @@ export class BrandPenetrationService { 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 + 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) @@ -313,23 +320,24 @@ export class BrandPenetrationService { } if (category) { - filters += ` AND sp.category = $${paramIdx}`; + filters += ` AND sp.category_raw = $${paramIdx}`; params.push(category); paramIdx++; } const result = await this.pool.query(` SELECT - sp.brand_name, + 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 - LEFT JOIN states s ON s.id = sp.state_id - WHERE sp.brand_name IS NOT NULL + 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 + GROUP BY sp.brand_name_raw ORDER BY dispensary_count DESC, sku_count DESC LIMIT $1 `, params); @@ -460,7 +468,8 @@ export class BrandPenetrationService { ) AS prev_stock_quantity FROM store_product_snapshots sps JOIN store_products sp ON sp.id = sps.store_product_id - LEFT JOIN states s ON s.id = sp.state_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