Optimize and fix calculate scripts
This commit is contained in:
@@ -15,7 +15,7 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount) {
|
||||
percentage: '95'
|
||||
});
|
||||
|
||||
// Calculate brand metrics
|
||||
// Calculate brand metrics with optimized queries
|
||||
await connection.query(`
|
||||
INSERT INTO brand_metrics (
|
||||
brand,
|
||||
@@ -28,71 +28,77 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount) {
|
||||
avg_margin,
|
||||
growth_rate
|
||||
)
|
||||
WITH brand_data AS (
|
||||
WITH filtered_products AS (
|
||||
SELECT
|
||||
p.brand,
|
||||
COUNT(DISTINCT CASE WHEN p.stock_quantity <= 5000 THEN p.pid END) as product_count,
|
||||
COUNT(DISTINCT CASE WHEN p.visible = true AND p.stock_quantity <= 5000 THEN p.pid END) as active_products,
|
||||
SUM(CASE
|
||||
p.*,
|
||||
CASE WHEN p.stock_quantity <= 5000 THEN p.pid END as valid_pid,
|
||||
CASE WHEN p.visible = true AND p.stock_quantity <= 5000 THEN p.pid END as active_pid,
|
||||
CASE
|
||||
WHEN p.stock_quantity IS NULL OR p.stock_quantity < 0 OR p.stock_quantity > 5000 THEN 0
|
||||
ELSE p.stock_quantity
|
||||
END) as total_stock_units,
|
||||
SUM(CASE
|
||||
WHEN p.stock_quantity IS NULL OR p.stock_quantity < 0 OR p.stock_quantity > 5000 OR p.cost_price IS NULL OR p.cost_price < 0 THEN 0
|
||||
ELSE p.stock_quantity * p.cost_price
|
||||
END) as total_stock_cost,
|
||||
SUM(CASE
|
||||
WHEN p.stock_quantity IS NULL OR p.stock_quantity < 0 OR p.stock_quantity > 5000 OR p.price IS NULL OR p.price < 0 THEN 0
|
||||
ELSE p.stock_quantity * p.price
|
||||
END) as total_stock_retail,
|
||||
SUM(CASE
|
||||
WHEN o.quantity IS NULL OR o.price IS NULL OR o.quantity < 0 OR o.price < 0 THEN 0
|
||||
ELSE o.price * o.quantity
|
||||
END) as total_revenue,
|
||||
END as valid_stock
|
||||
FROM products p
|
||||
WHERE p.brand IS NOT NULL
|
||||
),
|
||||
sales_periods AS (
|
||||
SELECT
|
||||
p.brand,
|
||||
SUM(o.quantity * o.price) as period_revenue,
|
||||
CASE
|
||||
WHEN SUM(o.price * o.quantity) > 0 THEN
|
||||
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 3 MONTH) THEN 'current'
|
||||
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH) THEN 'previous'
|
||||
END as period_type
|
||||
FROM filtered_products p
|
||||
JOIN orders o ON p.pid = o.pid
|
||||
WHERE o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH)
|
||||
GROUP BY p.brand, period_type
|
||||
),
|
||||
brand_data AS (
|
||||
SELECT
|
||||
p.brand,
|
||||
COUNT(DISTINCT p.valid_pid) as product_count,
|
||||
COUNT(DISTINCT p.active_pid) as active_products,
|
||||
SUM(p.valid_stock) as total_stock_units,
|
||||
SUM(p.valid_stock * p.cost_price) as total_stock_cost,
|
||||
SUM(p.valid_stock * p.price) as total_stock_retail,
|
||||
COALESCE(SUM(o.quantity * o.price), 0) as total_revenue,
|
||||
CASE
|
||||
WHEN SUM(o.quantity * o.price) > 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
|
||||
END as avg_margin
|
||||
FROM filtered_products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid 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,
|
||||
bd.brand,
|
||||
bd.product_count,
|
||||
bd.active_products,
|
||||
bd.total_stock_units,
|
||||
bd.total_stock_cost,
|
||||
bd.total_stock_retail,
|
||||
bd.total_revenue,
|
||||
bd.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
|
||||
WHEN MAX(CASE WHEN sp.period_type = 'previous' THEN sp.period_revenue END) = 0
|
||||
AND MAX(CASE WHEN sp.period_type = 'current' THEN sp.period_revenue END) > 0 THEN 100.0
|
||||
WHEN MAX(CASE WHEN sp.period_type = 'previous' THEN sp.period_revenue END) = 0 THEN 0.0
|
||||
ELSE LEAST(
|
||||
GREATEST(
|
||||
((current_period_sales - previous_year_period_sales) /
|
||||
NULLIF(previous_year_period_sales, 0)) * 100.0,
|
||||
((MAX(CASE WHEN sp.period_type = 'current' THEN sp.period_revenue END) -
|
||||
MAX(CASE WHEN sp.period_type = 'previous' THEN sp.period_revenue END)) /
|
||||
NULLIF(MAX(CASE WHEN sp.period_type = 'previous' THEN sp.period_revenue END), 0)) * 100.0,
|
||||
-100.0
|
||||
),
|
||||
999.99
|
||||
)
|
||||
END as growth_rate
|
||||
FROM brand_data
|
||||
FROM brand_data bd
|
||||
LEFT JOIN sales_periods sp ON bd.brand = sp.brand
|
||||
GROUP BY bd.brand, bd.product_count, bd.active_products, bd.total_stock_units,
|
||||
bd.total_stock_cost, bd.total_stock_retail, bd.total_revenue, bd.avg_margin
|
||||
ON DUPLICATE KEY UPDATE
|
||||
product_count = VALUES(product_count),
|
||||
active_products = VALUES(active_products),
|
||||
@@ -105,7 +111,7 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount) {
|
||||
last_calculated_at = CURRENT_TIMESTAMP
|
||||
`);
|
||||
|
||||
// Calculate brand time-based metrics
|
||||
// Calculate brand time-based metrics with optimized query
|
||||
await connection.query(`
|
||||
INSERT INTO brand_time_metrics (
|
||||
brand,
|
||||
@@ -119,38 +125,41 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount) {
|
||||
total_revenue,
|
||||
avg_margin
|
||||
)
|
||||
SELECT
|
||||
p.brand,
|
||||
YEAR(o.date) as year,
|
||||
MONTH(o.date) as month,
|
||||
COUNT(DISTINCT CASE WHEN p.stock_quantity <= 5000 THEN p.pid END) as product_count,
|
||||
COUNT(DISTINCT CASE WHEN p.visible = true AND p.stock_quantity <= 5000 THEN p.pid END) as active_products,
|
||||
SUM(CASE
|
||||
WHEN p.stock_quantity IS NULL OR p.stock_quantity < 0 OR p.stock_quantity > 5000 THEN 0
|
||||
ELSE p.stock_quantity
|
||||
END) as total_stock_units,
|
||||
SUM(CASE
|
||||
WHEN p.stock_quantity IS NULL OR p.stock_quantity < 0 OR p.stock_quantity > 5000 OR p.cost_price IS NULL OR p.cost_price < 0 THEN 0
|
||||
ELSE p.stock_quantity * p.cost_price
|
||||
END) as total_stock_cost,
|
||||
SUM(CASE
|
||||
WHEN p.stock_quantity IS NULL OR p.stock_quantity < 0 OR p.stock_quantity > 5000 OR p.price IS NULL OR p.price < 0 THEN 0
|
||||
ELSE p.stock_quantity * p.price
|
||||
END) as total_stock_retail,
|
||||
SUM(CASE
|
||||
WHEN o.quantity IS NULL OR o.price IS NULL OR o.quantity < 0 OR o.price < 0 THEN 0
|
||||
ELSE o.price * o.quantity
|
||||
END) 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.pid = o.pid 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)
|
||||
WITH filtered_products AS (
|
||||
SELECT
|
||||
p.*,
|
||||
CASE WHEN p.stock_quantity <= 5000 THEN p.pid END as valid_pid,
|
||||
CASE WHEN p.visible = true AND p.stock_quantity <= 5000 THEN p.pid END as active_pid,
|
||||
CASE
|
||||
WHEN p.stock_quantity IS NULL OR p.stock_quantity < 0 OR p.stock_quantity > 5000 THEN 0
|
||||
ELSE p.stock_quantity
|
||||
END as valid_stock
|
||||
FROM products p
|
||||
WHERE p.brand IS NOT NULL
|
||||
),
|
||||
monthly_metrics AS (
|
||||
SELECT
|
||||
p.brand,
|
||||
YEAR(o.date) as year,
|
||||
MONTH(o.date) as month,
|
||||
COUNT(DISTINCT p.valid_pid) as product_count,
|
||||
COUNT(DISTINCT p.active_pid) as active_products,
|
||||
SUM(p.valid_stock) as total_stock_units,
|
||||
SUM(p.valid_stock * p.cost_price) as total_stock_cost,
|
||||
SUM(p.valid_stock * p.price) as total_stock_retail,
|
||||
SUM(o.quantity * o.price) as total_revenue,
|
||||
CASE
|
||||
WHEN SUM(o.quantity * o.price) > 0 THEN
|
||||
(SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
|
||||
ELSE 0
|
||||
END as avg_margin
|
||||
FROM filtered_products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid AND o.canceled = false
|
||||
WHERE o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
||||
GROUP BY p.brand, YEAR(o.date), MONTH(o.date)
|
||||
)
|
||||
SELECT *
|
||||
FROM monthly_metrics
|
||||
ON DUPLICATE KEY UPDATE
|
||||
product_count = VALUES(product_count),
|
||||
active_products = VALUES(active_products),
|
||||
|
||||
Reference in New Issue
Block a user