feat(analytics): Brand promotional history + specials fix + API key editing
- Add brand promotional history endpoint (GET /api/analytics/v2/brand/:name/promotions) - Tracks when products go on special, duration, discounts, quantity sold estimates - Aggregates by category with frequency metrics (weekly/monthly) - Add quantity changes endpoint (GET /api/analytics/v2/store/:id/quantity-changes) - Filter by direction (increase/decrease/all) for sales vs restock estimation - Fix canonical-upsert to populate stock_quantity and total_quantity_available - Add API key edit functionality in admin UI - Edit allowed domains and IPs - Display domains in list view 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude <noreply@anthropic.com>
This commit is contained in:
@@ -26,6 +26,8 @@ import {
|
||||
PenetrationDataPoint,
|
||||
BrandMarketPosition,
|
||||
BrandRecVsMedFootprint,
|
||||
BrandPromotionalSummary,
|
||||
BrandPromotionalEvent,
|
||||
} from './types';
|
||||
|
||||
export class BrandPenetrationService {
|
||||
@@ -401,6 +403,224 @@ export class BrandPenetrationService {
|
||||
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<BrandPromotionalSummary> {
|
||||
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
|
||||
LEFT JOIN states s ON s.id = sp.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<string, { count: number; discounts: number[]; quantity: number }>();
|
||||
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;
|
||||
|
||||
Reference in New Issue
Block a user