const { outputProgress } = require('../utils/progress'); const { getConnection } = require('../utils/db'); async function calculateCategoryMetrics(startTime, totalProducts, processedCount) { const connection = await getConnection(); try { outputProgress({ status: 'running', operation: 'Calculating category metrics', current: Math.floor(totalProducts * 0.85), total: totalProducts, elapsed: formatElapsedTime(startTime), remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.85), totalProducts), rate: calculateRate(startTime, Math.floor(totalProducts * 0.85)), percentage: '85' }); // Calculate category performance metrics await connection.query(` INSERT INTO category_metrics ( category_id, product_count, active_products, total_value, avg_margin, turnover_rate, growth_rate, status ) WITH category_sales AS ( SELECT c.id as category_id, COUNT(DISTINCT p.product_id) as product_count, COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products, SUM(p.stock_quantity * p.cost_price) as total_value, CASE WHEN SUM(o.price * o.quantity) > 0 THEN (SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity) ELSE 0 END as avg_margin, CASE WHEN AVG(GREATEST(p.stock_quantity, 0)) >= 0.01 THEN LEAST( SUM(CASE WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 1 YEAR) THEN COALESCE(o.quantity, 0) ELSE 0 END) / GREATEST( AVG(GREATEST(p.stock_quantity, 0)), 1.0 ), 999.99 ) ELSE 0 END as turnover_rate, -- Current period (last 3 months) SUM(CASE WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 3 MONTH) THEN COALESCE(o.quantity * o.price, 0) ELSE 0 END) as current_period_sales, -- Previous year same period SUM(CASE WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH) THEN COALESCE(o.quantity * o.price, 0) ELSE 0 END) as previous_year_period_sales, c.status FROM categories c LEFT JOIN product_categories pc ON c.id = pc.category_id LEFT JOIN products p ON pc.product_id = p.product_id LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false GROUP BY c.id, c.status ) SELECT category_id, product_count, active_products, total_value, COALESCE(avg_margin, 0) as avg_margin, COALESCE(turnover_rate, 0) as turnover_rate, -- Enhanced YoY growth rate calculation CASE WHEN previous_year_period_sales = 0 AND current_period_sales > 0 THEN 100.0 WHEN previous_year_period_sales = 0 THEN 0.0 ELSE LEAST( GREATEST( ((current_period_sales - previous_year_period_sales) / NULLIF(previous_year_period_sales, 0)) * 100.0, -100.0 ), 999.99 ) END as growth_rate, status FROM category_sales ON DUPLICATE KEY UPDATE product_count = VALUES(product_count), active_products = VALUES(active_products), total_value = VALUES(total_value), avg_margin = VALUES(avg_margin), turnover_rate = VALUES(turnover_rate), growth_rate = VALUES(growth_rate), status = VALUES(status), last_calculated_at = CURRENT_TIMESTAMP `); // Calculate category time-based metrics await connection.query(` INSERT INTO category_time_metrics ( category_id, year, month, product_count, active_products, total_value, total_revenue, avg_margin, turnover_rate ) SELECT c.id as category_id, YEAR(o.date) as year, MONTH(o.date) as month, COUNT(DISTINCT p.product_id) as product_count, COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products, SUM(p.stock_quantity * p.cost_price) as total_value, SUM(o.price * o.quantity) as total_revenue, CASE WHEN SUM(o.price * o.quantity) > 0 THEN (SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity) ELSE 0 END as avg_margin, CASE WHEN AVG(p.stock_quantity) > 0 THEN SUM(o.quantity) / AVG(p.stock_quantity) ELSE 0 END as turnover_rate FROM categories c LEFT JOIN product_categories pc ON c.id = pc.category_id LEFT JOIN products p ON pc.product_id = p.product_id LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false WHERE o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH) GROUP BY c.id, YEAR(o.date), MONTH(o.date) ON DUPLICATE KEY UPDATE product_count = VALUES(product_count), active_products = VALUES(active_products), total_value = VALUES(total_value), total_revenue = VALUES(total_revenue), avg_margin = VALUES(avg_margin), turnover_rate = VALUES(turnover_rate) `); // Calculate category sales metrics await connection.query(` INSERT INTO category_sales_metrics ( category_id, brand, period_start, period_end, avg_daily_sales, total_sold, num_products, avg_price, last_calculated_at ) WITH date_ranges AS ( SELECT DATE_SUB(CURDATE(), INTERVAL 30 DAY) as period_start, CURDATE() as period_end UNION ALL SELECT DATE_SUB(CURDATE(), INTERVAL 90 DAY), CURDATE() UNION ALL SELECT DATE_SUB(CURDATE(), INTERVAL 180 DAY), CURDATE() UNION ALL SELECT DATE_SUB(CURDATE(), INTERVAL 365 DAY), CURDATE() ), category_metrics AS ( SELECT c.id as category_id, p.brand, dr.period_start, dr.period_end, COUNT(DISTINCT p.product_id) as num_products, COALESCE(SUM(o.quantity), 0) / DATEDIFF(dr.period_end, dr.period_start) as avg_daily_sales, COALESCE(SUM(o.quantity), 0) as total_sold, COALESCE(AVG(o.price), 0) as avg_price FROM categories c JOIN product_categories pc ON c.id = pc.category_id JOIN products p ON pc.product_id = p.product_id CROSS JOIN date_ranges dr LEFT JOIN orders o ON p.product_id = o.product_id AND o.date BETWEEN dr.period_start AND dr.period_end AND o.canceled = false GROUP BY c.id, p.brand, dr.period_start, dr.period_end ) SELECT category_id, brand, period_start, period_end, avg_daily_sales, total_sold, num_products, avg_price, NOW() as last_calculated_at FROM category_metrics ON DUPLICATE KEY UPDATE avg_daily_sales = VALUES(avg_daily_sales), total_sold = VALUES(total_sold), num_products = VALUES(num_products), avg_price = VALUES(avg_price), last_calculated_at = NOW() `); return Math.floor(totalProducts * 0.9); } finally { connection.release(); } } module.exports = calculateCategoryMetrics;