/** * Price Analytics API Routes * * Endpoints for price history, specials, and price comparison analytics * Uses the new product_variants and product_variant_snapshots tables */ import { Router, Request, Response } from 'express'; import { pool } from '../db/pool'; const router = Router(); // ============================================================ // PRICE HISTORY // ============================================================ /** * GET /api/price-analytics/products/:id/history * Get price and stock history for a product variant * * Query params: * - days: Number of days to look back (default: 30, max: 90) * - option: Specific variant option (e.g., "1g", "3.5g") */ router.get('/products/:id/history', async (req: Request, res: Response) => { try { const { id } = req.params; const { days = '30', option } = req.query; const daysNum = Math.min(parseInt(days as string, 10) || 30, 90); // Get product info const productResult = await pool.query(` SELECT sp.id, sp.name_raw as name, sp.brand_name_raw as brand, sp.category_raw as category, sp.dispensary_id, d.name as dispensary_name FROM store_products sp JOIN dispensaries d ON d.id = sp.dispensary_id WHERE sp.id = $1 `, [id]); if (productResult.rows.length === 0) { return res.status(404).json({ error: 'Product not found' }); } const product = productResult.rows[0]; // Get variant history let variantQuery = ` SELECT pv.id as variant_id, pv.option, pvs.price_rec, pvs.price_med, pvs.price_rec_special, pvs.price_med_special, pvs.quantity, pvs.in_stock, pvs.is_on_special, pvs.captured_at FROM product_variant_snapshots pvs JOIN product_variants pv ON pv.id = pvs.product_variant_id WHERE pv.store_product_id = $1 AND pvs.captured_at >= NOW() - ($2 || ' days')::INTERVAL `; const params: any[] = [id, daysNum]; if (option) { variantQuery += ` AND pv.option = $3`; params.push(option); } variantQuery += ` ORDER BY pv.option, pvs.captured_at ASC`; const historyResult = await pool.query(variantQuery, params); // Get current variants const currentResult = await pool.query(` SELECT id, option, price_rec, price_med, price_rec_special, price_med_special, quantity, in_stock, is_on_special, last_price_change_at, last_stock_change_at FROM product_variants WHERE store_product_id = $1 ORDER BY option `, [id]); // Get sale stats using the function const saleStatsResult = await pool.query(` SELECT pv.option, (get_variant_sale_stats(pv.id, $2)).* FROM product_variants pv WHERE pv.store_product_id = $1 `, [id, daysNum]); // Group history by variant const historyByVariant: Record = {}; for (const row of historyResult.rows) { if (!historyByVariant[row.option]) { historyByVariant[row.option] = []; } historyByVariant[row.option].push({ 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, quantity: row.quantity, in_stock: row.in_stock, is_on_special: row.is_on_special, captured_at: row.captured_at, }); } res.json({ product: { id: product.id, name: product.name, brand: product.brand, category: product.category, dispensary_id: product.dispensary_id, dispensary_name: product.dispensary_name, }, current_variants: currentResult.rows.map((v: any) => ({ ...v, price_rec: v.price_rec ? parseFloat(v.price_rec) : null, price_med: v.price_med ? parseFloat(v.price_med) : null, price_rec_special: v.price_rec_special ? parseFloat(v.price_rec_special) : null, })), history: historyByVariant, sale_stats: saleStatsResult.rows.reduce((acc: any, row: any) => { acc[row.option] = { total_snapshots: parseInt(row.total_snapshots), times_on_special: parseInt(row.times_on_special), special_frequency_pct: row.special_frequency_pct ? parseFloat(row.special_frequency_pct) : 0, avg_discount_pct: row.avg_discount_pct ? parseFloat(row.avg_discount_pct) : null, min_price: row.min_price ? parseFloat(row.min_price) : null, max_price: row.max_price ? parseFloat(row.max_price) : null, avg_price: row.avg_price ? parseFloat(row.avg_price) : null, }; return acc; }, {}), days: daysNum, }); } catch (error: any) { console.error('Product history error:', error); res.status(500).json({ error: 'Failed to fetch product history', message: error.message }); } }); // ============================================================ // CURRENT SPECIALS // ============================================================ /** * GET /api/price-analytics/specials * Get all products currently on special * * Query params: * - state: Filter by state code * - city: Filter by city * - category: Filter by category * - min_discount: Minimum discount percentage * - limit: Max results (default: 100, max: 500) * - offset: Pagination offset */ router.get('/specials', async (req: Request, res: Response) => { try { const { state, city, category, min_discount = '0', limit = '100', offset = '0', } = req.query; const limitNum = Math.min(parseInt(limit as string, 10) || 100, 500); const offsetNum = parseInt(offset as string, 10) || 0; const minDiscountNum = parseFloat(min_discount as string) || 0; let whereClause = `WHERE pv.is_on_special = TRUE AND pv.in_stock = TRUE`; const params: any[] = []; let paramIndex = 1; if (state) { whereClause += ` AND d.state = $${paramIndex}`; params.push(state); paramIndex++; } if (city) { whereClause += ` AND LOWER(d.city) LIKE LOWER($${paramIndex})`; params.push(`%${city}%`); paramIndex++; } if (category) { whereClause += ` AND LOWER(sp.category_raw) = LOWER($${paramIndex})`; params.push(category); paramIndex++; } // Calculate discount and filter const discountCalc = `ROUND(((pv.price_rec - pv.price_rec_special) / NULLIF(pv.price_rec, 0)) * 100, 1)`; if (minDiscountNum > 0) { whereClause += ` AND ${discountCalc} >= $${paramIndex}`; params.push(minDiscountNum); paramIndex++; } params.push(limitNum, offsetNum); const { rows: specials } = await pool.query(` SELECT pv.id as variant_id, sp.id as product_id, sp.name_raw as product_name, sp.brand_name_raw as brand_name, sp.category_raw as category, sp.image_url, d.id as dispensary_id, d.name as dispensary_name, d.city, d.state, pv.option, pv.price_rec, pv.price_rec_special, ${discountCalc} as discount_percent, pv.quantity, pv.last_seen_at FROM product_variants pv JOIN store_products sp ON sp.id = pv.store_product_id JOIN dispensaries d ON d.id = pv.dispensary_id ${whereClause} AND pv.price_rec_special IS NOT NULL AND pv.price_rec_special < pv.price_rec ORDER BY ${discountCalc} DESC LIMIT $${paramIndex} OFFSET $${paramIndex + 1} `, params); // Get count const countParams = params.slice(0, -2); const { rows: countRows } = await pool.query(` SELECT COUNT(*) as total FROM product_variants pv JOIN store_products sp ON sp.id = pv.store_product_id JOIN dispensaries d ON d.id = pv.dispensary_id ${whereClause} AND pv.price_rec_special IS NOT NULL AND pv.price_rec_special < pv.price_rec `, countParams); res.json({ specials: specials.map((s: any) => ({ ...s, price_rec: s.price_rec ? parseFloat(s.price_rec) : null, price_rec_special: s.price_rec_special ? parseFloat(s.price_rec_special) : null, discount_percent: s.discount_percent ? parseFloat(s.discount_percent) : null, })), pagination: { total: parseInt(countRows[0]?.total || '0', 10), limit: limitNum, offset: offsetNum, has_more: offsetNum + specials.length < parseInt(countRows[0]?.total || '0', 10), }, }); } catch (error: any) { console.error('Specials error:', error); res.status(500).json({ error: 'Failed to fetch specials', message: error.message }); } }); // ============================================================ // PRICE COMPARISON // ============================================================ /** * GET /api/price-analytics/compare * Compare prices for a product across stores * * Query params: * - name: Product name to search * - option: Variant option (e.g., "1g", "3.5g") * - state: Filter by state * - limit: Max results (default: 50) */ router.get('/compare', async (req: Request, res: Response) => { try { const { name, option, state, limit = '50' } = req.query; if (!name) { return res.status(400).json({ error: 'Product name is required' }); } const limitNum = Math.min(parseInt(limit as string, 10) || 50, 200); let whereClause = `WHERE sp.name_raw ILIKE $1 AND pv.in_stock = TRUE`; const params: any[] = [`%${name}%`]; let paramIndex = 2; if (option) { whereClause += ` AND pv.option = $${paramIndex}`; params.push(option); paramIndex++; } if (state) { whereClause += ` AND d.state = $${paramIndex}`; params.push(state); paramIndex++; } params.push(limitNum); const { rows } = await pool.query(` SELECT sp.id as product_id, sp.name_raw as product_name, sp.brand_name_raw as brand_name, sp.category_raw as category, sp.image_url, d.id as dispensary_id, d.name as dispensary_name, d.city, d.state, pv.option, pv.price_rec, pv.price_rec_special, pv.is_on_special, pv.quantity, COALESCE(pv.price_rec_special, pv.price_rec) as effective_price, RANK() OVER (PARTITION BY pv.option ORDER BY COALESCE(pv.price_rec_special, pv.price_rec) ASC) as price_rank FROM product_variants pv JOIN store_products sp ON sp.id = pv.store_product_id JOIN dispensaries d ON d.id = pv.dispensary_id ${whereClause} AND (pv.price_rec IS NOT NULL OR pv.price_rec_special IS NOT NULL) ORDER BY pv.option, effective_price ASC LIMIT $${paramIndex} `, params); // Group by option const byOption: Record = {}; for (const row of rows) { if (!byOption[row.option]) { byOption[row.option] = []; } byOption[row.option].push({ product_id: row.product_id, product_name: row.product_name, brand_name: row.brand_name, category: row.category, image_url: row.image_url, dispensary_id: row.dispensary_id, dispensary_name: row.dispensary_name, city: row.city, state: row.state, price_rec: row.price_rec ? parseFloat(row.price_rec) : null, price_rec_special: row.price_rec_special ? parseFloat(row.price_rec_special) : null, effective_price: row.effective_price ? parseFloat(row.effective_price) : null, is_on_special: row.is_on_special, quantity: row.quantity, price_rank: parseInt(row.price_rank), }); } // Calculate stats per option const stats: Record = {}; for (const [opt, items] of Object.entries(byOption)) { const prices = items.map((i: any) => i.effective_price).filter((p: any) => p !== null); stats[opt] = { count: items.length, min_price: Math.min(...prices), max_price: Math.max(...prices), avg_price: prices.reduce((a: number, b: number) => a + b, 0) / prices.length, cheapest_store: items[0]?.dispensary_name, on_special_count: items.filter((i: any) => i.is_on_special).length, }; } res.json({ search_term: name, results: byOption, stats, options: Object.keys(byOption), }); } catch (error: any) { console.error('Price compare error:', error); res.status(500).json({ error: 'Failed to compare prices', message: error.message }); } }); // ============================================================ // MARKET SUMMARY // ============================================================ /** * GET /api/price-analytics/market-summary * Get overall market analytics summary */ router.get('/market-summary', async (req: Request, res: Response) => { try { const { state } = req.query; let stateFilter = ''; const params: any[] = []; if (state) { stateFilter = 'WHERE d.state = $1'; params.push(state); } // Get variant counts const variantStats = await pool.query(` SELECT COUNT(DISTINCT pv.id) as total_variants, COUNT(DISTINCT pv.id) FILTER (WHERE pv.is_on_special) as on_special, COUNT(DISTINCT pv.id) FILTER (WHERE pv.in_stock) as in_stock, COUNT(DISTINCT pv.store_product_id) as total_products, COUNT(DISTINCT pv.dispensary_id) as total_stores FROM product_variants pv JOIN dispensaries d ON d.id = pv.dispensary_id ${stateFilter} `, params); // Get category breakdown const categoryStats = await pool.query(` SELECT sp.category_raw as category, COUNT(DISTINCT pv.id) as variant_count, AVG(COALESCE(pv.price_rec_special, pv.price_rec)) as avg_price, COUNT(DISTINCT pv.id) FILTER (WHERE pv.is_on_special) as on_special_count FROM product_variants pv JOIN store_products sp ON sp.id = pv.store_product_id JOIN dispensaries d ON d.id = pv.dispensary_id ${stateFilter} GROUP BY sp.category_raw ORDER BY variant_count DESC LIMIT 10 `, params); // Get recent price changes (last 24h) const recentChanges = await pool.query(` SELECT COUNT(*) as price_changes_24h FROM product_variants pv JOIN dispensaries d ON d.id = pv.dispensary_id ${stateFilter ? stateFilter + ' AND' : 'WHERE'} pv.last_price_change_at >= NOW() - INTERVAL '24 hours' `, params); res.json({ summary: { total_variants: parseInt(variantStats.rows[0]?.total_variants || '0'), on_special: parseInt(variantStats.rows[0]?.on_special || '0'), in_stock: parseInt(variantStats.rows[0]?.in_stock || '0'), total_products: parseInt(variantStats.rows[0]?.total_products || '0'), total_stores: parseInt(variantStats.rows[0]?.total_stores || '0'), price_changes_24h: parseInt(recentChanges.rows[0]?.price_changes_24h || '0'), }, categories: categoryStats.rows.map((c: any) => ({ category: c.category || 'Unknown', variant_count: parseInt(c.variant_count), avg_price: c.avg_price ? parseFloat(c.avg_price).toFixed(2) : null, on_special_count: parseInt(c.on_special_count), })), }); } catch (error: any) { console.error('Market summary error:', error); res.status(500).json({ error: 'Failed to fetch market summary', message: error.message }); } }); export default router;