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>
393 lines
13 KiB
TypeScript
393 lines
13 KiB
TypeScript
/**
|
|
* PriceAnalyticsService
|
|
*
|
|
* Analytics for price trends, volatility, and comparisons.
|
|
*
|
|
* Data Sources:
|
|
* - store_products: Current prices and price change timestamps
|
|
* - store_product_snapshots: Historical price data points
|
|
* - states: Rec/med legal status for segmentation
|
|
*
|
|
* Key Metrics:
|
|
* - Price trends over time per product
|
|
* - Price by category and state
|
|
* - Price volatility (frequency and magnitude of changes)
|
|
* - Rec vs Med pricing comparisons
|
|
*/
|
|
|
|
import { Pool } from 'pg';
|
|
import {
|
|
TimeWindow,
|
|
DateRange,
|
|
getDateRangeFromWindow,
|
|
PriceTrendResult,
|
|
PriceDataPoint,
|
|
CategoryPriceStats,
|
|
PriceVolatilityResult,
|
|
} from './types';
|
|
|
|
export class PriceAnalyticsService {
|
|
constructor(private pool: Pool) {}
|
|
|
|
/**
|
|
* Get price trends for a specific store product over time
|
|
*/
|
|
async getPriceTrendsForStoreProduct(
|
|
storeProductId: number,
|
|
options: { window?: TimeWindow; customRange?: DateRange } = {}
|
|
): Promise<PriceTrendResult | null> {
|
|
const { window = '30d', customRange } = options;
|
|
const { start, end } = getDateRangeFromWindow(window, customRange);
|
|
|
|
// Get product info
|
|
const productResult = await this.pool.query(`
|
|
SELECT
|
|
sp.id,
|
|
sp.name,
|
|
sp.brand_name,
|
|
sp.category,
|
|
sp.dispensary_id,
|
|
sp.price_rec,
|
|
sp.price_med,
|
|
d.name AS dispensary_name,
|
|
s.code AS state_code
|
|
FROM store_products sp
|
|
JOIN dispensaries d ON d.id = sp.dispensary_id
|
|
LEFT JOIN states s ON s.id = sp.state_id
|
|
WHERE sp.id = $1
|
|
`, [storeProductId]);
|
|
|
|
if (productResult.rows.length === 0) {
|
|
return null;
|
|
}
|
|
|
|
const product = productResult.rows[0];
|
|
|
|
// Get historical snapshots
|
|
const snapshotsResult = await this.pool.query(`
|
|
SELECT
|
|
DATE(captured_at) AS date,
|
|
AVG(price_rec) AS price_rec,
|
|
AVG(price_med) AS price_med,
|
|
AVG(price_rec_special) AS price_rec_special,
|
|
AVG(price_med_special) AS price_med_special,
|
|
BOOL_OR(is_on_special) AS is_on_special
|
|
FROM store_product_snapshots
|
|
WHERE store_product_id = $1
|
|
AND captured_at >= $2
|
|
AND captured_at <= $3
|
|
GROUP BY DATE(captured_at)
|
|
ORDER BY date ASC
|
|
`, [storeProductId, start, end]);
|
|
|
|
const dataPoints: PriceDataPoint[] = snapshotsResult.rows.map((row: any) => ({
|
|
date: row.date.toISOString().split('T')[0],
|
|
price_rec: row.price_rec ? parseFloat(row.price_rec) : null,
|
|
price_med: row.price_med ? parseFloat(row.price_med) : null,
|
|
price_rec_special: row.price_rec_special ? parseFloat(row.price_rec_special) : null,
|
|
price_med_special: row.price_med_special ? parseFloat(row.price_med_special) : null,
|
|
is_on_special: row.is_on_special || false,
|
|
}));
|
|
|
|
// Calculate summary statistics
|
|
const prices = dataPoints
|
|
.map(dp => dp.price_rec)
|
|
.filter((p): p is number => p !== null);
|
|
|
|
const summary = {
|
|
current_price: product.price_rec ? parseFloat(product.price_rec) : null,
|
|
min_price: prices.length > 0 ? Math.min(...prices) : null,
|
|
max_price: prices.length > 0 ? Math.max(...prices) : null,
|
|
avg_price: prices.length > 0 ? prices.reduce((a, b) => a + b, 0) / prices.length : null,
|
|
price_change_count: this.countPriceChanges(prices),
|
|
volatility_percent: this.calculateVolatility(prices),
|
|
};
|
|
|
|
return {
|
|
store_product_id: storeProductId,
|
|
product_name: product.name,
|
|
brand_name: product.brand_name,
|
|
category: product.category,
|
|
dispensary_id: product.dispensary_id,
|
|
dispensary_name: product.dispensary_name,
|
|
state_code: product.state_code || 'XX',
|
|
data_points: dataPoints,
|
|
summary,
|
|
};
|
|
}
|
|
|
|
/**
|
|
* Get price statistics by category and state
|
|
*/
|
|
async getCategoryPriceByState(
|
|
category: string,
|
|
options: { stateCode?: string } = {}
|
|
): Promise<CategoryPriceStats[]> {
|
|
const params: any[] = [category];
|
|
let stateFilter = '';
|
|
|
|
if (options.stateCode) {
|
|
stateFilter = 'AND s.code = $2';
|
|
params.push(options.stateCode);
|
|
}
|
|
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
sp.category,
|
|
s.code AS state_code,
|
|
s.name AS state_name,
|
|
CASE
|
|
WHEN s.recreational_legal = TRUE THEN 'recreational'
|
|
ELSE 'medical_only'
|
|
END AS legal_type,
|
|
AVG(sp.price_rec) AS avg_price,
|
|
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY sp.price_rec) AS median_price,
|
|
MIN(sp.price_rec) AS min_price,
|
|
MAX(sp.price_rec) AS max_price,
|
|
COUNT(*) AS product_count,
|
|
COUNT(DISTINCT sp.dispensary_id) AS dispensary_count
|
|
FROM store_products sp
|
|
JOIN dispensaries d ON d.id = sp.dispensary_id
|
|
JOIN states s ON s.id = sp.state_id
|
|
WHERE sp.category = $1
|
|
AND sp.price_rec IS NOT NULL
|
|
AND sp.is_in_stock = TRUE
|
|
AND (s.recreational_legal = TRUE OR s.medical_legal = TRUE)
|
|
${stateFilter}
|
|
GROUP BY sp.category, s.code, s.name, s.recreational_legal
|
|
ORDER BY state_code
|
|
`, params);
|
|
|
|
return result.rows.map((row: any) => ({
|
|
category: row.category,
|
|
state_code: row.state_code,
|
|
state_name: row.state_name,
|
|
legal_type: row.legal_type,
|
|
avg_price: parseFloat(row.avg_price),
|
|
median_price: parseFloat(row.median_price),
|
|
min_price: parseFloat(row.min_price),
|
|
max_price: parseFloat(row.max_price),
|
|
product_count: parseInt(row.product_count),
|
|
dispensary_count: parseInt(row.dispensary_count),
|
|
}));
|
|
}
|
|
|
|
/**
|
|
* Get price statistics by brand and state
|
|
*/
|
|
async getBrandPriceByState(
|
|
brandName: string,
|
|
options: { stateCode?: string } = {}
|
|
): Promise<CategoryPriceStats[]> {
|
|
const params: any[] = [brandName];
|
|
let stateFilter = '';
|
|
|
|
if (options.stateCode) {
|
|
stateFilter = 'AND s.code = $2';
|
|
params.push(options.stateCode);
|
|
}
|
|
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
sp.brand_name AS category,
|
|
s.code AS state_code,
|
|
s.name AS state_name,
|
|
CASE
|
|
WHEN s.recreational_legal = TRUE THEN 'recreational'
|
|
ELSE 'medical_only'
|
|
END AS legal_type,
|
|
AVG(sp.price_rec) AS avg_price,
|
|
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY sp.price_rec) AS median_price,
|
|
MIN(sp.price_rec) AS min_price,
|
|
MAX(sp.price_rec) AS max_price,
|
|
COUNT(*) AS product_count,
|
|
COUNT(DISTINCT sp.dispensary_id) AS dispensary_count
|
|
FROM store_products sp
|
|
JOIN dispensaries d ON d.id = sp.dispensary_id
|
|
JOIN states s ON s.id = sp.state_id
|
|
WHERE sp.brand_name = $1
|
|
AND sp.price_rec IS NOT NULL
|
|
AND sp.is_in_stock = TRUE
|
|
AND (s.recreational_legal = TRUE OR s.medical_legal = TRUE)
|
|
${stateFilter}
|
|
GROUP BY sp.brand_name, s.code, s.name, s.recreational_legal
|
|
ORDER BY state_code
|
|
`, params);
|
|
|
|
return result.rows.map((row: any) => ({
|
|
category: row.category,
|
|
state_code: row.state_code,
|
|
state_name: row.state_name,
|
|
legal_type: row.legal_type,
|
|
avg_price: parseFloat(row.avg_price),
|
|
median_price: parseFloat(row.median_price),
|
|
min_price: parseFloat(row.min_price),
|
|
max_price: parseFloat(row.max_price),
|
|
product_count: parseInt(row.product_count),
|
|
dispensary_count: parseInt(row.dispensary_count),
|
|
}));
|
|
}
|
|
|
|
/**
|
|
* Get most volatile products (frequent price changes)
|
|
*/
|
|
async getMostVolatileProducts(
|
|
options: {
|
|
window?: TimeWindow;
|
|
customRange?: DateRange;
|
|
limit?: number;
|
|
stateCode?: string;
|
|
category?: string;
|
|
} = {}
|
|
): Promise<PriceVolatilityResult[]> {
|
|
const { window = '30d', customRange, limit = 50, stateCode, category } = options;
|
|
const { start, end } = getDateRangeFromWindow(window, customRange);
|
|
|
|
const params: any[] = [start, end, limit];
|
|
let paramIdx = 4;
|
|
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(`
|
|
WITH price_changes AS (
|
|
SELECT
|
|
sps.store_product_id,
|
|
sps.price_rec,
|
|
LAG(sps.price_rec) OVER (
|
|
PARTITION BY sps.store_product_id ORDER BY sps.captured_at
|
|
) AS prev_price,
|
|
sps.captured_at
|
|
FROM store_product_snapshots sps
|
|
WHERE sps.captured_at >= $1
|
|
AND sps.captured_at <= $2
|
|
AND sps.price_rec IS NOT NULL
|
|
),
|
|
volatility AS (
|
|
SELECT
|
|
store_product_id,
|
|
COUNT(*) FILTER (WHERE price_rec != prev_price) AS change_count,
|
|
AVG(ABS((price_rec - prev_price) / NULLIF(prev_price, 0) * 100))
|
|
FILTER (WHERE prev_price IS NOT NULL AND prev_price != 0) AS avg_change_pct,
|
|
MAX(ABS((price_rec - prev_price) / NULLIF(prev_price, 0) * 100))
|
|
FILTER (WHERE prev_price IS NOT NULL AND prev_price != 0) AS max_change_pct,
|
|
MAX(captured_at) FILTER (WHERE price_rec != prev_price) AS last_change_at
|
|
FROM price_changes
|
|
GROUP BY store_product_id
|
|
HAVING COUNT(*) FILTER (WHERE price_rec != prev_price) > 0
|
|
)
|
|
SELECT
|
|
v.store_product_id,
|
|
sp.name AS product_name,
|
|
sp.brand_name,
|
|
v.change_count,
|
|
v.avg_change_pct,
|
|
v.max_change_pct,
|
|
v.last_change_at
|
|
FROM volatility v
|
|
JOIN store_products sp ON sp.id = v.store_product_id
|
|
LEFT JOIN states s ON s.id = sp.state_id
|
|
WHERE 1=1 ${filters}
|
|
ORDER BY v.change_count DESC, v.avg_change_pct DESC
|
|
LIMIT $3
|
|
`, params);
|
|
|
|
return result.rows.map((row: any) => ({
|
|
store_product_id: row.store_product_id,
|
|
product_name: row.product_name,
|
|
brand_name: row.brand_name,
|
|
change_count: parseInt(row.change_count),
|
|
avg_change_percent: row.avg_change_pct ? parseFloat(row.avg_change_pct) : 0,
|
|
max_change_percent: row.max_change_pct ? parseFloat(row.max_change_pct) : 0,
|
|
last_change_at: row.last_change_at ? row.last_change_at.toISOString() : null,
|
|
}));
|
|
}
|
|
|
|
/**
|
|
* Get average prices by category (rec vs med states)
|
|
*/
|
|
async getCategoryRecVsMedPrices(category?: string): Promise<{
|
|
category: string;
|
|
rec_avg: number | null;
|
|
rec_median: number | null;
|
|
med_avg: number | null;
|
|
med_median: number | null;
|
|
}[]> {
|
|
const params: any[] = [];
|
|
let categoryFilter = '';
|
|
|
|
if (category) {
|
|
categoryFilter = 'WHERE sp.category = $1';
|
|
params.push(category);
|
|
}
|
|
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
sp.category,
|
|
AVG(sp.price_rec) FILTER (WHERE s.recreational_legal = TRUE) AS rec_avg,
|
|
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY sp.price_rec)
|
|
FILTER (WHERE s.recreational_legal = TRUE) AS rec_median,
|
|
AVG(sp.price_rec) FILTER (
|
|
WHERE s.medical_legal = TRUE AND (s.recreational_legal = FALSE OR s.recreational_legal IS NULL)
|
|
) AS med_avg,
|
|
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY sp.price_rec)
|
|
FILTER (WHERE s.medical_legal = TRUE AND (s.recreational_legal = FALSE OR s.recreational_legal IS NULL)) AS med_median
|
|
FROM store_products sp
|
|
JOIN states s ON s.id = sp.state_id
|
|
${categoryFilter}
|
|
${category ? 'AND' : 'WHERE'} sp.price_rec IS NOT NULL
|
|
AND sp.is_in_stock = TRUE
|
|
AND sp.category IS NOT NULL
|
|
GROUP BY sp.category
|
|
ORDER BY sp.category
|
|
`, params);
|
|
|
|
return result.rows.map((row: any) => ({
|
|
category: row.category,
|
|
rec_avg: row.rec_avg ? parseFloat(row.rec_avg) : null,
|
|
rec_median: row.rec_median ? parseFloat(row.rec_median) : null,
|
|
med_avg: row.med_avg ? parseFloat(row.med_avg) : null,
|
|
med_median: row.med_median ? parseFloat(row.med_median) : null,
|
|
}));
|
|
}
|
|
|
|
// ============================================================
|
|
// HELPER METHODS
|
|
// ============================================================
|
|
|
|
private countPriceChanges(prices: number[]): number {
|
|
let changes = 0;
|
|
for (let i = 1; i < prices.length; i++) {
|
|
if (prices[i] !== prices[i - 1]) {
|
|
changes++;
|
|
}
|
|
}
|
|
return changes;
|
|
}
|
|
|
|
private calculateVolatility(prices: number[]): number | null {
|
|
if (prices.length < 2) return null;
|
|
|
|
const mean = prices.reduce((a, b) => a + b, 0) / prices.length;
|
|
if (mean === 0) return null;
|
|
|
|
const variance = prices.reduce((sum, p) => sum + Math.pow(p - mean, 2), 0) / prices.length;
|
|
const stdDev = Math.sqrt(variance);
|
|
|
|
// Coefficient of variation as percentage
|
|
return (stdDev / mean) * 100;
|
|
}
|
|
}
|
|
|
|
export default PriceAnalyticsService;
|