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>
588 lines
18 KiB
TypeScript
588 lines
18 KiB
TypeScript
/**
|
|
* Store Change Tracking Service
|
|
*
|
|
* Tracks changes at the store level including:
|
|
* - New/lost brands
|
|
* - New/discontinued products
|
|
* - Stock status transitions
|
|
* - Price changes
|
|
* - Category movement leaderboards
|
|
*
|
|
* Phase 3: Analytics Dashboards
|
|
*/
|
|
|
|
import { Pool } from 'pg';
|
|
import { AnalyticsCache, cacheKey } from './cache';
|
|
|
|
export interface StoreChangeSummary {
|
|
storeId: number;
|
|
storeName: string;
|
|
city: string;
|
|
state: string;
|
|
brandsAdded7d: number;
|
|
brandsAdded30d: number;
|
|
brandsLost7d: number;
|
|
brandsLost30d: number;
|
|
productsAdded7d: number;
|
|
productsAdded30d: number;
|
|
productsDiscontinued7d: number;
|
|
productsDiscontinued30d: number;
|
|
priceDrops7d: number;
|
|
priceIncreases7d: number;
|
|
restocks7d: number;
|
|
stockOuts7d: number;
|
|
}
|
|
|
|
export interface StoreChangeEvent {
|
|
id: number;
|
|
storeId: number;
|
|
storeName: string;
|
|
eventType: string;
|
|
eventDate: string;
|
|
brandName: string | null;
|
|
productName: string | null;
|
|
category: string | null;
|
|
oldValue: string | null;
|
|
newValue: string | null;
|
|
metadata: Record<string, unknown> | null;
|
|
}
|
|
|
|
export interface BrandChange {
|
|
brandName: string;
|
|
changeType: 'added' | 'removed';
|
|
date: string;
|
|
skuCount: number;
|
|
categories: string[];
|
|
}
|
|
|
|
export interface ProductChange {
|
|
productId: number;
|
|
productName: string;
|
|
brandName: string | null;
|
|
category: string | null;
|
|
changeType: 'added' | 'discontinued' | 'price_drop' | 'price_increase' | 'restocked' | 'out_of_stock';
|
|
date: string;
|
|
oldValue?: string;
|
|
newValue?: string;
|
|
}
|
|
|
|
export interface CategoryLeaderboard {
|
|
category: string;
|
|
storeId: number;
|
|
storeName: string;
|
|
skuCount: number;
|
|
brandCount: number;
|
|
avgPrice: number | null;
|
|
changePercent7d: number;
|
|
rank: number;
|
|
}
|
|
|
|
export interface StoreFilters {
|
|
storeId?: number;
|
|
state?: string;
|
|
days?: number;
|
|
eventType?: string;
|
|
}
|
|
|
|
export class StoreChangeService {
|
|
private pool: Pool;
|
|
private cache: AnalyticsCache;
|
|
|
|
constructor(pool: Pool, cache: AnalyticsCache) {
|
|
this.pool = pool;
|
|
this.cache = cache;
|
|
}
|
|
|
|
/**
|
|
* Get change summary for a store
|
|
*/
|
|
async getStoreChangeSummary(
|
|
storeId: number
|
|
): Promise<StoreChangeSummary | null> {
|
|
const key = cacheKey('store_change_summary', { storeId });
|
|
|
|
return (await this.cache.getOrCompute(key, async () => {
|
|
// Get store info
|
|
const storeResult = await this.pool.query(`
|
|
SELECT id, name, city, state FROM dispensaries WHERE id = $1
|
|
`, [storeId]);
|
|
|
|
if (storeResult.rows.length === 0) return null;
|
|
const store = storeResult.rows[0];
|
|
|
|
// Get change events counts
|
|
const eventsResult = await this.pool.query(`
|
|
SELECT
|
|
event_type,
|
|
COUNT(*) FILTER (WHERE event_date >= CURRENT_DATE - INTERVAL '7 days') as count_7d,
|
|
COUNT(*) FILTER (WHERE event_date >= CURRENT_DATE - INTERVAL '30 days') as count_30d
|
|
FROM store_change_events
|
|
WHERE store_id = $1
|
|
GROUP BY event_type
|
|
`, [storeId]);
|
|
|
|
const counts: Record<string, { count_7d: number; count_30d: number }> = {};
|
|
eventsResult.rows.forEach(row => {
|
|
counts[row.event_type] = {
|
|
count_7d: parseInt(row.count_7d) || 0,
|
|
count_30d: parseInt(row.count_30d) || 0,
|
|
};
|
|
});
|
|
|
|
return {
|
|
storeId: store.id,
|
|
storeName: store.name,
|
|
city: store.city,
|
|
state: store.state,
|
|
brandsAdded7d: counts['brand_added']?.count_7d || 0,
|
|
brandsAdded30d: counts['brand_added']?.count_30d || 0,
|
|
brandsLost7d: counts['brand_removed']?.count_7d || 0,
|
|
brandsLost30d: counts['brand_removed']?.count_30d || 0,
|
|
productsAdded7d: counts['product_added']?.count_7d || 0,
|
|
productsAdded30d: counts['product_added']?.count_30d || 0,
|
|
productsDiscontinued7d: counts['product_removed']?.count_7d || 0,
|
|
productsDiscontinued30d: counts['product_removed']?.count_30d || 0,
|
|
priceDrops7d: counts['price_drop']?.count_7d || 0,
|
|
priceIncreases7d: counts['price_increase']?.count_7d || 0,
|
|
restocks7d: counts['restocked']?.count_7d || 0,
|
|
stockOuts7d: counts['out_of_stock']?.count_7d || 0,
|
|
};
|
|
}, 15)).data;
|
|
}
|
|
|
|
/**
|
|
* Get recent change events for a store
|
|
*/
|
|
async getStoreChangeEvents(
|
|
storeId: number,
|
|
filters: { eventType?: string; days?: number; limit?: number } = {}
|
|
): Promise<StoreChangeEvent[]> {
|
|
const { eventType, days = 30, limit = 100 } = filters;
|
|
const key = cacheKey('store_change_events', { storeId, eventType, days, limit });
|
|
|
|
return (await this.cache.getOrCompute(key, async () => {
|
|
const params: (string | number)[] = [storeId, days, limit];
|
|
let eventTypeCondition = '';
|
|
|
|
if (eventType) {
|
|
eventTypeCondition = 'AND event_type = $4';
|
|
params.push(eventType);
|
|
}
|
|
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
sce.id,
|
|
sce.store_id,
|
|
d.name as store_name,
|
|
sce.event_type,
|
|
sce.event_date,
|
|
sce.brand_name,
|
|
sce.product_name,
|
|
sce.category,
|
|
sce.old_value,
|
|
sce.new_value,
|
|
sce.metadata
|
|
FROM store_change_events sce
|
|
JOIN dispensaries d ON sce.store_id = d.id
|
|
WHERE sce.store_id = $1
|
|
AND sce.event_date >= CURRENT_DATE - ($2 || ' days')::INTERVAL
|
|
${eventTypeCondition}
|
|
ORDER BY sce.event_date DESC, sce.id DESC
|
|
LIMIT $3
|
|
`, params);
|
|
|
|
return result.rows.map(row => ({
|
|
id: row.id,
|
|
storeId: row.store_id,
|
|
storeName: row.store_name,
|
|
eventType: row.event_type,
|
|
eventDate: row.event_date.toISOString().split('T')[0],
|
|
brandName: row.brand_name,
|
|
productName: row.product_name,
|
|
category: row.category,
|
|
oldValue: row.old_value,
|
|
newValue: row.new_value,
|
|
metadata: row.metadata,
|
|
}));
|
|
}, 5)).data;
|
|
}
|
|
|
|
/**
|
|
* Get new brands added to a store
|
|
*/
|
|
async getNewBrands(
|
|
storeId: number,
|
|
days: number = 30
|
|
): Promise<BrandChange[]> {
|
|
const key = cacheKey('new_brands', { storeId, days });
|
|
|
|
return (await this.cache.getOrCompute(key, async () => {
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
brand_name,
|
|
event_date,
|
|
metadata
|
|
FROM store_change_events
|
|
WHERE store_id = $1
|
|
AND event_type = 'brand_added'
|
|
AND event_date >= CURRENT_DATE - ($2 || ' days')::INTERVAL
|
|
ORDER BY event_date DESC
|
|
`, [storeId, days]);
|
|
|
|
return result.rows.map(row => ({
|
|
brandName: row.brand_name,
|
|
changeType: 'added' as const,
|
|
date: row.event_date.toISOString().split('T')[0],
|
|
skuCount: row.metadata?.sku_count || 0,
|
|
categories: row.metadata?.categories || [],
|
|
}));
|
|
}, 15)).data;
|
|
}
|
|
|
|
/**
|
|
* Get brands lost from a store
|
|
*/
|
|
async getLostBrands(
|
|
storeId: number,
|
|
days: number = 30
|
|
): Promise<BrandChange[]> {
|
|
const key = cacheKey('lost_brands', { storeId, days });
|
|
|
|
return (await this.cache.getOrCompute(key, async () => {
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
brand_name,
|
|
event_date,
|
|
metadata
|
|
FROM store_change_events
|
|
WHERE store_id = $1
|
|
AND event_type = 'brand_removed'
|
|
AND event_date >= CURRENT_DATE - ($2 || ' days')::INTERVAL
|
|
ORDER BY event_date DESC
|
|
`, [storeId, days]);
|
|
|
|
return result.rows.map(row => ({
|
|
brandName: row.brand_name,
|
|
changeType: 'removed' as const,
|
|
date: row.event_date.toISOString().split('T')[0],
|
|
skuCount: row.metadata?.sku_count || 0,
|
|
categories: row.metadata?.categories || [],
|
|
}));
|
|
}, 15)).data;
|
|
}
|
|
|
|
/**
|
|
* Get product changes for a store
|
|
*/
|
|
async getProductChanges(
|
|
storeId: number,
|
|
changeType?: 'added' | 'discontinued' | 'price_drop' | 'price_increase' | 'restocked' | 'out_of_stock',
|
|
days: number = 7
|
|
): Promise<ProductChange[]> {
|
|
const key = cacheKey('product_changes', { storeId, changeType, days });
|
|
|
|
return (await this.cache.getOrCompute(key, async () => {
|
|
const eventTypeMap: Record<string, string> = {
|
|
'added': 'product_added',
|
|
'discontinued': 'product_removed',
|
|
'price_drop': 'price_drop',
|
|
'price_increase': 'price_increase',
|
|
'restocked': 'restocked',
|
|
'out_of_stock': 'out_of_stock',
|
|
};
|
|
|
|
const params: (string | number)[] = [storeId, days];
|
|
let eventCondition = '';
|
|
|
|
if (changeType) {
|
|
eventCondition = 'AND event_type = $3';
|
|
params.push(eventTypeMap[changeType]);
|
|
}
|
|
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
product_id,
|
|
product_name,
|
|
brand_name,
|
|
category,
|
|
event_type,
|
|
event_date,
|
|
old_value,
|
|
new_value
|
|
FROM store_change_events
|
|
WHERE store_id = $1
|
|
AND event_date >= CURRENT_DATE - ($2 || ' days')::INTERVAL
|
|
AND product_id IS NOT NULL
|
|
${eventCondition}
|
|
ORDER BY event_date DESC
|
|
LIMIT 100
|
|
`, params);
|
|
|
|
const reverseMap: Record<string, ProductChange['changeType']> = {
|
|
'product_added': 'added',
|
|
'product_removed': 'discontinued',
|
|
'price_drop': 'price_drop',
|
|
'price_increase': 'price_increase',
|
|
'restocked': 'restocked',
|
|
'out_of_stock': 'out_of_stock',
|
|
};
|
|
|
|
return result.rows.map(row => ({
|
|
productId: row.product_id,
|
|
productName: row.product_name,
|
|
brandName: row.brand_name,
|
|
category: row.category,
|
|
changeType: reverseMap[row.event_type] || 'added',
|
|
date: row.event_date.toISOString().split('T')[0],
|
|
oldValue: row.old_value,
|
|
newValue: row.new_value,
|
|
}));
|
|
}, 5)).data;
|
|
}
|
|
|
|
/**
|
|
* Get category leaderboard across stores
|
|
*/
|
|
async getCategoryLeaderboard(
|
|
category: string,
|
|
limit: number = 20
|
|
): Promise<CategoryLeaderboard[]> {
|
|
const key = cacheKey('category_leaderboard', { category, limit });
|
|
|
|
return (await this.cache.getOrCompute(key, async () => {
|
|
const result = await this.pool.query(`
|
|
WITH store_category_stats AS (
|
|
SELECT
|
|
dp.dispensary_id as store_id,
|
|
d.name as store_name,
|
|
COUNT(*) as sku_count,
|
|
COUNT(DISTINCT dp.brand_name) as brand_count,
|
|
AVG(extract_min_price(dp.latest_raw_payload)) as avg_price
|
|
FROM dutchie_products dp
|
|
JOIN dispensaries d ON dp.dispensary_id = d.id
|
|
WHERE dp.type = $1
|
|
GROUP BY dp.dispensary_id, d.name
|
|
)
|
|
SELECT
|
|
scs.*,
|
|
RANK() OVER (ORDER BY scs.sku_count DESC) as rank
|
|
FROM store_category_stats scs
|
|
ORDER BY scs.sku_count DESC
|
|
LIMIT $2
|
|
`, [category, limit]);
|
|
|
|
return result.rows.map(row => ({
|
|
category,
|
|
storeId: row.store_id,
|
|
storeName: row.store_name,
|
|
skuCount: parseInt(row.sku_count) || 0,
|
|
brandCount: parseInt(row.brand_count) || 0,
|
|
avgPrice: row.avg_price ? Math.round(parseFloat(row.avg_price) * 100) / 100 : null,
|
|
changePercent7d: 0, // Would need historical data
|
|
rank: parseInt(row.rank) || 0,
|
|
}));
|
|
}, 15)).data;
|
|
}
|
|
|
|
/**
|
|
* Get stores with most activity (changes)
|
|
*/
|
|
async getMostActiveStores(
|
|
days: number = 7,
|
|
limit: number = 10
|
|
): Promise<Array<{
|
|
storeId: number;
|
|
storeName: string;
|
|
city: string;
|
|
state: string;
|
|
totalChanges: number;
|
|
brandsChanged: number;
|
|
productsChanged: number;
|
|
priceChanges: number;
|
|
stockChanges: number;
|
|
}>> {
|
|
const key = cacheKey('most_active_stores', { days, limit });
|
|
|
|
return (await this.cache.getOrCompute(key, async () => {
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
d.id as store_id,
|
|
d.name as store_name,
|
|
d.city,
|
|
d.state,
|
|
COUNT(*) as total_changes,
|
|
COUNT(*) FILTER (WHERE sce.event_type IN ('brand_added', 'brand_removed')) as brands_changed,
|
|
COUNT(*) FILTER (WHERE sce.event_type IN ('product_added', 'product_removed')) as products_changed,
|
|
COUNT(*) FILTER (WHERE sce.event_type IN ('price_drop', 'price_increase')) as price_changes,
|
|
COUNT(*) FILTER (WHERE sce.event_type IN ('restocked', 'out_of_stock')) as stock_changes
|
|
FROM store_change_events sce
|
|
JOIN dispensaries d ON sce.store_id = d.id
|
|
WHERE sce.event_date >= CURRENT_DATE - ($1 || ' days')::INTERVAL
|
|
GROUP BY d.id, d.name, d.city, d.state
|
|
ORDER BY total_changes DESC
|
|
LIMIT $2
|
|
`, [days, limit]);
|
|
|
|
return result.rows.map(row => ({
|
|
storeId: row.store_id,
|
|
storeName: row.store_name,
|
|
city: row.city,
|
|
state: row.state,
|
|
totalChanges: parseInt(row.total_changes) || 0,
|
|
brandsChanged: parseInt(row.brands_changed) || 0,
|
|
productsChanged: parseInt(row.products_changed) || 0,
|
|
priceChanges: parseInt(row.price_changes) || 0,
|
|
stockChanges: parseInt(row.stock_changes) || 0,
|
|
}));
|
|
}, 15)).data;
|
|
}
|
|
|
|
/**
|
|
* Compare two stores
|
|
*/
|
|
async compareStores(
|
|
storeId1: number,
|
|
storeId2: number
|
|
): Promise<{
|
|
store1: { id: number; name: string; brands: string[]; categories: string[]; skuCount: number };
|
|
store2: { id: number; name: string; brands: string[]; categories: string[]; skuCount: number };
|
|
sharedBrands: string[];
|
|
uniqueToStore1: string[];
|
|
uniqueToStore2: string[];
|
|
categoryComparison: Array<{
|
|
category: string;
|
|
store1Skus: number;
|
|
store2Skus: number;
|
|
difference: number;
|
|
}>;
|
|
}> {
|
|
const key = cacheKey('compare_stores', { storeId1, storeId2 });
|
|
|
|
return (await this.cache.getOrCompute(key, async () => {
|
|
const [store1Data, store2Data] = await Promise.all([
|
|
this.pool.query(`
|
|
SELECT
|
|
d.id, d.name,
|
|
ARRAY_AGG(DISTINCT dp.brand_name) FILTER (WHERE dp.brand_name IS NOT NULL) as brands,
|
|
ARRAY_AGG(DISTINCT dp.type) FILTER (WHERE dp.type IS NOT NULL) as categories,
|
|
COUNT(*) as sku_count
|
|
FROM dispensaries d
|
|
LEFT JOIN dutchie_products dp ON d.id = dp.dispensary_id
|
|
WHERE d.id = $1
|
|
GROUP BY d.id, d.name
|
|
`, [storeId1]),
|
|
this.pool.query(`
|
|
SELECT
|
|
d.id, d.name,
|
|
ARRAY_AGG(DISTINCT dp.brand_name) FILTER (WHERE dp.brand_name IS NOT NULL) as brands,
|
|
ARRAY_AGG(DISTINCT dp.type) FILTER (WHERE dp.type IS NOT NULL) as categories,
|
|
COUNT(*) as sku_count
|
|
FROM dispensaries d
|
|
LEFT JOIN dutchie_products dp ON d.id = dp.dispensary_id
|
|
WHERE d.id = $1
|
|
GROUP BY d.id, d.name
|
|
`, [storeId2]),
|
|
]);
|
|
|
|
const s1 = store1Data.rows[0];
|
|
const s2 = store2Data.rows[0];
|
|
|
|
const brands1Array: string[] = (s1?.brands || []).filter((b: string | null): b is string => b !== null);
|
|
const brands2Array: string[] = (s2?.brands || []).filter((b: string | null): b is string => b !== null);
|
|
const brands1 = new Set(brands1Array);
|
|
const brands2 = new Set(brands2Array);
|
|
|
|
const sharedBrands: string[] = brands1Array.filter(b => brands2.has(b));
|
|
const uniqueToStore1: string[] = brands1Array.filter(b => !brands2.has(b));
|
|
const uniqueToStore2: string[] = brands2Array.filter(b => !brands1.has(b));
|
|
|
|
// Category comparison
|
|
const categoryResult = await this.pool.query(`
|
|
WITH store1_cats AS (
|
|
SELECT type as category, COUNT(*) as sku_count
|
|
FROM dutchie_products WHERE dispensary_id = $1 AND type IS NOT NULL
|
|
GROUP BY type
|
|
),
|
|
store2_cats AS (
|
|
SELECT type as category, COUNT(*) as sku_count
|
|
FROM dutchie_products WHERE dispensary_id = $2 AND type IS NOT NULL
|
|
GROUP BY type
|
|
),
|
|
all_cats AS (
|
|
SELECT category FROM store1_cats
|
|
UNION
|
|
SELECT category FROM store2_cats
|
|
)
|
|
SELECT
|
|
ac.category,
|
|
COALESCE(s1.sku_count, 0) as store1_skus,
|
|
COALESCE(s2.sku_count, 0) as store2_skus
|
|
FROM all_cats ac
|
|
LEFT JOIN store1_cats s1 ON ac.category = s1.category
|
|
LEFT JOIN store2_cats s2 ON ac.category = s2.category
|
|
ORDER BY (COALESCE(s1.sku_count, 0) + COALESCE(s2.sku_count, 0)) DESC
|
|
`, [storeId1, storeId2]);
|
|
|
|
return {
|
|
store1: {
|
|
id: s1?.id || storeId1,
|
|
name: s1?.name || 'Unknown',
|
|
brands: s1?.brands || [],
|
|
categories: s1?.categories || [],
|
|
skuCount: parseInt(s1?.sku_count) || 0,
|
|
},
|
|
store2: {
|
|
id: s2?.id || storeId2,
|
|
name: s2?.name || 'Unknown',
|
|
brands: s2?.brands || [],
|
|
categories: s2?.categories || [],
|
|
skuCount: parseInt(s2?.sku_count) || 0,
|
|
},
|
|
sharedBrands,
|
|
uniqueToStore1,
|
|
uniqueToStore2,
|
|
categoryComparison: categoryResult.rows.map(row => ({
|
|
category: row.category,
|
|
store1Skus: parseInt(row.store1_skus) || 0,
|
|
store2Skus: parseInt(row.store2_skus) || 0,
|
|
difference: (parseInt(row.store1_skus) || 0) - (parseInt(row.store2_skus) || 0),
|
|
})),
|
|
};
|
|
}, 15)).data;
|
|
}
|
|
|
|
/**
|
|
* Record a change event (used by crawler/worker)
|
|
*/
|
|
async recordChangeEvent(event: {
|
|
storeId: number;
|
|
eventType: string;
|
|
brandName?: string;
|
|
productId?: number;
|
|
productName?: string;
|
|
category?: string;
|
|
oldValue?: string;
|
|
newValue?: string;
|
|
metadata?: Record<string, unknown>;
|
|
}): Promise<void> {
|
|
await this.pool.query(`
|
|
INSERT INTO store_change_events
|
|
(store_id, event_type, event_date, brand_name, product_id, product_name, category, old_value, new_value, metadata)
|
|
VALUES ($1, $2, CURRENT_DATE, $3, $4, $5, $6, $7, $8, $9)
|
|
`, [
|
|
event.storeId,
|
|
event.eventType,
|
|
event.brandName || null,
|
|
event.productId || null,
|
|
event.productName || null,
|
|
event.category || null,
|
|
event.oldValue || null,
|
|
event.newValue || null,
|
|
event.metadata ? JSON.stringify(event.metadata) : null,
|
|
]);
|
|
|
|
// Invalidate cache
|
|
await this.cache.invalidatePattern(`store_change_summary:storeId=${event.storeId}`);
|
|
}
|
|
}
|