Prevents long decimal numbers like 37.805740635007325 from displaying in the UI. Now shows clean values like 37.81. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
925 lines
32 KiB
TypeScript
925 lines
32 KiB
TypeScript
/**
|
|
* StateQueryService
|
|
*
|
|
* Core service for multi-state queries and analytics.
|
|
* Phase 4: Multi-State Expansion
|
|
*/
|
|
|
|
import { Pool } from 'pg';
|
|
import {
|
|
State,
|
|
StateMetrics,
|
|
StateSummary,
|
|
BrandInState,
|
|
BrandStatePenetration,
|
|
BrandCrossStateComparison,
|
|
CategoryInState,
|
|
CategoryStateDist,
|
|
CategoryCrossStateComparison,
|
|
StoreInState,
|
|
StatePriceDistribution,
|
|
NationalSummary,
|
|
NationalPenetrationTrend,
|
|
StateHeatmapData,
|
|
StateQueryOptions,
|
|
CrossStateQueryOptions,
|
|
} from './types';
|
|
|
|
export class StateQueryService {
|
|
constructor(private pool: Pool) {}
|
|
|
|
// =========================================================================
|
|
// State List & Basic Queries
|
|
// =========================================================================
|
|
|
|
/**
|
|
* Get all available states
|
|
*/
|
|
async listStates(): Promise<State[]> {
|
|
const result = await this.pool.query(`
|
|
SELECT code, name
|
|
FROM states
|
|
ORDER BY name
|
|
`);
|
|
return result.rows;
|
|
}
|
|
|
|
/**
|
|
* Get states that have dispensary data
|
|
*/
|
|
async listActiveStates(): Promise<State[]> {
|
|
const result = await this.pool.query(`
|
|
SELECT DISTINCT s.code, s.name
|
|
FROM states s
|
|
JOIN dispensaries d ON d.state = s.code
|
|
WHERE d.menu_type IS NOT NULL
|
|
ORDER BY s.name
|
|
`);
|
|
return result.rows;
|
|
}
|
|
|
|
// =========================================================================
|
|
// State Summary & Metrics
|
|
// =========================================================================
|
|
|
|
/**
|
|
* Get summary metrics for a single state
|
|
*/
|
|
async getStateSummary(state: string): Promise<StateSummary | null> {
|
|
// Get base metrics from materialized view
|
|
// Migration 051 uses dispensary_count column (not store_count)
|
|
const metricsResult = await this.pool.query(`
|
|
SELECT
|
|
state,
|
|
state_name AS "stateName",
|
|
COALESCE(dispensary_count, 0) AS "storeCount",
|
|
COALESCE(dispensary_count, 0) AS "dutchieStores",
|
|
COALESCE(dispensary_count, 0) AS "activeStores",
|
|
COALESCE(total_products, 0) AS "totalProducts",
|
|
COALESCE(in_stock_products, 0) AS "inStockProducts",
|
|
COALESCE(out_of_stock_products, 0) AS "outOfStockProducts",
|
|
COALESCE(unique_brands, 0) AS "uniqueBrands",
|
|
COALESCE(unique_categories, 0) AS "uniqueCategories",
|
|
avg_price_rec AS "avgPriceRec",
|
|
min_price_rec AS "minPriceRec",
|
|
max_price_rec AS "maxPriceRec",
|
|
refreshed_at AS "refreshedAt"
|
|
FROM mv_state_metrics
|
|
WHERE state = $1
|
|
`, [state]);
|
|
|
|
if (metricsResult.rows.length === 0) {
|
|
return null;
|
|
}
|
|
|
|
const metrics = metricsResult.rows[0];
|
|
|
|
// Get crawl stats
|
|
const crawlResult = await this.pool.query(`
|
|
SELECT
|
|
COUNT(*) FILTER (WHERE cr.status = 'success' AND cr.started_at > NOW() - INTERVAL '24 hours') AS recent_crawls,
|
|
COUNT(*) FILTER (WHERE cr.status = 'failed' AND cr.started_at > NOW() - INTERVAL '24 hours') AS failed_crawls,
|
|
MAX(cr.finished_at) AS last_crawl_at
|
|
FROM crawl_runs cr
|
|
JOIN dispensaries d ON cr.dispensary_id = d.id
|
|
WHERE d.state = $1
|
|
`, [state]);
|
|
|
|
// Get top brands
|
|
const topBrands = await this.getBrandsByState(state, { limit: 5 });
|
|
|
|
// Get top categories
|
|
const topCategories = await this.getCategoriesByState(state, { limit: 5 });
|
|
|
|
// Parse numeric values from strings (PostgreSQL returns bigint as string)
|
|
return {
|
|
state: metrics.state,
|
|
stateName: metrics.stateName,
|
|
storeCount: parseInt(metrics.storeCount || '0', 10),
|
|
dutchieStores: parseInt(metrics.dutchieStores || '0', 10),
|
|
activeStores: parseInt(metrics.activeStores || '0', 10),
|
|
totalProducts: parseInt(metrics.totalProducts || '0', 10),
|
|
inStockProducts: parseInt(metrics.inStockProducts || '0', 10),
|
|
outOfStockProducts: parseInt(metrics.outOfStockProducts || '0', 10),
|
|
onSpecialProducts: parseInt(metrics.onSpecialProducts || '0', 10),
|
|
uniqueBrands: parseInt(metrics.uniqueBrands || '0', 10),
|
|
uniqueCategories: parseInt(metrics.uniqueCategories || '0', 10),
|
|
avgPriceRec: metrics.avgPriceRec ? parseFloat(metrics.avgPriceRec) : null,
|
|
minPriceRec: metrics.minPriceRec ? parseFloat(metrics.minPriceRec) : null,
|
|
maxPriceRec: metrics.maxPriceRec ? parseFloat(metrics.maxPriceRec) : null,
|
|
refreshedAt: metrics.refreshedAt,
|
|
recentCrawls: parseInt(crawlResult.rows[0]?.recent_crawls || '0', 10),
|
|
failedCrawls: parseInt(crawlResult.rows[0]?.failed_crawls || '0', 10),
|
|
lastCrawlAt: crawlResult.rows[0]?.last_crawl_at || null,
|
|
topBrands,
|
|
topCategories,
|
|
};
|
|
}
|
|
|
|
/**
|
|
* Get metrics for all states (including states with no data)
|
|
*/
|
|
async getAllStateMetrics(): Promise<StateMetrics[]> {
|
|
// Migration 051 uses dispensary_count column (not store_count)
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
s.code AS state,
|
|
s.name AS "stateName",
|
|
COALESCE(m.dispensary_count, 0) AS "storeCount",
|
|
COALESCE(m.dispensary_count, 0) AS "dutchieStores",
|
|
COALESCE(m.dispensary_count, 0) AS "activeStores",
|
|
COALESCE(m.total_products, 0) AS "totalProducts",
|
|
COALESCE(m.in_stock_products, 0) AS "inStockProducts",
|
|
COALESCE(m.out_of_stock_products, 0) AS "outOfStockProducts",
|
|
COALESCE(m.unique_brands, 0) AS "uniqueBrands",
|
|
COALESCE(m.unique_categories, 0) AS "uniqueCategories",
|
|
m.avg_price_rec AS "avgPriceRec",
|
|
m.min_price_rec AS "minPriceRec",
|
|
m.max_price_rec AS "maxPriceRec",
|
|
m.refreshed_at AS "refreshedAt",
|
|
0 AS "onSpecialProducts"
|
|
FROM states s
|
|
LEFT JOIN mv_state_metrics m ON s.code = m.state
|
|
ORDER BY COALESCE(m.dispensary_count, 0) DESC, s.name ASC
|
|
`);
|
|
// Parse numeric values from strings (PostgreSQL returns bigint as string)
|
|
return result.rows.map((row: any) => ({
|
|
state: row.state,
|
|
stateName: row.stateName,
|
|
storeCount: parseInt(row.storeCount || '0', 10),
|
|
dutchieStores: parseInt(row.dutchieStores || '0', 10),
|
|
activeStores: parseInt(row.activeStores || '0', 10),
|
|
totalProducts: parseInt(row.totalProducts || '0', 10),
|
|
inStockProducts: parseInt(row.inStockProducts || '0', 10),
|
|
outOfStockProducts: parseInt(row.outOfStockProducts || '0', 10),
|
|
uniqueBrands: parseInt(row.uniqueBrands || '0', 10),
|
|
uniqueCategories: parseInt(row.uniqueCategories || '0', 10),
|
|
avgPriceRec: row.avgPriceRec ? parseFloat(row.avgPriceRec) : null,
|
|
minPriceRec: row.minPriceRec ? parseFloat(row.minPriceRec) : null,
|
|
maxPriceRec: row.maxPriceRec ? parseFloat(row.maxPriceRec) : null,
|
|
refreshedAt: row.refreshedAt,
|
|
onSpecialProducts: parseInt(row.onSpecialProducts || '0', 10),
|
|
}));
|
|
}
|
|
|
|
// =========================================================================
|
|
// Brand Queries
|
|
// =========================================================================
|
|
|
|
/**
|
|
* Get brands present in a specific state
|
|
* Uses inline query instead of v_brand_state_presence view for compatibility
|
|
*/
|
|
async getBrandsByState(state: string, options: StateQueryOptions = {}): Promise<BrandInState[]> {
|
|
const { limit = 50, offset = 0, sortBy = 'productCount', sortDir = 'desc' } = options;
|
|
|
|
// Sort columns must reference the aliased output names with quotes
|
|
const sortColumn = {
|
|
productCount: '"productCount"',
|
|
storeCount: '"storeCount"',
|
|
avgPrice: '"avgPrice"',
|
|
name: '"brandName"',
|
|
}[sortBy] || '"productCount"';
|
|
|
|
// Inline query that aggregates brand data from store_products and dispensaries
|
|
// Works whether or not v_brand_state_presence view exists
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
COALESCE(sp.brand_id, 0) AS "brandId",
|
|
sp.brand_name_raw AS "brandName",
|
|
LOWER(REPLACE(sp.brand_name_raw, ' ', '-')) AS "brandSlug",
|
|
COUNT(DISTINCT d.id) AS "storeCount",
|
|
COUNT(DISTINCT sp.id) AS "productCount",
|
|
ROUND(AVG(sp.price_rec)::numeric, 2) AS "avgPrice",
|
|
MIN(sp.first_seen_at) AS "firstSeenInState",
|
|
MAX(sp.last_seen_at) AS "lastSeenInState"
|
|
FROM store_products sp
|
|
JOIN dispensaries d ON sp.dispensary_id = d.id
|
|
WHERE d.state = $1
|
|
AND sp.brand_name_raw IS NOT NULL
|
|
AND sp.brand_name_raw != ''
|
|
GROUP BY sp.brand_id, sp.brand_name_raw
|
|
ORDER BY ${sortColumn} ${sortDir === 'asc' ? 'ASC' : 'DESC'}
|
|
LIMIT $2 OFFSET $3
|
|
`, [state, limit, offset]);
|
|
|
|
return result.rows;
|
|
}
|
|
|
|
/**
|
|
* Get brand penetration across all states
|
|
* Uses inline query instead of fn_brand_state_penetration function for compatibility
|
|
*/
|
|
async getBrandStatePenetration(brandId: number): Promise<BrandStatePenetration[]> {
|
|
// Inline query that calculates brand penetration by state
|
|
const result = await this.pool.query(`
|
|
WITH state_totals AS (
|
|
SELECT
|
|
d.state,
|
|
s.name AS state_name,
|
|
COUNT(DISTINCT d.id) AS total_stores
|
|
FROM dispensaries d
|
|
JOIN states s ON d.state = s.code
|
|
WHERE d.state IS NOT NULL
|
|
GROUP BY d.state, s.name
|
|
),
|
|
brand_presence AS (
|
|
SELECT
|
|
d.state,
|
|
COUNT(DISTINCT d.id) AS stores_with_brand,
|
|
COUNT(DISTINCT sp.id) AS product_count,
|
|
ROUND(AVG(sp.price_rec)::numeric, 2) AS avg_price
|
|
FROM store_products sp
|
|
JOIN dispensaries d ON sp.dispensary_id = d.id
|
|
WHERE (sp.brand_id = $1 OR sp.brand_name_raw = (SELECT name FROM brands WHERE id = $1))
|
|
AND d.state IS NOT NULL
|
|
GROUP BY d.state
|
|
)
|
|
SELECT
|
|
st.state,
|
|
st.state_name AS "stateName",
|
|
st.total_stores AS "totalStores",
|
|
COALESCE(bp.stores_with_brand, 0) AS "storesWithBrand",
|
|
CASE
|
|
WHEN st.total_stores > 0
|
|
THEN ROUND((COALESCE(bp.stores_with_brand, 0)::numeric / st.total_stores) * 100, 2)
|
|
ELSE 0
|
|
END AS "penetrationPct",
|
|
COALESCE(bp.product_count, 0) AS "productCount",
|
|
bp.avg_price AS "avgPrice"
|
|
FROM state_totals st
|
|
LEFT JOIN brand_presence bp ON st.state = bp.state
|
|
ORDER BY COALESCE(bp.stores_with_brand, 0) DESC
|
|
`, [brandId]);
|
|
|
|
return result.rows;
|
|
}
|
|
|
|
/**
|
|
* Compare a brand across multiple states
|
|
*/
|
|
async compareBrandAcrossStates(
|
|
brandId: number,
|
|
states: string[]
|
|
): Promise<BrandCrossStateComparison> {
|
|
// Get brand info
|
|
const brandResult = await this.pool.query(`
|
|
SELECT id, name FROM brands WHERE id = $1
|
|
`, [brandId]);
|
|
|
|
if (brandResult.rows.length === 0) {
|
|
throw new Error(`Brand ${brandId} not found`);
|
|
}
|
|
|
|
const brand = brandResult.rows[0];
|
|
|
|
// Get penetration for specified states
|
|
const allPenetration = await this.getBrandStatePenetration(brandId);
|
|
const filteredStates = allPenetration.filter(p => states.includes(p.state));
|
|
|
|
// Calculate national metrics
|
|
const nationalResult = await this.pool.query(`
|
|
SELECT
|
|
COUNT(DISTINCT d.id) AS total_stores,
|
|
COUNT(DISTINCT CASE WHEN sp.brand_id = $1 THEN d.id END) AS stores_with_brand,
|
|
AVG(sp.price_rec) FILTER (WHERE sp.brand_id = $1) AS avg_price
|
|
FROM dispensaries d
|
|
LEFT JOIN store_products sp ON d.id = sp.dispensary_id
|
|
WHERE d.state IS NOT NULL
|
|
`, [brandId]);
|
|
|
|
const nationalData = nationalResult.rows[0];
|
|
const nationalPenetration = nationalData.total_stores > 0
|
|
? (nationalData.stores_with_brand / nationalData.total_stores) * 100
|
|
: 0;
|
|
|
|
// Find best/worst states
|
|
const sortedByPenetration = [...filteredStates].sort(
|
|
(a, b) => b.penetrationPct - a.penetrationPct
|
|
);
|
|
|
|
return {
|
|
brandId,
|
|
brandName: brand.name,
|
|
states: filteredStates,
|
|
nationalPenetration: Math.round(nationalPenetration * 100) / 100,
|
|
nationalAvgPrice: nationalData.avg_price
|
|
? Math.round(nationalData.avg_price * 100) / 100
|
|
: null,
|
|
bestPerformingState: sortedByPenetration[0]?.state || null,
|
|
worstPerformingState: sortedByPenetration[sortedByPenetration.length - 1]?.state || null,
|
|
};
|
|
}
|
|
|
|
/**
|
|
* Compare a brand by name across multiple states
|
|
* Used when we only have a brand name (not an ID from the brands table)
|
|
*/
|
|
async compareBrandByNameAcrossStates(
|
|
brandName: string,
|
|
states: string[]
|
|
): Promise<BrandCrossStateComparison> {
|
|
// Get penetration data by brand name
|
|
const penetrationResult = await this.pool.query(`
|
|
WITH state_totals AS (
|
|
SELECT
|
|
d.state,
|
|
s.name AS state_name,
|
|
COUNT(DISTINCT d.id) AS total_stores
|
|
FROM dispensaries d
|
|
JOIN states s ON d.state = s.code
|
|
WHERE d.state IS NOT NULL
|
|
GROUP BY d.state, s.name
|
|
),
|
|
brand_presence AS (
|
|
SELECT
|
|
d.state,
|
|
COUNT(DISTINCT d.id) AS stores_with_brand,
|
|
COUNT(DISTINCT sp.id) AS product_count,
|
|
ROUND(AVG(sp.price_rec)::numeric, 2) AS avg_price
|
|
FROM store_products sp
|
|
JOIN dispensaries d ON sp.dispensary_id = d.id
|
|
WHERE sp.brand_name_raw ILIKE $1
|
|
AND d.state IS NOT NULL
|
|
GROUP BY d.state
|
|
)
|
|
SELECT
|
|
st.state,
|
|
st.state_name AS "stateName",
|
|
st.total_stores AS "totalStores",
|
|
COALESCE(bp.stores_with_brand, 0) AS "storesWithBrand",
|
|
CASE
|
|
WHEN st.total_stores > 0
|
|
THEN ROUND((COALESCE(bp.stores_with_brand, 0)::numeric / st.total_stores) * 100, 2)
|
|
ELSE 0
|
|
END AS "penetrationPct",
|
|
COALESCE(bp.product_count, 0) AS "productCount",
|
|
bp.avg_price AS "avgPrice"
|
|
FROM state_totals st
|
|
LEFT JOIN brand_presence bp ON st.state = bp.state
|
|
ORDER BY COALESCE(bp.stores_with_brand, 0) DESC
|
|
`, [brandName]);
|
|
|
|
// Filter by requested states
|
|
const filteredStates = penetrationResult.rows.filter((p: any) =>
|
|
states.includes(p.state)
|
|
);
|
|
|
|
// Calculate national metrics
|
|
const nationalResult = await this.pool.query(`
|
|
SELECT
|
|
COUNT(DISTINCT d.id) AS total_stores,
|
|
COUNT(DISTINCT CASE WHEN sp.brand_name_raw ILIKE $1 THEN d.id END) AS stores_with_brand,
|
|
AVG(sp.price_rec) FILTER (WHERE sp.brand_name_raw ILIKE $1) AS avg_price
|
|
FROM dispensaries d
|
|
LEFT JOIN store_products sp ON d.id = sp.dispensary_id
|
|
WHERE d.state IS NOT NULL
|
|
`, [brandName]);
|
|
|
|
const nationalData = nationalResult.rows[0];
|
|
const nationalPenetration = nationalData.total_stores > 0
|
|
? (nationalData.stores_with_brand / nationalData.total_stores) * 100
|
|
: 0;
|
|
|
|
// Find best/worst states
|
|
const sortedByPenetration = [...filteredStates].sort(
|
|
(a: any, b: any) => parseFloat(b.penetrationPct) - parseFloat(a.penetrationPct)
|
|
);
|
|
|
|
return {
|
|
brandId: 0, // No ID when using brand name
|
|
brandName,
|
|
states: filteredStates,
|
|
nationalPenetration: Math.round(nationalPenetration * 100) / 100,
|
|
nationalAvgPrice: nationalData.avg_price
|
|
? Math.round(parseFloat(nationalData.avg_price) * 100) / 100
|
|
: null,
|
|
bestPerformingState: sortedByPenetration[0]?.state || null,
|
|
worstPerformingState: sortedByPenetration[sortedByPenetration.length - 1]?.state || null,
|
|
};
|
|
}
|
|
|
|
// =========================================================================
|
|
// Category Queries
|
|
// =========================================================================
|
|
|
|
/**
|
|
* Get categories in a specific state
|
|
* Uses inline query instead of v_category_state_distribution view for compatibility
|
|
*/
|
|
async getCategoriesByState(state: string, options: StateQueryOptions = {}): Promise<CategoryInState[]> {
|
|
const { limit = 50, offset = 0, sortBy = 'productCount', sortDir = 'desc' } = options;
|
|
|
|
// Sort columns must reference the aliased output names with quotes
|
|
const sortColumn = {
|
|
productCount: '"productCount"',
|
|
storeCount: '"storeCount"',
|
|
avgPrice: '"avgPrice"',
|
|
category: 'category',
|
|
}[sortBy] || '"productCount"';
|
|
|
|
// Inline query that aggregates category data from store_products and dispensaries
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
sp.category_raw AS category,
|
|
COUNT(DISTINCT sp.id) AS "productCount",
|
|
COUNT(DISTINCT d.id) AS "storeCount",
|
|
ROUND(AVG(sp.price_rec)::numeric, 2) AS "avgPrice",
|
|
COUNT(DISTINCT CASE WHEN sp.is_in_stock THEN sp.id END) AS "inStockCount",
|
|
0 AS "onSpecialCount"
|
|
FROM store_products sp
|
|
JOIN dispensaries d ON sp.dispensary_id = d.id
|
|
WHERE d.state = $1
|
|
AND sp.category_raw IS NOT NULL
|
|
AND sp.category_raw != ''
|
|
GROUP BY sp.category_raw
|
|
ORDER BY ${sortColumn} ${sortDir === 'asc' ? 'ASC' : 'DESC'}
|
|
LIMIT $2 OFFSET $3
|
|
`, [state, limit, offset]);
|
|
|
|
return result.rows;
|
|
}
|
|
|
|
/**
|
|
* Compare a category across multiple states
|
|
* Uses inline query instead of v_category_state_distribution view for compatibility
|
|
*/
|
|
async compareCategoryAcrossStates(
|
|
category: string,
|
|
states: string[]
|
|
): Promise<CategoryCrossStateComparison> {
|
|
// Inline query for category distribution by state
|
|
const result = await this.pool.query(`
|
|
WITH category_stats AS (
|
|
SELECT
|
|
d.state,
|
|
sp.category_raw AS category,
|
|
COUNT(DISTINCT sp.id) AS product_count,
|
|
COUNT(DISTINCT d.id) AS store_count,
|
|
ROUND(AVG(sp.price_rec)::numeric, 2) AS avg_price
|
|
FROM store_products sp
|
|
JOIN dispensaries d ON sp.dispensary_id = d.id
|
|
WHERE sp.category_raw = $1
|
|
AND d.state = ANY($2)
|
|
GROUP BY d.state, sp.category_raw
|
|
)
|
|
SELECT
|
|
cs.state,
|
|
s.name AS "stateName",
|
|
cs.category,
|
|
cs.product_count AS "productCount",
|
|
cs.store_count AS "storeCount",
|
|
cs.avg_price AS "avgPrice",
|
|
ROUND(cs.product_count::NUMERIC / NULLIF(SUM(cs.product_count) OVER (), 0) * 100, 2) AS "marketShare"
|
|
FROM category_stats cs
|
|
JOIN states s ON cs.state = s.code
|
|
ORDER BY cs.product_count DESC
|
|
`, [category, states]);
|
|
|
|
// Get national totals
|
|
const nationalResult = await this.pool.query(`
|
|
SELECT
|
|
COUNT(DISTINCT sp.id) AS product_count,
|
|
AVG(sp.price_rec) AS avg_price
|
|
FROM store_products sp
|
|
WHERE sp.category_raw = $1
|
|
`, [category]);
|
|
|
|
const national = nationalResult.rows[0];
|
|
|
|
// Find dominant state
|
|
const dominantState = result.rows.length > 0 ? result.rows[0].state : null;
|
|
|
|
return {
|
|
category,
|
|
states: result.rows,
|
|
nationalProductCount: parseInt(national.product_count || '0'),
|
|
nationalAvgPrice: national.avg_price
|
|
? Math.round(national.avg_price * 100) / 100
|
|
: null,
|
|
dominantState,
|
|
};
|
|
}
|
|
|
|
// =========================================================================
|
|
// Store Queries
|
|
// =========================================================================
|
|
|
|
/**
|
|
* Get stores in a specific state
|
|
* Uses inline query for compatibility - does not depend on v_store_state_summary view
|
|
*/
|
|
async getStoresByState(state: string, options: StateQueryOptions = {}): Promise<StoreInState[]> {
|
|
const { limit = 100, offset = 0, includeInactive = false, sortBy = 'productCount', sortDir = 'desc' } = options;
|
|
|
|
// Sort columns must reference the aliased output names with quotes
|
|
const sortColumn = {
|
|
productCount: '"productCount"',
|
|
brandCount: '"brandCount"',
|
|
avgPrice: '"avgPrice"',
|
|
name: '"dispensaryName"',
|
|
city: 'city',
|
|
lastCrawl: '"lastCrawlAt"',
|
|
}[sortBy] || '"productCount"';
|
|
|
|
let whereClause = 'WHERE d.state = $1';
|
|
if (!includeInactive) {
|
|
// Use stage column instead of crawl_status (which doesn't exist)
|
|
whereClause += ` AND (d.stage IS NULL OR d.stage NOT IN ('disabled', 'failing'))`;
|
|
}
|
|
|
|
// Inline query that aggregates store data from dispensaries and store_products
|
|
// Works whether or not v_store_state_summary view exists
|
|
// Uses 'stage' column instead of 'crawl_status' which doesn't exist in this schema
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
d.id AS "dispensaryId",
|
|
d.name AS "dispensaryName",
|
|
d.slug AS "dispensarySlug",
|
|
d.state,
|
|
d.city,
|
|
d.menu_type AS "menuType",
|
|
d.stage AS "crawlStatus",
|
|
d.last_crawl_at AS "lastCrawlAt",
|
|
COUNT(DISTINCT sp.id) AS "productCount",
|
|
COUNT(DISTINCT CASE WHEN sp.is_in_stock THEN sp.id END) AS "inStockCount",
|
|
COUNT(DISTINCT sp.brand_id) AS "brandCount",
|
|
ROUND(AVG(sp.price_rec)::numeric, 2) AS "avgPrice",
|
|
COUNT(DISTINCT CASE WHEN sp.is_on_special THEN sp.id END) AS "specialCount"
|
|
FROM dispensaries d
|
|
LEFT JOIN store_products sp ON d.id = sp.dispensary_id
|
|
${whereClause}
|
|
GROUP BY d.id, d.name, d.slug, d.state, d.city, d.menu_type, d.stage, d.last_crawl_at
|
|
ORDER BY ${sortColumn} ${sortDir === 'asc' ? 'ASC' : 'DESC'} NULLS LAST
|
|
LIMIT $2 OFFSET $3
|
|
`, [state, limit, offset]);
|
|
|
|
return result.rows;
|
|
}
|
|
|
|
// =========================================================================
|
|
// Price Analytics
|
|
// =========================================================================
|
|
|
|
/**
|
|
* Get price distribution by state
|
|
* Uses inline query instead of fn_national_price_comparison for compatibility
|
|
*/
|
|
async getStorePriceDistribution(
|
|
state: string,
|
|
options: { category?: string; brandId?: number } = {}
|
|
): Promise<StatePriceDistribution[]> {
|
|
const { category, brandId } = options;
|
|
|
|
// Build WHERE conditions dynamically
|
|
const conditions = ['d.state = $1', 'sp.price_rec IS NOT NULL', 'sp.price_rec > 0'];
|
|
const params: any[] = [state];
|
|
let paramIndex = 2;
|
|
|
|
if (category) {
|
|
conditions.push(`sp.category_raw = $${paramIndex}`);
|
|
params.push(category);
|
|
paramIndex++;
|
|
}
|
|
if (brandId) {
|
|
conditions.push(`sp.brand_id = $${paramIndex}`);
|
|
params.push(brandId);
|
|
paramIndex++;
|
|
}
|
|
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
d.state,
|
|
s.name AS state_name,
|
|
COUNT(DISTINCT sp.id) AS product_count,
|
|
ROUND(AVG(sp.price_rec)::numeric, 2) AS avg_price,
|
|
MIN(sp.price_rec) AS min_price,
|
|
MAX(sp.price_rec) AS max_price,
|
|
ROUND(PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY sp.price_rec)::numeric, 2) AS median_price,
|
|
ROUND(STDDEV(sp.price_rec)::numeric, 2) AS price_stddev
|
|
FROM dispensaries d
|
|
JOIN states s ON d.state = s.code
|
|
JOIN store_products sp ON d.id = sp.dispensary_id
|
|
WHERE ${conditions.join(' AND ')}
|
|
GROUP BY d.state, s.name
|
|
ORDER BY avg_price DESC
|
|
`, params);
|
|
|
|
return result.rows.map(row => ({
|
|
state: row.state,
|
|
stateName: row.state_name,
|
|
productCount: parseInt(row.product_count || '0'),
|
|
avgPrice: parseFloat(row.avg_price || '0'),
|
|
minPrice: parseFloat(row.min_price || '0'),
|
|
maxPrice: parseFloat(row.max_price || '0'),
|
|
medianPrice: parseFloat(row.median_price || '0'),
|
|
priceStddev: parseFloat(row.price_stddev || '0'),
|
|
}));
|
|
}
|
|
|
|
/**
|
|
* Get national price comparison across all states
|
|
* Uses inline query instead of fn_national_price_comparison for compatibility
|
|
*/
|
|
async getNationalPriceComparison(
|
|
options: { category?: string; brandId?: number } = {}
|
|
): Promise<StatePriceDistribution[]> {
|
|
const { category, brandId } = options;
|
|
|
|
// Build WHERE conditions dynamically
|
|
const conditions = ['d.state IS NOT NULL', 'sp.price_rec IS NOT NULL', 'sp.price_rec > 0'];
|
|
const params: any[] = [];
|
|
let paramIndex = 1;
|
|
|
|
if (category) {
|
|
conditions.push(`sp.category_raw = $${paramIndex}`);
|
|
params.push(category);
|
|
paramIndex++;
|
|
}
|
|
if (brandId) {
|
|
conditions.push(`sp.brand_id = $${paramIndex}`);
|
|
params.push(brandId);
|
|
paramIndex++;
|
|
}
|
|
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
d.state,
|
|
s.name AS state_name,
|
|
COUNT(DISTINCT sp.id) AS product_count,
|
|
ROUND(AVG(sp.price_rec)::numeric, 2) AS avg_price,
|
|
MIN(sp.price_rec) AS min_price,
|
|
MAX(sp.price_rec) AS max_price,
|
|
ROUND(PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY sp.price_rec)::numeric, 2) AS median_price,
|
|
ROUND(STDDEV(sp.price_rec)::numeric, 2) AS price_stddev
|
|
FROM dispensaries d
|
|
JOIN states s ON d.state = s.code
|
|
JOIN store_products sp ON d.id = sp.dispensary_id
|
|
WHERE ${conditions.join(' AND ')}
|
|
GROUP BY d.state, s.name
|
|
ORDER BY avg_price DESC
|
|
`, params);
|
|
|
|
return result.rows.map(row => ({
|
|
state: row.state,
|
|
stateName: row.state_name,
|
|
productCount: parseInt(row.product_count || '0'),
|
|
avgPrice: parseFloat(row.avg_price || '0'),
|
|
minPrice: parseFloat(row.min_price || '0'),
|
|
maxPrice: parseFloat(row.max_price || '0'),
|
|
medianPrice: parseFloat(row.median_price || '0'),
|
|
priceStddev: parseFloat(row.price_stddev || '0'),
|
|
}));
|
|
}
|
|
|
|
// =========================================================================
|
|
// National Analytics
|
|
// =========================================================================
|
|
|
|
/**
|
|
* Get national summary across all states
|
|
*/
|
|
async getNationalSummary(): Promise<NationalSummary> {
|
|
const stateMetrics = await this.getAllStateMetrics();
|
|
|
|
const result = await this.pool.query(`
|
|
SELECT
|
|
COUNT(DISTINCT s.code) AS total_states,
|
|
COUNT(DISTINCT CASE WHEN EXISTS (
|
|
SELECT 1 FROM dispensaries d WHERE d.state = s.code AND d.menu_type IS NOT NULL
|
|
) THEN s.code END) AS active_states,
|
|
(SELECT COUNT(*) FROM dispensaries WHERE state IS NOT NULL) AS total_stores,
|
|
(SELECT COUNT(*) FROM store_products sp
|
|
JOIN dispensaries d ON sp.dispensary_id = d.id
|
|
WHERE d.state IS NOT NULL) AS total_products,
|
|
(SELECT COUNT(DISTINCT brand_id) FROM store_products sp
|
|
JOIN dispensaries d ON sp.dispensary_id = d.id
|
|
WHERE d.state IS NOT NULL AND sp.brand_id IS NOT NULL) AS total_brands,
|
|
(SELECT AVG(price_rec) FROM store_products sp
|
|
JOIN dispensaries d ON sp.dispensary_id = d.id
|
|
WHERE d.state IS NOT NULL AND sp.price_rec > 0) AS avg_price_national
|
|
FROM states s
|
|
`);
|
|
|
|
const data = result.rows[0];
|
|
|
|
return {
|
|
totalStates: parseInt(data.total_states),
|
|
activeStates: parseInt(data.active_states),
|
|
totalStores: parseInt(data.total_stores),
|
|
totalProducts: parseInt(data.total_products),
|
|
totalBrands: parseInt(data.total_brands),
|
|
avgPriceNational: data.avg_price_national
|
|
? Math.round(parseFloat(data.avg_price_national) * 100) / 100
|
|
: null,
|
|
stateMetrics,
|
|
};
|
|
}
|
|
|
|
/**
|
|
* Get heatmap data for a specific metric
|
|
*/
|
|
async getStateHeatmapData(
|
|
metric: 'stores' | 'products' | 'brands' | 'avgPrice' | 'penetration',
|
|
options: { brandId?: number; category?: string } = {}
|
|
): Promise<StateHeatmapData[]> {
|
|
let query: string;
|
|
let params: any[] = [];
|
|
|
|
switch (metric) {
|
|
case 'stores':
|
|
query = `
|
|
SELECT state, state_name AS "stateName", COALESCE(dispensary_count, 0) AS value, 'stores' AS label
|
|
FROM mv_state_metrics
|
|
WHERE state IS NOT NULL
|
|
ORDER BY state
|
|
`;
|
|
break;
|
|
|
|
case 'products':
|
|
query = `
|
|
SELECT state, state_name AS "stateName", COALESCE(total_products, 0) AS value, 'products' AS label
|
|
FROM mv_state_metrics
|
|
WHERE state IS NOT NULL
|
|
ORDER BY state
|
|
`;
|
|
break;
|
|
|
|
case 'brands':
|
|
query = `
|
|
SELECT state, state_name AS "stateName", COALESCE(unique_brands, 0) AS value, 'brands' AS label
|
|
FROM mv_state_metrics
|
|
WHERE state IS NOT NULL
|
|
ORDER BY state
|
|
`;
|
|
break;
|
|
|
|
case 'avgPrice':
|
|
query = `
|
|
SELECT state, state_name AS "stateName", avg_price_rec AS value, 'avg price' AS label
|
|
FROM mv_state_metrics
|
|
WHERE state IS NOT NULL AND avg_price_rec IS NOT NULL
|
|
ORDER BY state
|
|
`;
|
|
break;
|
|
|
|
case 'penetration':
|
|
if (!options.brandId) {
|
|
throw new Error('brandId required for penetration heatmap');
|
|
}
|
|
// Inline query instead of fn_brand_state_penetration function
|
|
query = `
|
|
WITH state_totals AS (
|
|
SELECT d.state, s.name AS state_name, COUNT(DISTINCT d.id) AS total_stores
|
|
FROM dispensaries d
|
|
JOIN states s ON d.state = s.code
|
|
WHERE d.state IS NOT NULL
|
|
GROUP BY d.state, s.name
|
|
),
|
|
brand_presence AS (
|
|
SELECT d.state, COUNT(DISTINCT d.id) AS stores_with_brand
|
|
FROM store_products sp
|
|
JOIN dispensaries d ON sp.dispensary_id = d.id
|
|
WHERE (sp.brand_id = $1 OR sp.brand_name_raw = (SELECT name FROM brands WHERE id = $1))
|
|
AND d.state IS NOT NULL
|
|
GROUP BY d.state
|
|
)
|
|
SELECT
|
|
st.state,
|
|
st.state_name AS "stateName",
|
|
CASE WHEN st.total_stores > 0
|
|
THEN ROUND((COALESCE(bp.stores_with_brand, 0)::numeric / st.total_stores) * 100, 2)
|
|
ELSE 0 END AS value,
|
|
'penetration %' AS label
|
|
FROM state_totals st
|
|
LEFT JOIN brand_presence bp ON st.state = bp.state
|
|
ORDER BY st.state
|
|
`;
|
|
params = [options.brandId];
|
|
break;
|
|
|
|
default:
|
|
throw new Error(`Unknown metric: ${metric}`);
|
|
}
|
|
|
|
const result = await this.pool.query(query, params);
|
|
// Parse numeric values from strings (PostgreSQL returns bigint as string)
|
|
// Round to 2 decimal places for display
|
|
return result.rows.map((row: any) => ({
|
|
state: row.state,
|
|
stateName: row.stateName,
|
|
value: row.value !== null ? Math.round(parseFloat(row.value) * 100) / 100 : 0,
|
|
label: row.label,
|
|
}));
|
|
}
|
|
|
|
/**
|
|
* Get national penetration trend for a brand
|
|
*/
|
|
async getNationalPenetrationTrend(
|
|
brandId: number,
|
|
options: { days?: number } = {}
|
|
): Promise<NationalPenetrationTrend> {
|
|
const { days = 30 } = options;
|
|
|
|
// Get brand info
|
|
const brandResult = await this.pool.query(`
|
|
SELECT id, name FROM brands WHERE id = $1
|
|
`, [brandId]);
|
|
|
|
if (brandResult.rows.length === 0) {
|
|
throw new Error(`Brand ${brandId} not found`);
|
|
}
|
|
|
|
// Get historical data from snapshots
|
|
const result = await this.pool.query(`
|
|
WITH daily_presence AS (
|
|
SELECT
|
|
DATE(sps.captured_at) AS date,
|
|
COUNT(DISTINCT d.state) AS states_present,
|
|
COUNT(DISTINCT d.id) AS stores_with_brand
|
|
FROM store_product_snapshots sps
|
|
JOIN dispensaries d ON sps.dispensary_id = d.id
|
|
JOIN store_products sp ON sps.store_product_id = sp.id
|
|
WHERE sp.brand_id = $1
|
|
AND sps.captured_at > NOW() - INTERVAL '1 day' * $2
|
|
AND d.state IS NOT NULL
|
|
GROUP BY DATE(sps.captured_at)
|
|
),
|
|
daily_totals AS (
|
|
SELECT
|
|
DATE(sps.captured_at) AS date,
|
|
COUNT(DISTINCT d.id) AS total_stores
|
|
FROM store_product_snapshots sps
|
|
JOIN dispensaries d ON sps.dispensary_id = d.id
|
|
WHERE sps.captured_at > NOW() - INTERVAL '1 day' * $2
|
|
AND d.state IS NOT NULL
|
|
GROUP BY DATE(sps.captured_at)
|
|
)
|
|
SELECT
|
|
dp.date,
|
|
dp.states_present,
|
|
dt.total_stores,
|
|
ROUND(dp.stores_with_brand::NUMERIC / NULLIF(dt.total_stores, 0) * 100, 2) AS penetration_pct
|
|
FROM daily_presence dp
|
|
JOIN daily_totals dt ON dp.date = dt.date
|
|
ORDER BY dp.date
|
|
`, [brandId, days]);
|
|
|
|
return {
|
|
brandId,
|
|
brandName: brandResult.rows[0].name,
|
|
dataPoints: result.rows.map(row => ({
|
|
date: row.date.toISOString().split('T')[0],
|
|
statesPresent: parseInt(row.states_present),
|
|
totalStores: parseInt(row.total_stores),
|
|
penetrationPct: parseFloat(row.penetration_pct || '0'),
|
|
})),
|
|
};
|
|
}
|
|
|
|
// =========================================================================
|
|
// Utility Methods
|
|
// =========================================================================
|
|
|
|
/**
|
|
* Refresh materialized views
|
|
* Uses direct REFRESH MATERIALIZED VIEW for compatibility
|
|
*/
|
|
async refreshMetrics(): Promise<void> {
|
|
// Use direct refresh command instead of function call for better compatibility
|
|
// CONCURRENTLY requires a unique index (idx_mv_state_metrics_state exists)
|
|
await this.pool.query('REFRESH MATERIALIZED VIEW CONCURRENTLY mv_state_metrics');
|
|
}
|
|
|
|
/**
|
|
* Validate state code
|
|
*/
|
|
async isValidState(state: string): Promise<boolean> {
|
|
const result = await this.pool.query(`
|
|
SELECT 1 FROM states WHERE code = $1
|
|
`, [state]);
|
|
return result.rows.length > 0;
|
|
}
|
|
}
|