diff --git a/inventory-server/scripts/metrics/category-metrics.js b/inventory-server/scripts/metrics/category-metrics.js index 2df0ae0..4b2f926 100644 --- a/inventory-server/scripts/metrics/category-metrics.js +++ b/inventory-server/scripts/metrics/category-metrics.js @@ -133,52 +133,71 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount ) ENGINE=MEMORY `); - // Populate product stats + // Populate product stats with optimized index usage await connection.query(` INSERT INTO temp_product_stats SELECT c.cat_id, COUNT(DISTINCT p.pid) as product_count, COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid END) as active_products, - SUM(p.stock_quantity * p.cost_price) as total_value, - AVG(pm.avg_margin_percent) as avg_margin, - AVG(pm.turnover_rate) as turnover_rate + COALESCE(SUM(p.stock_quantity * p.cost_price), 0) as total_value, + COALESCE(AVG(NULLIF(pm.avg_margin_percent, 0)), 0) as avg_margin, + COALESCE(AVG(NULLIF(pm.turnover_rate, 0)), 0) as turnover_rate FROM categories c FORCE INDEX (PRIMARY) - JOIN product_categories pc FORCE INDEX (idx_category) ON c.cat_id = pc.cat_id + INNER JOIN product_categories pc FORCE INDEX (idx_category) ON c.cat_id = pc.cat_id LEFT JOIN products p FORCE INDEX (PRIMARY) ON pc.pid = p.pid LEFT JOIN product_metrics pm FORCE INDEX (PRIMARY) ON p.pid = pm.pid WHERE c.cat_id IN (?) + AND ( + p.updated > ? + OR EXISTS ( + SELECT 1 FROM orders o FORCE INDEX (idx_orders_metrics) + WHERE o.pid = p.pid + AND o.updated > ? + ) + ) GROUP BY c.cat_id - `, [batch.map(row => row.cat_id)]); + `, [batch.map(row => row.cat_id), lastCalculationTime, lastCalculationTime]); - // Populate sales stats + // Populate sales stats with optimized date handling await connection.query(` INSERT INTO temp_sales_stats + WITH date_ranges AS ( + SELECT + DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) as current_start, + CURRENT_DATE as current_end, + DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) as previous_start, + DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) as previous_end + ) SELECT c.cat_id, - COALESCE(SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) + COALESCE(SUM( + CASE WHEN o.date >= dr.current_start THEN o.quantity * o.price ELSE 0 - END), 0) as recent_revenue, - COALESCE(SUM(CASE - WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) + END + ), 0) as recent_revenue, + COALESCE(SUM( + CASE WHEN o.date >= dr.previous_start AND o.date < dr.current_start THEN o.quantity * o.price ELSE 0 - END), 0) as previous_revenue + END + ), 0) as previous_revenue FROM categories c FORCE INDEX (PRIMARY) - JOIN product_categories pc FORCE INDEX (idx_category) ON c.cat_id = pc.cat_id - LEFT JOIN products p FORCE INDEX (PRIMARY) ON pc.pid = p.pid - LEFT JOIN orders o FORCE INDEX (idx_orders_metrics) ON p.pid = o.pid - AND o.canceled = false - AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) + INNER JOIN product_categories pc FORCE INDEX (idx_category) ON c.cat_id = pc.cat_id + INNER JOIN products p FORCE INDEX (PRIMARY) ON pc.pid = p.pid + INNER JOIN orders o FORCE INDEX (idx_orders_metrics) ON p.pid = o.pid + CROSS JOIN date_ranges dr WHERE c.cat_id IN (?) + AND o.canceled = false + AND o.date >= dr.previous_start + AND o.updated > ? GROUP BY c.cat_id - `, [batch.map(row => row.cat_id)]); + `, [batch.map(row => row.cat_id), lastCalculationTime]); - // Update metrics using temp tables + // Update metrics using temp tables with optimized calculations await connection.query(` INSERT INTO category_metrics ( category_id, @@ -193,17 +212,17 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount ) SELECT c.cat_id, - COALESCE(ps.product_count, 0) as product_count, - COALESCE(ps.active_products, 0) as active_products, - COALESCE(ps.total_value, 0) as total_value, - COALESCE(ps.avg_margin, 0) as avg_margin, - COALESCE(ps.turnover_rate, 0) as turnover_rate, + ps.product_count, + ps.active_products, + ps.total_value, + ps.avg_margin, + ps.turnover_rate, CASE - WHEN ss.previous_revenue = 0 AND ss.recent_revenue > 0 THEN 100 - WHEN ss.previous_revenue = 0 THEN 0 - ELSE LEAST(999.99, GREATEST(-100, - ((ss.recent_revenue / NULLIF(ss.previous_revenue, 0) - 1) * 100) - )) + WHEN COALESCE(ss.previous_revenue, 0) = 0 AND COALESCE(ss.recent_revenue, 0) > 0 THEN 100 + WHEN COALESCE(ss.previous_revenue, 0) = 0 THEN 0 + ELSE ROUND(LEAST(999.99, GREATEST(-100, + ((ss.recent_revenue / NULLIF(ss.previous_revenue, 0)) - 1) * 100 + )), 2) END as growth_rate, c.status, NOW() as last_calculated_at