feat: SEO template library, discovery pipeline, and orchestrator enhancements
## SEO Template Library - Add complete template library with 7 page types (state, city, category, brand, product, search, regeneration) - Add Template Library tab in SEO Orchestrator with accordion-based editors - Add template preview, validation, and variable injection engine - Add API endpoints: /api/seo/templates, preview, validate, generate, regenerate ## Discovery Pipeline - Add promotion.ts for discovery location validation and promotion - Add discover-all-states.ts script for multi-state discovery - Add promotion log migration (067) - Enhance discovery routes and types ## Orchestrator & Admin - Add crawl_enabled filter to stores page - Add API permissions page - Add job queue management - Add price analytics routes - Add markets and intelligence routes - Enhance dashboard and worker monitoring ## Infrastructure - Add migrations for worker definitions, SEO settings, field alignment - Add canonical pipeline for scraper v2 - Update hydration and sync orchestrator - Enhance multi-state query service 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
@@ -67,18 +67,19 @@ export class StateQueryService {
|
||||
*/
|
||||
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",
|
||||
dispensary_count AS "storeCount",
|
||||
dispensary_count AS "dutchieStores",
|
||||
dispensary_count AS "activeStores",
|
||||
total_products AS "totalProducts",
|
||||
in_stock_products AS "inStockProducts",
|
||||
out_of_stock_products AS "outOfStockProducts",
|
||||
unique_brands AS "uniqueBrands",
|
||||
unique_categories AS "uniqueCategories",
|
||||
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",
|
||||
@@ -110,10 +111,24 @@ export class StateQueryService {
|
||||
// Get top categories
|
||||
const topCategories = await this.getCategoriesByState(state, { limit: 5 });
|
||||
|
||||
// Parse numeric values from strings (PostgreSQL returns bigint as string)
|
||||
return {
|
||||
...metrics,
|
||||
recentCrawls: parseInt(crawlResult.rows[0]?.recent_crawls || '0'),
|
||||
failedCrawls: parseInt(crawlResult.rows[0]?.failed_crawls || '0'),
|
||||
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),
|
||||
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,
|
||||
@@ -121,29 +136,49 @@ export class StateQueryService {
|
||||
}
|
||||
|
||||
/**
|
||||
* Get metrics for all states
|
||||
* 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
|
||||
state,
|
||||
state_name AS "stateName",
|
||||
dispensary_count AS "storeCount",
|
||||
dispensary_count AS "dutchieStores",
|
||||
dispensary_count AS "activeStores",
|
||||
total_products AS "totalProducts",
|
||||
in_stock_products AS "inStockProducts",
|
||||
out_of_stock_products AS "outOfStockProducts",
|
||||
unique_brands AS "uniqueBrands",
|
||||
unique_categories 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
|
||||
ORDER BY dispensary_count DESC
|
||||
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
|
||||
`);
|
||||
return result.rows;
|
||||
// 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),
|
||||
}));
|
||||
}
|
||||
|
||||
// =========================================================================
|
||||
@@ -152,29 +187,37 @@ export class StateQueryService {
|
||||
|
||||
/**
|
||||
* 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: 'product_count',
|
||||
storeCount: 'store_count',
|
||||
avgPrice: 'avg_price',
|
||||
name: 'brand_name',
|
||||
}[sortBy] || 'product_count';
|
||||
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
|
||||
brand_id AS "brandId",
|
||||
brand_name AS "brandName",
|
||||
brand_slug AS "brandSlug",
|
||||
store_count AS "storeCount",
|
||||
product_count AS "productCount",
|
||||
avg_price AS "avgPrice",
|
||||
first_seen_in_state AS "firstSeenInState",
|
||||
last_seen_in_state AS "lastSeenInState"
|
||||
FROM v_brand_state_presence
|
||||
WHERE state = $1
|
||||
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]);
|
||||
@@ -184,18 +227,48 @@ export class StateQueryService {
|
||||
|
||||
/**
|
||||
* 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
|
||||
state,
|
||||
state_name AS "stateName",
|
||||
total_stores AS "totalStores",
|
||||
stores_with_brand AS "storesWithBrand",
|
||||
penetration_pct AS "penetrationPct",
|
||||
product_count AS "productCount",
|
||||
avg_price AS "avgPrice"
|
||||
FROM fn_brand_state_penetration($1)
|
||||
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;
|
||||
@@ -257,33 +330,128 @@ export class StateQueryService {
|
||||
};
|
||||
}
|
||||
|
||||
/**
|
||||
* 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: 'product_count',
|
||||
storeCount: 'store_count',
|
||||
avgPrice: 'avg_price',
|
||||
productCount: '"productCount"',
|
||||
storeCount: '"storeCount"',
|
||||
avgPrice: '"avgPrice"',
|
||||
category: 'category',
|
||||
}[sortBy] || 'product_count';
|
||||
}[sortBy] || '"productCount"';
|
||||
|
||||
// Inline query that aggregates category data from store_products and dispensaries
|
||||
const result = await this.pool.query(`
|
||||
SELECT
|
||||
category,
|
||||
product_count AS "productCount",
|
||||
store_count AS "storeCount",
|
||||
avg_price AS "avgPrice",
|
||||
in_stock_count AS "inStockCount",
|
||||
on_special_count AS "onSpecialCount"
|
||||
FROM v_category_state_distribution
|
||||
WHERE state = $1
|
||||
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]);
|
||||
@@ -293,25 +461,38 @@ export class StateQueryService {
|
||||
|
||||
/**
|
||||
* 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
|
||||
v.state,
|
||||
cs.state,
|
||||
s.name AS "stateName",
|
||||
v.category,
|
||||
v.product_count AS "productCount",
|
||||
v.store_count AS "storeCount",
|
||||
v.avg_price AS "avgPrice",
|
||||
ROUND(v.product_count::NUMERIC / SUM(v.product_count) OVER () * 100, 2) AS "marketShare"
|
||||
FROM v_category_state_distribution v
|
||||
JOIN states s ON v.state = s.code
|
||||
WHERE v.category = $1
|
||||
AND v.state = ANY($2)
|
||||
ORDER BY v.product_count DESC
|
||||
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
|
||||
@@ -345,41 +526,49 @@ export class StateQueryService {
|
||||
|
||||
/**
|
||||
* 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: 'product_count',
|
||||
brandCount: 'brand_count',
|
||||
avgPrice: 'avg_price',
|
||||
name: 'dispensary_name',
|
||||
productCount: '"productCount"',
|
||||
brandCount: '"brandCount"',
|
||||
avgPrice: '"avgPrice"',
|
||||
name: '"dispensaryName"',
|
||||
city: 'city',
|
||||
lastCrawl: 'last_crawl_at',
|
||||
}[sortBy] || 'product_count';
|
||||
lastCrawl: '"lastCrawlAt"',
|
||||
}[sortBy] || '"productCount"';
|
||||
|
||||
let whereClause = 'WHERE state = $1';
|
||||
let whereClause = 'WHERE d.state = $1';
|
||||
if (!includeInactive) {
|
||||
whereClause += ` AND crawl_status != 'disabled'`;
|
||||
// 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
|
||||
dispensary_id AS "dispensaryId",
|
||||
dispensary_name AS "dispensaryName",
|
||||
dispensary_slug AS "dispensarySlug",
|
||||
state,
|
||||
city,
|
||||
menu_type AS "menuType",
|
||||
crawl_status AS "crawlStatus",
|
||||
last_crawl_at AS "lastCrawlAt",
|
||||
product_count AS "productCount",
|
||||
in_stock_count AS "inStockCount",
|
||||
brand_count AS "brandCount",
|
||||
avg_price AS "avgPrice",
|
||||
special_count AS "specialCount"
|
||||
FROM v_store_state_summary
|
||||
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]);
|
||||
@@ -393,6 +582,7 @@ export class StateQueryService {
|
||||
|
||||
/**
|
||||
* Get price distribution by state
|
||||
* Uses inline query instead of fn_national_price_comparison for compatibility
|
||||
*/
|
||||
async getStorePriceDistribution(
|
||||
state: string,
|
||||
@@ -400,44 +590,104 @@ export class StateQueryService {
|
||||
): 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 * FROM fn_national_price_comparison($1, $2)
|
||||
WHERE state = $3
|
||||
`, [category || null, brandId || null, state]);
|
||||
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),
|
||||
avgPrice: parseFloat(row.avg_price),
|
||||
minPrice: parseFloat(row.min_price),
|
||||
maxPrice: parseFloat(row.max_price),
|
||||
medianPrice: parseFloat(row.median_price),
|
||||
priceStddev: parseFloat(row.price_stddev),
|
||||
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 * FROM fn_national_price_comparison($1, $2)
|
||||
`, [category || null, brandId || null]);
|
||||
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),
|
||||
avgPrice: parseFloat(row.avg_price),
|
||||
minPrice: parseFloat(row.min_price),
|
||||
maxPrice: parseFloat(row.max_price),
|
||||
medianPrice: parseFloat(row.median_price),
|
||||
priceStddev: parseFloat(row.price_stddev),
|
||||
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'),
|
||||
}));
|
||||
}
|
||||
|
||||
@@ -498,7 +748,7 @@ export class StateQueryService {
|
||||
switch (metric) {
|
||||
case 'stores':
|
||||
query = `
|
||||
SELECT state, state_name AS "stateName", dispensary_count AS value, 'stores' AS label
|
||||
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
|
||||
@@ -507,7 +757,7 @@ export class StateQueryService {
|
||||
|
||||
case 'products':
|
||||
query = `
|
||||
SELECT state, state_name AS "stateName", total_products AS value, 'products' AS label
|
||||
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
|
||||
@@ -516,7 +766,7 @@ export class StateQueryService {
|
||||
|
||||
case 'brands':
|
||||
query = `
|
||||
SELECT state, state_name AS "stateName", unique_brands AS value, 'brands' AS label
|
||||
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
|
||||
@@ -536,10 +786,33 @@ export class StateQueryService {
|
||||
if (!options.brandId) {
|
||||
throw new Error('brandId required for penetration heatmap');
|
||||
}
|
||||
// Inline query instead of fn_brand_state_penetration function
|
||||
query = `
|
||||
SELECT state, state_name AS "stateName", penetration_pct AS value, 'penetration %' AS label
|
||||
FROM fn_brand_state_penetration($1)
|
||||
ORDER BY state
|
||||
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;
|
||||
|
||||
Reference in New Issue
Block a user