Files
cannaiq/backend/src/services/analytics/StoreAnalyticsService.ts
Kelly 9aefb554bc fix: Correct Analytics V2 SQL queries for schema alignment
- Fix JOIN path: store_products -> dispensaries -> states (was incorrectly joining sp.state_id which doesn't exist)
- Fix column names to use *_raw suffixes (category_raw, brand_name_raw, name_raw)
- Fix row mappings to read correct column names from query results
- Add ::timestamp casts for interval arithmetic in StoreAnalyticsService

All Analytics V2 endpoints now work correctly:
- /state/legal-breakdown
- /state/recreational
- /category/all
- /category/rec-vs-med
- /state/:code/summary
- /store/:id/summary

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2025-12-10 18:52:57 -07:00

634 lines
21 KiB
TypeScript

/**
* StoreAnalyticsService
*
* Analytics for individual store/dispensary performance and changes.
*
* Data Sources:
* - store_products: Current product catalog per dispensary
* - store_product_snapshots: Historical product data
* - dispensaries: Store metadata
* - states: Rec/med segmentation
*
* Key Metrics:
* - Products added/dropped over time window
* - Brands added/dropped
* - Price changes count and magnitude
* - Stock in/out events
* - Store inventory composition
*/
import { Pool } from 'pg';
import {
TimeWindow,
DateRange,
getDateRangeFromWindow,
StoreChangeSummary,
ProductChangeEvent,
} from './types';
export class StoreAnalyticsService {
constructor(private pool: Pool) {}
/**
* Get change summary for a dispensary over a time window
*/
async getStoreChangeSummary(
dispensaryId: number,
options: { window?: TimeWindow; customRange?: DateRange } = {}
): Promise<StoreChangeSummary | null> {
const { window = '30d', customRange } = options;
const { start, end } = getDateRangeFromWindow(window, customRange);
// Get dispensary info
const dispResult = await this.pool.query(`
SELECT
d.id,
d.name,
s.code AS state_code
FROM dispensaries d
LEFT JOIN states s ON s.id = d.state_id
WHERE d.id = $1
`, [dispensaryId]);
if (dispResult.rows.length === 0) {
return null;
}
const dispensary = dispResult.rows[0];
// Get current counts
const currentResult = await this.pool.query(`
SELECT
COUNT(*) AS product_count,
COUNT(*) FILTER (WHERE is_in_stock = TRUE) AS in_stock_count
FROM store_products
WHERE dispensary_id = $1
`, [dispensaryId]);
const current = currentResult.rows[0];
// Get products added (first_seen_at in window)
const addedResult = await this.pool.query(`
SELECT COUNT(*) AS count
FROM store_products
WHERE dispensary_id = $1
AND first_seen_at >= $2
AND first_seen_at <= $3
`, [dispensaryId, start, end]);
// Get products dropped (last_seen_at in window but not in current inventory)
const droppedResult = await this.pool.query(`
SELECT COUNT(*) AS count
FROM store_products
WHERE dispensary_id = $1
AND last_seen_at >= $2
AND last_seen_at <= $3
AND is_in_stock = FALSE
`, [dispensaryId, start, end]);
// Get brands added/dropped
const brandsResult = await this.pool.query(`
WITH start_brands AS (
SELECT DISTINCT brand_name_raw
FROM store_product_snapshots
WHERE dispensary_id = $1
AND captured_at >= $2::timestamp AND captured_at < $2::timestamp + INTERVAL '1 day'
AND brand_name_raw IS NOT NULL
),
end_brands AS (
SELECT DISTINCT brand_name_raw
FROM store_product_snapshots
WHERE dispensary_id = $1
AND captured_at >= $3::timestamp - INTERVAL '1 day' AND captured_at <= $3::timestamp
AND brand_name_raw IS NOT NULL
)
SELECT
ARRAY(SELECT brand_name_raw FROM end_brands EXCEPT SELECT brand_name_raw FROM start_brands) AS added,
ARRAY(SELECT brand_name_raw FROM start_brands EXCEPT SELECT brand_name_raw FROM end_brands) AS dropped
`, [dispensaryId, start, end]);
const brands = brandsResult.rows[0] || { added: [], dropped: [] };
// Get price changes
const priceChangeResult = await this.pool.query(`
WITH price_changes AS (
SELECT
store_product_id,
price_rec,
LAG(price_rec) OVER (PARTITION BY store_product_id ORDER BY captured_at) AS prev_price
FROM store_product_snapshots
WHERE dispensary_id = $1
AND captured_at >= $2
AND captured_at <= $3
AND price_rec IS NOT NULL
)
SELECT
COUNT(*) FILTER (WHERE price_rec != prev_price AND prev_price IS NOT NULL) AS change_count,
AVG(ABS((price_rec - prev_price) / NULLIF(prev_price, 0) * 100))
FILTER (WHERE price_rec != prev_price AND prev_price IS NOT NULL AND prev_price != 0) AS avg_change_pct
FROM price_changes
`, [dispensaryId, start, end]);
const priceChanges = priceChangeResult.rows[0];
// Get stock events
const stockEventsResult = await this.pool.query(`
WITH stock_changes AS (
SELECT
store_product_id,
is_in_stock,
LAG(is_in_stock) OVER (PARTITION BY store_product_id ORDER BY captured_at) AS prev_stock
FROM store_product_snapshots
WHERE dispensary_id = $1
AND captured_at >= $2
AND captured_at <= $3
)
SELECT
COUNT(*) FILTER (WHERE is_in_stock = TRUE AND prev_stock = FALSE) AS stock_in,
COUNT(*) FILTER (WHERE is_in_stock = FALSE AND prev_stock = TRUE) AS stock_out
FROM stock_changes
`, [dispensaryId, start, end]);
const stockEvents = stockEventsResult.rows[0];
return {
dispensary_id: dispensaryId,
dispensary_name: dispensary.name,
state_code: dispensary.state_code || 'XX',
window: window,
products_added: parseInt(addedResult.rows[0]?.count) || 0,
products_dropped: parseInt(droppedResult.rows[0]?.count) || 0,
brands_added: brands.added || [],
brands_dropped: brands.dropped || [],
price_changes: parseInt(priceChanges?.change_count) || 0,
avg_price_change_percent: priceChanges?.avg_change_pct ? parseFloat(priceChanges.avg_change_pct) : null,
stock_in_events: parseInt(stockEvents?.stock_in) || 0,
stock_out_events: parseInt(stockEvents?.stock_out) || 0,
current_product_count: parseInt(current.product_count) || 0,
current_in_stock_count: parseInt(current.in_stock_count) || 0,
};
}
/**
* Get recent product change events for a dispensary
*/
async getProductChangeEvents(
dispensaryId: number,
options: { window?: TimeWindow; customRange?: DateRange; limit?: number } = {}
): Promise<ProductChangeEvent[]> {
const { window = '7d', customRange, limit = 100 } = options;
const { start, end } = getDateRangeFromWindow(window, customRange);
const result = await this.pool.query(`
WITH changes AS (
-- Products added
SELECT
sp.id AS store_product_id,
sp.name_raw AS product_name,
sp.brand_name_raw,
sp.category_raw,
'added' AS event_type,
sp.first_seen_at AS event_date,
NULL::TEXT AS old_value,
NULL::TEXT AS new_value
FROM store_products sp
WHERE sp.dispensary_id = $1
AND sp.first_seen_at >= $2
AND sp.first_seen_at <= $3
UNION ALL
-- Stock in/out from snapshots
SELECT
sps.store_product_id,
sp.name_raw AS product_name,
sp.brand_name_raw,
sp.category_raw,
CASE
WHEN sps.is_in_stock = TRUE AND LAG(sps.is_in_stock) OVER w = FALSE THEN 'stock_in'
WHEN sps.is_in_stock = FALSE AND LAG(sps.is_in_stock) OVER w = TRUE THEN 'stock_out'
ELSE NULL
END AS event_type,
sps.captured_at AS event_date,
LAG(sps.is_in_stock::TEXT) OVER w AS old_value,
sps.is_in_stock::TEXT AS new_value
FROM store_product_snapshots sps
JOIN store_products sp ON sp.id = sps.store_product_id
WHERE sps.dispensary_id = $1
AND sps.captured_at >= $2
AND sps.captured_at <= $3
WINDOW w AS (PARTITION BY sps.store_product_id ORDER BY sps.captured_at)
UNION ALL
-- Price changes from snapshots
SELECT
sps.store_product_id,
sp.name_raw AS product_name,
sp.brand_name_raw,
sp.category_raw,
'price_change' AS event_type,
sps.captured_at AS event_date,
LAG(sps.price_rec::TEXT) OVER w AS old_value,
sps.price_rec::TEXT AS new_value
FROM store_product_snapshots sps
JOIN store_products sp ON sp.id = sps.store_product_id
WHERE sps.dispensary_id = $1
AND sps.captured_at >= $2
AND sps.captured_at <= $3
AND sps.price_rec IS NOT NULL
AND sps.price_rec != LAG(sps.price_rec) OVER w
WINDOW w AS (PARTITION BY sps.store_product_id ORDER BY sps.captured_at)
)
SELECT *
FROM changes
WHERE event_type IS NOT NULL
ORDER BY event_date DESC
LIMIT $4
`, [dispensaryId, start, end, limit]);
return result.rows.map((row: any) => ({
store_product_id: row.store_product_id,
product_name: row.product_name,
brand_name: row.brand_name_raw,
category: row.category_raw,
event_type: row.event_type,
event_date: row.event_date ? row.event_date.toISOString() : null,
old_value: row.old_value,
new_value: row.new_value,
}));
}
/**
* Get quantity changes for a store (increases/decreases)
* Useful for estimating sales (decreases) or restocks (increases)
*
* @param direction - 'decrease' for likely sales, 'increase' for restocks, 'all' for both
*/
async getQuantityChanges(
dispensaryId: number,
options: {
window?: TimeWindow;
customRange?: DateRange;
direction?: 'increase' | 'decrease' | 'all';
limit?: number;
} = {}
): Promise<{
dispensary_id: number;
window: TimeWindow;
direction: string;
total_changes: number;
total_units_decreased: number;
total_units_increased: number;
changes: Array<{
store_product_id: number;
product_name: string;
brand_name: string | null;
category: string | null;
old_quantity: number;
new_quantity: number;
quantity_delta: number;
direction: 'increase' | 'decrease';
captured_at: string;
}>;
}> {
const { window = '7d', customRange, direction = 'all', limit = 100 } = options;
const { start, end } = getDateRangeFromWindow(window, customRange);
// Build direction filter
let directionFilter = '';
if (direction === 'decrease') {
directionFilter = 'AND qty_delta < 0';
} else if (direction === 'increase') {
directionFilter = 'AND qty_delta > 0';
}
const result = await this.pool.query(`
WITH qty_changes AS (
SELECT
sps.store_product_id,
sp.name_raw AS product_name,
sp.brand_name_raw AS brand_name,
sp.category_raw AS category,
LAG(sps.stock_quantity) OVER w AS old_quantity,
sps.stock_quantity AS new_quantity,
sps.stock_quantity - LAG(sps.stock_quantity) OVER w AS qty_delta,
sps.captured_at
FROM store_product_snapshots sps
JOIN store_products sp ON sp.id = sps.store_product_id
WHERE sps.dispensary_id = $1
AND sps.captured_at >= $2
AND sps.captured_at <= $3
AND sps.stock_quantity IS NOT NULL
WINDOW w AS (PARTITION BY sps.store_product_id ORDER BY sps.captured_at)
)
SELECT *
FROM qty_changes
WHERE old_quantity IS NOT NULL
AND qty_delta != 0
${directionFilter}
ORDER BY captured_at DESC
LIMIT $4
`, [dispensaryId, start, end, limit]);
// Calculate totals
const totalsResult = await this.pool.query(`
WITH qty_changes AS (
SELECT
sps.stock_quantity - LAG(sps.stock_quantity) OVER w AS qty_delta
FROM store_product_snapshots sps
WHERE sps.dispensary_id = $1
AND sps.captured_at >= $2
AND sps.captured_at <= $3
AND sps.stock_quantity IS NOT NULL
AND sps.store_product_id IS NOT NULL
WINDOW w AS (PARTITION BY sps.store_product_id ORDER BY sps.captured_at)
)
SELECT
COUNT(*) FILTER (WHERE qty_delta != 0) AS total_changes,
COALESCE(SUM(ABS(qty_delta)) FILTER (WHERE qty_delta < 0), 0) AS units_decreased,
COALESCE(SUM(qty_delta) FILTER (WHERE qty_delta > 0), 0) AS units_increased
FROM qty_changes
WHERE qty_delta IS NOT NULL
`, [dispensaryId, start, end]);
const totals = totalsResult.rows[0] || {};
return {
dispensary_id: dispensaryId,
window,
direction,
total_changes: parseInt(totals.total_changes) || 0,
total_units_decreased: parseInt(totals.units_decreased) || 0,
total_units_increased: parseInt(totals.units_increased) || 0,
changes: result.rows.map((row: any) => ({
store_product_id: row.store_product_id,
product_name: row.product_name,
brand_name: row.brand_name_raw,
category: row.category_raw,
old_quantity: row.old_quantity,
new_quantity: row.new_quantity,
quantity_delta: row.qty_delta,
direction: row.qty_delta > 0 ? 'increase' : 'decrease',
captured_at: row.captured_at?.toISOString() || null,
})),
};
}
/**
* Get store inventory composition (categories and brands breakdown)
*/
async getStoreInventoryComposition(dispensaryId: number): Promise<{
total_products: number;
in_stock_count: number;
out_of_stock_count: number;
categories: Array<{ category: string; count: number; percent: number }>;
top_brands: Array<{ brand: string; count: number; percent: number }>;
}> {
// Get totals
const totalsResult = await this.pool.query(`
SELECT
COUNT(*) AS total,
COUNT(*) FILTER (WHERE is_in_stock = TRUE) AS in_stock,
COUNT(*) FILTER (WHERE is_in_stock = FALSE) AS out_of_stock
FROM store_products
WHERE dispensary_id = $1
`, [dispensaryId]);
const totals = totalsResult.rows[0];
const totalProducts = parseInt(totals.total) || 0;
// Get category breakdown
const categoriesResult = await this.pool.query(`
SELECT
category,
COUNT(*) AS count,
ROUND(COUNT(*)::NUMERIC * 100 / NULLIF($2, 0), 2) AS percent
FROM store_products
WHERE dispensary_id = $1
AND category IS NOT NULL
AND is_in_stock = TRUE
GROUP BY category
ORDER BY count DESC
`, [dispensaryId, totalProducts]);
// Get top brands
const brandsResult = await this.pool.query(`
SELECT
brand_name_raw AS brand,
COUNT(*) AS count,
ROUND(COUNT(*)::NUMERIC * 100 / NULLIF($2, 0), 2) AS percent
FROM store_products
WHERE dispensary_id = $1
AND brand_name_raw IS NOT NULL
AND is_in_stock = TRUE
GROUP BY brand_name_raw
ORDER BY count DESC
LIMIT 20
`, [dispensaryId, totalProducts]);
return {
total_products: totalProducts,
in_stock_count: parseInt(totals.in_stock) || 0,
out_of_stock_count: parseInt(totals.out_of_stock) || 0,
categories: categoriesResult.rows.map((row: any) => ({
category: row.category_raw,
count: parseInt(row.count),
percent: parseFloat(row.percent) || 0,
})),
top_brands: brandsResult.rows.map((row: any) => ({
brand: row.brand,
count: parseInt(row.count),
percent: parseFloat(row.percent) || 0,
})),
};
}
/**
* Get stores with most changes (high-activity stores)
*/
async getMostActiveStores(
options: { window?: TimeWindow; customRange?: DateRange; limit?: number; stateCode?: string } = {}
): Promise<Array<{
dispensary_id: number;
dispensary_name: string;
state_code: string;
total_changes: number;
price_changes: number;
stock_changes: number;
products_added: number;
}>> {
const { window = '7d', customRange, limit = 25, stateCode } = options;
const { start, end } = getDateRangeFromWindow(window, customRange);
const params: any[] = [start, end, limit];
let paramIdx = 4;
let stateFilter = '';
if (stateCode) {
stateFilter = `AND s.code = $${paramIdx}`;
params.push(stateCode);
paramIdx++;
}
const result = await this.pool.query(`
WITH store_activity AS (
SELECT
sps.dispensary_id,
-- Price changes
COUNT(*) FILTER (
WHERE sps.price_rec IS NOT NULL
AND sps.price_rec != LAG(sps.price_rec) OVER (PARTITION BY sps.store_product_id ORDER BY sps.captured_at)
) AS price_changes,
-- Stock changes
COUNT(*) FILTER (
WHERE sps.is_in_stock != LAG(sps.is_in_stock) OVER (PARTITION BY sps.store_product_id ORDER BY sps.captured_at)
) AS stock_changes
FROM store_product_snapshots sps
WHERE sps.captured_at >= $1
AND sps.captured_at <= $2
GROUP BY sps.dispensary_id
),
products_added AS (
SELECT
dispensary_id,
COUNT(*) AS count
FROM store_products
WHERE first_seen_at >= $1
AND first_seen_at <= $2
GROUP BY dispensary_id
)
SELECT
d.id AS dispensary_id,
d.name AS dispensary_name,
s.code AS state_code,
COALESCE(sa.price_changes, 0) + COALESCE(sa.stock_changes, 0) + COALESCE(pa.count, 0) AS total_changes,
COALESCE(sa.price_changes, 0) AS price_changes,
COALESCE(sa.stock_changes, 0) AS stock_changes,
COALESCE(pa.count, 0) AS products_added
FROM dispensaries d
LEFT JOIN states s ON s.id = d.state_id
LEFT JOIN store_activity sa ON sa.dispensary_id = d.id
LEFT JOIN products_added pa ON pa.dispensary_id = d.id
WHERE (sa.price_changes > 0 OR sa.stock_changes > 0 OR pa.count > 0)
${stateFilter}
ORDER BY total_changes DESC
LIMIT $3
`, params);
return result.rows.map((row: any) => ({
dispensary_id: row.dispensary_id,
dispensary_name: row.dispensary_name,
state_code: row.state_code || 'XX',
total_changes: parseInt(row.total_changes) || 0,
price_changes: parseInt(row.price_changes) || 0,
stock_changes: parseInt(row.stock_changes) || 0,
products_added: parseInt(row.products_added) || 0,
}));
}
/**
* Get store price positioning vs market
*/
async getStorePricePositioning(dispensaryId: number): Promise<{
dispensary_id: number;
dispensary_name: string;
categories: Array<{
category: string;
store_avg_price: number;
market_avg_price: number;
price_vs_market_percent: number;
product_count: number;
}>;
overall_price_vs_market_percent: number | null;
}> {
// Get dispensary info
const dispResult = await this.pool.query(`
SELECT id, name, state_id FROM dispensaries WHERE id = $1
`, [dispensaryId]);
if (dispResult.rows.length === 0) {
return {
dispensary_id: dispensaryId,
dispensary_name: 'Unknown',
categories: [],
overall_price_vs_market_percent: null,
};
}
const dispensary = dispResult.rows[0];
// Get category price comparison
const result = await this.pool.query(`
WITH store_prices AS (
SELECT
category,
AVG(price_rec) AS store_avg,
COUNT(*) AS product_count
FROM store_products
WHERE dispensary_id = $1
AND price_rec IS NOT NULL
AND is_in_stock = TRUE
AND category IS NOT NULL
GROUP BY category
),
market_prices AS (
SELECT
sp.category_raw,
AVG(sp.price_rec) AS market_avg
FROM store_products sp
JOIN dispensaries d ON d.id = sp.dispensary_id
WHERE d.state_id = $2
AND sp.price_rec IS NOT NULL
AND sp.is_in_stock = TRUE
AND sp.category_raw IS NOT NULL
GROUP BY sp.category_raw
)
SELECT
sp.category_raw,
sp.store_avg AS store_avg_price,
mp.market_avg AS market_avg_price,
ROUND(((sp.store_avg - mp.market_avg) / NULLIF(mp.market_avg, 0) * 100)::NUMERIC, 2) AS price_vs_market_percent,
sp.product_count
FROM store_prices sp
LEFT JOIN market_prices mp ON mp.category = sp.category_raw
ORDER BY sp.product_count DESC
`, [dispensaryId, dispensary.state_id]);
// Calculate overall
const overallResult = await this.pool.query(`
WITH store_avg AS (
SELECT AVG(price_rec) AS avg
FROM store_products
WHERE dispensary_id = $1 AND price_rec IS NOT NULL AND is_in_stock = TRUE
),
market_avg AS (
SELECT AVG(sp.price_rec) AS avg
FROM store_products sp
JOIN dispensaries d ON d.id = sp.dispensary_id
WHERE d.state_id = $2 AND sp.price_rec IS NOT NULL AND sp.is_in_stock = TRUE
)
SELECT
ROUND(((sa.avg - ma.avg) / NULLIF(ma.avg, 0) * 100)::NUMERIC, 2) AS price_vs_market
FROM store_avg sa, market_avg ma
`, [dispensaryId, dispensary.state_id]);
return {
dispensary_id: dispensaryId,
dispensary_name: dispensary.name,
categories: result.rows.map((row: any) => ({
category: row.category_raw,
store_avg_price: parseFloat(row.store_avg_price),
market_avg_price: row.market_avg_price ? parseFloat(row.market_avg_price) : 0,
price_vs_market_percent: row.price_vs_market_percent ? parseFloat(row.price_vs_market_percent) : 0,
product_count: parseInt(row.product_count),
})),
overall_price_vs_market_percent: overallResult.rows[0]?.price_vs_market
? parseFloat(overallResult.rows[0].price_vs_market)
: null,
};
}
}
export default StoreAnalyticsService;