feat(api): Add /api/brands/:brand/stores/performance endpoint
Some checks failed
ci/woodpecker/push/woodpecker Pipeline failed
Some checks failed
ci/woodpecker/push/woodpecker Pipeline failed
Add comprehensive per-store performance endpoint for Cannabrands integration. Returns all metrics in one call for easy merging with internal order data. Response includes per store: - active_skus, oos_skus, total_skus, oos_pct - avg_daily_units (velocity from inventory deltas) - avg_days_on_hand (stock / daily velocity) - total_sales_est (units × price × days) - lost_opportunity (OOS days × velocity × price) - categories breakdown (JSON object) - avg_price, total_stock Query params: ?days=28&state=AZ&limit=100&offset=0 Matches Hoodie Analytics columns for Order Management view. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
@@ -696,6 +696,228 @@ export function createBrandsRouter(pool: Pool): Router {
|
|||||||
}
|
}
|
||||||
});
|
});
|
||||||
|
|
||||||
|
/**
|
||||||
|
* GET /:brand/stores/performance
|
||||||
|
* Get comprehensive per-store performance metrics for a brand
|
||||||
|
* Returns all metrics in one call for easy merging with internal data
|
||||||
|
*
|
||||||
|
* Designed for Cannabrands integration - matches Hoodie Analytics columns
|
||||||
|
*/
|
||||||
|
router.get('/:brand/stores/performance', 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 limit = parseLimit(req.query.limit as string, 100);
|
||||||
|
const offset = parseOffset(req.query.offset as string);
|
||||||
|
|
||||||
|
const startDate = new Date();
|
||||||
|
startDate.setDate(startDate.getDate() - days);
|
||||||
|
|
||||||
|
// Build state filter
|
||||||
|
const stateFilter = stateCode ? 'AND s.code = $4' : '';
|
||||||
|
const params = stateCode
|
||||||
|
? [brandName, startDate, limit, stateCode, offset]
|
||||||
|
: [brandName, startDate, limit, offset];
|
||||||
|
const offsetParam = stateCode ? '$5' : '$4';
|
||||||
|
|
||||||
|
const result = await pool.query(`
|
||||||
|
WITH brand_store_products AS (
|
||||||
|
-- Get all products for this brand at each store
|
||||||
|
SELECT
|
||||||
|
sp.dispensary_id,
|
||||||
|
sp.id AS store_product_id,
|
||||||
|
sp.name_raw AS product_name,
|
||||||
|
sp.category_raw AS category,
|
||||||
|
sp.is_in_stock,
|
||||||
|
sp.stock_quantity,
|
||||||
|
sp.price_rec,
|
||||||
|
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
|
||||||
|
${stateFilter}
|
||||||
|
),
|
||||||
|
store_sku_counts AS (
|
||||||
|
-- Count SKUs per store
|
||||||
|
SELECT
|
||||||
|
dispensary_id,
|
||||||
|
COUNT(*) AS total_skus,
|
||||||
|
COUNT(*) FILTER (WHERE is_in_stock = TRUE) AS active_skus,
|
||||||
|
COUNT(*) FILTER (WHERE is_in_stock = FALSE) AS oos_skus,
|
||||||
|
AVG(price_rec) AS avg_price,
|
||||||
|
SUM(stock_quantity) AS total_stock
|
||||||
|
FROM brand_store_products
|
||||||
|
GROUP BY dispensary_id
|
||||||
|
),
|
||||||
|
store_velocity AS (
|
||||||
|
-- Calculate velocity from snapshots
|
||||||
|
SELECT
|
||||||
|
sp.dispensary_id,
|
||||||
|
SUM(GREATEST(0, COALESCE(
|
||||||
|
LAG(sps.stock_quantity) OVER (PARTITION BY sps.store_product_id ORDER BY sps.captured_at),
|
||||||
|
0
|
||||||
|
) - sps.stock_quantity)) AS units_sold,
|
||||||
|
COUNT(DISTINCT DATE(sps.captured_at)) AS days_tracked
|
||||||
|
FROM store_product_snapshots sps
|
||||||
|
JOIN store_products sp ON sp.id = sps.store_product_id
|
||||||
|
WHERE sps.brand_name_raw = $1
|
||||||
|
AND sps.captured_at >= $2
|
||||||
|
AND sps.stock_quantity IS NOT NULL
|
||||||
|
GROUP BY sp.dispensary_id
|
||||||
|
),
|
||||||
|
store_days_on_hand AS (
|
||||||
|
-- Calculate average days on hand per store
|
||||||
|
SELECT
|
||||||
|
sp.dispensary_id,
|
||||||
|
AVG(
|
||||||
|
CASE
|
||||||
|
WHEN sv.days_tracked > 0 AND sv.units_sold > 0 AND sp.stock_quantity IS NOT NULL
|
||||||
|
THEN sp.stock_quantity::NUMERIC / NULLIF(sv.units_sold::NUMERIC / sv.days_tracked, 0)
|
||||||
|
ELSE NULL
|
||||||
|
END
|
||||||
|
) AS avg_days_on_hand
|
||||||
|
FROM brand_store_products sp
|
||||||
|
LEFT JOIN store_velocity sv ON sv.dispensary_id = sp.dispensary_id
|
||||||
|
WHERE sp.is_in_stock = TRUE
|
||||||
|
GROUP BY sp.dispensary_id
|
||||||
|
),
|
||||||
|
store_categories AS (
|
||||||
|
-- Get category breakdown per store
|
||||||
|
SELECT
|
||||||
|
dispensary_id,
|
||||||
|
jsonb_object_agg(
|
||||||
|
COALESCE(category, 'Other'),
|
||||||
|
cat_count
|
||||||
|
) AS categories
|
||||||
|
FROM (
|
||||||
|
SELECT
|
||||||
|
dispensary_id,
|
||||||
|
category,
|
||||||
|
COUNT(*) AS cat_count
|
||||||
|
FROM brand_store_products
|
||||||
|
WHERE is_in_stock = TRUE
|
||||||
|
GROUP BY dispensary_id, category
|
||||||
|
) sub
|
||||||
|
GROUP BY dispensary_id
|
||||||
|
),
|
||||||
|
store_lost_opportunity AS (
|
||||||
|
-- Estimate lost opportunity (OOS days × avg velocity × avg price)
|
||||||
|
SELECT
|
||||||
|
sp.dispensary_id,
|
||||||
|
SUM(
|
||||||
|
CASE
|
||||||
|
WHEN sp.is_in_stock = FALSE AND sv.days_tracked > 0 AND sv.units_sold > 0
|
||||||
|
THEN (
|
||||||
|
EXTRACT(DAY FROM NOW() - sp.last_seen_at) *
|
||||||
|
(sv.units_sold::NUMERIC / sv.days_tracked) *
|
||||||
|
COALESCE(sp.price_rec, 0)
|
||||||
|
)
|
||||||
|
ELSE 0
|
||||||
|
END
|
||||||
|
) AS lost_opportunity
|
||||||
|
FROM brand_store_products sp
|
||||||
|
LEFT JOIN store_velocity sv ON sv.dispensary_id = sp.dispensary_id
|
||||||
|
GROUP BY sp.dispensary_id
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
d.id AS store_id,
|
||||||
|
d.name AS store_name,
|
||||||
|
s.code AS state_code,
|
||||||
|
d.city,
|
||||||
|
d.address,
|
||||||
|
COALESCE(ssc.active_skus, 0) AS active_skus,
|
||||||
|
COALESCE(ssc.oos_skus, 0) AS oos_skus,
|
||||||
|
COALESCE(ssc.total_skus, 0) AS total_skus,
|
||||||
|
CASE
|
||||||
|
WHEN COALESCE(ssc.total_skus, 0) > 0
|
||||||
|
THEN ROUND(ssc.oos_skus::NUMERIC * 100 / ssc.total_skus, 0)
|
||||||
|
ELSE 0
|
||||||
|
END AS oos_pct,
|
||||||
|
CASE
|
||||||
|
WHEN COALESCE(sv.days_tracked, 0) > 0
|
||||||
|
THEN ROUND(sv.units_sold::NUMERIC / sv.days_tracked, 1)
|
||||||
|
ELSE NULL
|
||||||
|
END AS avg_daily_units,
|
||||||
|
ROUND(sdoh.avg_days_on_hand, 1) AS avg_days_on_hand,
|
||||||
|
CASE
|
||||||
|
WHEN COALESCE(sv.days_tracked, 0) > 0
|
||||||
|
THEN ROUND(sv.units_sold::NUMERIC / sv.days_tracked * ssc.avg_price * $3, 2)
|
||||||
|
ELSE NULL
|
||||||
|
END AS total_sales_est,
|
||||||
|
ROUND(slo.lost_opportunity, 2) AS lost_opportunity,
|
||||||
|
ssc.avg_price,
|
||||||
|
ssc.total_stock,
|
||||||
|
sc.categories
|
||||||
|
FROM dispensaries d
|
||||||
|
LEFT JOIN states s ON s.id = d.state_id
|
||||||
|
JOIN store_sku_counts ssc ON ssc.dispensary_id = d.id
|
||||||
|
LEFT JOIN store_velocity sv ON sv.dispensary_id = d.id
|
||||||
|
LEFT JOIN store_days_on_hand sdoh ON sdoh.dispensary_id = d.id
|
||||||
|
LEFT JOIN store_categories sc ON sc.dispensary_id = d.id
|
||||||
|
LEFT JOIN store_lost_opportunity slo ON slo.dispensary_id = d.id
|
||||||
|
ORDER BY ssc.active_skus DESC
|
||||||
|
LIMIT $3 OFFSET ${offsetParam}
|
||||||
|
`, params);
|
||||||
|
|
||||||
|
// Get totals for header stats
|
||||||
|
const totalsResult = await pool.query(`
|
||||||
|
SELECT
|
||||||
|
COUNT(DISTINCT sp.dispensary_id) AS total_stores,
|
||||||
|
COUNT(*) FILTER (WHERE sp.is_in_stock = FALSE) AS total_oos
|
||||||
|
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
|
||||||
|
${stateFilter}
|
||||||
|
`, stateCode ? [brandName, stateCode] : [brandName]);
|
||||||
|
|
||||||
|
const totals = totalsResult.rows[0] || {};
|
||||||
|
|
||||||
|
res.json({
|
||||||
|
brand: brandName,
|
||||||
|
period_days: days,
|
||||||
|
state: stateCode || 'all',
|
||||||
|
summary: {
|
||||||
|
total_stores: parseInt(totals.total_stores) || 0,
|
||||||
|
total_oos: parseInt(totals.total_oos) || 0,
|
||||||
|
},
|
||||||
|
stores: result.rows.map(row => ({
|
||||||
|
store_id: row.store_id,
|
||||||
|
store_name: row.store_name,
|
||||||
|
state_code: row.state_code,
|
||||||
|
city: row.city,
|
||||||
|
address: row.address,
|
||||||
|
// SKU counts
|
||||||
|
active_skus: parseInt(row.active_skus) || 0,
|
||||||
|
oos_skus: parseInt(row.oos_skus) || 0,
|
||||||
|
total_skus: parseInt(row.total_skus) || 0,
|
||||||
|
oos_pct: parseInt(row.oos_pct) || 0,
|
||||||
|
// Velocity & Sales
|
||||||
|
avg_daily_units: row.avg_daily_units ? parseFloat(row.avg_daily_units) : null,
|
||||||
|
total_sales_est: row.total_sales_est ? parseFloat(row.total_sales_est) : null,
|
||||||
|
// Inventory
|
||||||
|
avg_days_on_hand: row.avg_days_on_hand ? parseFloat(row.avg_days_on_hand) : null,
|
||||||
|
total_stock: row.total_stock ? parseInt(row.total_stock) : null,
|
||||||
|
// Pricing
|
||||||
|
avg_price: row.avg_price ? parseFloat(row.avg_price).toFixed(2) : null,
|
||||||
|
// Opportunities
|
||||||
|
lost_opportunity: row.lost_opportunity ? parseFloat(row.lost_opportunity) : null,
|
||||||
|
// Categories breakdown
|
||||||
|
categories: row.categories || {},
|
||||||
|
})),
|
||||||
|
pagination: {
|
||||||
|
limit,
|
||||||
|
offset,
|
||||||
|
},
|
||||||
|
});
|
||||||
|
} catch (error) {
|
||||||
|
console.error('[Brands] Stores performance error:', error);
|
||||||
|
res.status(500).json({ error: 'Failed to fetch store performance' });
|
||||||
|
}
|
||||||
|
});
|
||||||
|
|
||||||
/**
|
/**
|
||||||
* GET /:brand/gaps
|
* GET /:brand/gaps
|
||||||
* Get stores NOT carrying brand (whitespace opportunities)
|
* Get stores NOT carrying brand (whitespace opportunities)
|
||||||
|
|||||||
Reference in New Issue
Block a user