146 lines
6.2 KiB
JavaScript
146 lines
6.2 KiB
JavaScript
const { outputProgress } = require('../utils/progress');
|
|
const { getConnection } = require('../utils/db');
|
|
|
|
async function calculateBrandMetrics(startTime, totalProducts, processedCount) {
|
|
const connection = await getConnection();
|
|
try {
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Calculating brand metrics',
|
|
current: Math.floor(totalProducts * 0.95),
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.95), totalProducts),
|
|
rate: calculateRate(startTime, Math.floor(totalProducts * 0.95)),
|
|
percentage: '95'
|
|
});
|
|
|
|
// Calculate brand metrics
|
|
await connection.query(`
|
|
INSERT INTO brand_metrics (
|
|
brand,
|
|
product_count,
|
|
active_products,
|
|
total_stock_units,
|
|
total_stock_cost,
|
|
total_stock_retail,
|
|
total_revenue,
|
|
avg_margin,
|
|
growth_rate
|
|
)
|
|
WITH brand_data AS (
|
|
SELECT
|
|
p.brand,
|
|
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) as total_stock_units,
|
|
SUM(p.stock_quantity * p.cost_price) as total_stock_cost,
|
|
SUM(p.stock_quantity * p.price) as total_stock_retail,
|
|
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,
|
|
-- 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
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
|
|
WHERE p.brand IS NOT NULL
|
|
GROUP BY p.brand
|
|
)
|
|
SELECT
|
|
brand,
|
|
product_count,
|
|
active_products,
|
|
total_stock_units,
|
|
total_stock_cost,
|
|
total_stock_retail,
|
|
total_revenue,
|
|
avg_margin,
|
|
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
|
|
FROM brand_data
|
|
ON DUPLICATE KEY UPDATE
|
|
product_count = VALUES(product_count),
|
|
active_products = VALUES(active_products),
|
|
total_stock_units = VALUES(total_stock_units),
|
|
total_stock_cost = VALUES(total_stock_cost),
|
|
total_stock_retail = VALUES(total_stock_retail),
|
|
total_revenue = VALUES(total_revenue),
|
|
avg_margin = VALUES(avg_margin),
|
|
growth_rate = VALUES(growth_rate),
|
|
last_calculated_at = CURRENT_TIMESTAMP
|
|
`);
|
|
|
|
// Calculate brand time-based metrics
|
|
await connection.query(`
|
|
INSERT INTO brand_time_metrics (
|
|
brand,
|
|
year,
|
|
month,
|
|
product_count,
|
|
active_products,
|
|
total_stock_units,
|
|
total_stock_cost,
|
|
total_stock_retail,
|
|
total_revenue,
|
|
avg_margin
|
|
)
|
|
SELECT
|
|
p.brand,
|
|
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) as total_stock_units,
|
|
SUM(p.stock_quantity * p.cost_price) as total_stock_cost,
|
|
SUM(p.stock_quantity * p.price) as total_stock_retail,
|
|
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
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
|
|
WHERE p.brand IS NOT NULL
|
|
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
|
GROUP BY p.brand, YEAR(o.date), MONTH(o.date)
|
|
ON DUPLICATE KEY UPDATE
|
|
product_count = VALUES(product_count),
|
|
active_products = VALUES(active_products),
|
|
total_stock_units = VALUES(total_stock_units),
|
|
total_stock_cost = VALUES(total_stock_cost),
|
|
total_stock_retail = VALUES(total_stock_retail),
|
|
total_revenue = VALUES(total_revenue),
|
|
avg_margin = VALUES(avg_margin)
|
|
`);
|
|
|
|
return Math.floor(totalProducts * 0.98);
|
|
} finally {
|
|
connection.release();
|
|
}
|
|
}
|
|
|
|
module.exports = calculateBrandMetrics;
|