321 lines
14 KiB
JavaScript
321 lines
14 KiB
JavaScript
const { outputProgress, formatElapsedTime, estimateRemaining, calculateRate, logError } = require('./utils/progress');
|
|
const { getConnection } = require('./utils/db');
|
|
|
|
async function calculateBrandMetrics(startTime, totalProducts, processedCount = 0, isCancelled = false) {
|
|
const connection = await getConnection();
|
|
let success = false;
|
|
let processedOrders = 0;
|
|
|
|
try {
|
|
if (isCancelled) {
|
|
outputProgress({
|
|
status: 'cancelled',
|
|
operation: 'Brand metrics calculation cancelled',
|
|
current: processedCount,
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: null,
|
|
rate: calculateRate(startTime, processedCount),
|
|
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
|
|
timing: {
|
|
start_time: new Date(startTime).toISOString(),
|
|
end_time: new Date().toISOString(),
|
|
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
|
|
}
|
|
});
|
|
return {
|
|
processedProducts: processedCount,
|
|
processedOrders: 0,
|
|
processedPurchaseOrders: 0,
|
|
success
|
|
};
|
|
}
|
|
|
|
// Get order count that will be processed
|
|
const orderCount = await connection.query(`
|
|
SELECT COUNT(*) as count
|
|
FROM orders o
|
|
WHERE o.canceled = false
|
|
`);
|
|
processedOrders = parseInt(orderCount.rows[0].count);
|
|
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Starting brand metrics calculation',
|
|
current: processedCount,
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: estimateRemaining(startTime, processedCount, totalProducts),
|
|
rate: calculateRate(startTime, processedCount),
|
|
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
|
|
timing: {
|
|
start_time: new Date(startTime).toISOString(),
|
|
end_time: new Date().toISOString(),
|
|
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
|
|
}
|
|
});
|
|
|
|
// Calculate brand metrics with optimized queries
|
|
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 filtered_products AS (
|
|
SELECT
|
|
p.*,
|
|
CASE
|
|
WHEN p.stock_quantity <= 5000 AND p.stock_quantity >= 0
|
|
THEN p.pid
|
|
END as valid_pid,
|
|
CASE
|
|
WHEN p.visible = true
|
|
AND p.stock_quantity <= 5000
|
|
AND p.stock_quantity >= 0
|
|
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
|
|
),
|
|
sales_periods AS (
|
|
SELECT
|
|
p.brand,
|
|
SUM(o.quantity * (o.price - COALESCE(o.discount, 0))) as period_revenue,
|
|
SUM(o.quantity * (o.price - COALESCE(o.discount, 0) - p.cost_price)) as period_margin,
|
|
COUNT(DISTINCT DATE(o.date)) as period_days,
|
|
CASE
|
|
WHEN o.date >= CURRENT_DATE - INTERVAL '3 months' THEN 'current'
|
|
WHEN o.date BETWEEN CURRENT_DATE - INTERVAL '15 months'
|
|
AND CURRENT_DATE - INTERVAL '12 months' 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 >= CURRENT_DATE - INTERVAL '15 months'
|
|
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 - COALESCE(o.discount, 0))), 0) as total_revenue,
|
|
CASE
|
|
WHEN SUM(o.quantity * o.price) > 0
|
|
THEN GREATEST(
|
|
-100.0,
|
|
LEAST(
|
|
100.0,
|
|
(
|
|
SUM(o.quantity * o.price) - -- Use gross revenue (before discounts)
|
|
SUM(o.quantity * COALESCE(p.cost_price, 0)) -- Total costs
|
|
) * 100.0 /
|
|
NULLIF(SUM(o.quantity * o.price), 0) -- Divide by gross revenue
|
|
)
|
|
)
|
|
ELSE 0
|
|
END as avg_margin
|
|
FROM filtered_products p
|
|
LEFT JOIN orders o ON p.pid = o.pid AND o.canceled = false
|
|
GROUP BY p.brand
|
|
)
|
|
SELECT
|
|
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 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 GREATEST(
|
|
-100.0,
|
|
LEAST(
|
|
((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(ABS(MAX(CASE WHEN sp.period_type = 'previous' THEN sp.period_revenue END)), 0)) * 100.0,
|
|
999.99
|
|
)
|
|
)
|
|
END as growth_rate
|
|
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 CONFLICT (brand) DO UPDATE
|
|
SET
|
|
product_count = EXCLUDED.product_count,
|
|
active_products = EXCLUDED.active_products,
|
|
total_stock_units = EXCLUDED.total_stock_units,
|
|
total_stock_cost = EXCLUDED.total_stock_cost,
|
|
total_stock_retail = EXCLUDED.total_stock_retail,
|
|
total_revenue = EXCLUDED.total_revenue,
|
|
avg_margin = EXCLUDED.avg_margin,
|
|
growth_rate = EXCLUDED.growth_rate,
|
|
last_calculated_at = CURRENT_TIMESTAMP
|
|
`);
|
|
|
|
processedCount = Math.floor(totalProducts * 0.97);
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Brand metrics calculated, starting time-based metrics',
|
|
current: processedCount,
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: estimateRemaining(startTime, processedCount, totalProducts),
|
|
rate: calculateRate(startTime, processedCount),
|
|
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
|
|
timing: {
|
|
start_time: new Date(startTime).toISOString(),
|
|
end_time: new Date().toISOString(),
|
|
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
|
|
}
|
|
});
|
|
|
|
if (isCancelled) return {
|
|
processedProducts: processedCount,
|
|
processedOrders,
|
|
processedPurchaseOrders: 0,
|
|
success
|
|
};
|
|
|
|
// Calculate brand time-based metrics with optimized query
|
|
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
|
|
)
|
|
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,
|
|
EXTRACT(YEAR FROM o.date) as year,
|
|
EXTRACT(MONTH FROM 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 GREATEST(
|
|
-100.0,
|
|
LEAST(
|
|
100.0,
|
|
(
|
|
SUM(o.quantity * o.price) - -- Use gross revenue (before discounts)
|
|
SUM(o.quantity * COALESCE(p.cost_price, 0)) -- Total costs
|
|
) * 100.0 /
|
|
NULLIF(SUM(o.quantity * o.price), 0) -- Divide by gross revenue
|
|
)
|
|
)
|
|
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 >= CURRENT_DATE - INTERVAL '12 months'
|
|
GROUP BY p.brand, EXTRACT(YEAR FROM o.date), EXTRACT(MONTH FROM o.date)
|
|
)
|
|
SELECT *
|
|
FROM monthly_metrics
|
|
ON CONFLICT (brand, year, month) DO UPDATE
|
|
SET
|
|
product_count = EXCLUDED.product_count,
|
|
active_products = EXCLUDED.active_products,
|
|
total_stock_units = EXCLUDED.total_stock_units,
|
|
total_stock_cost = EXCLUDED.total_stock_cost,
|
|
total_stock_retail = EXCLUDED.total_stock_retail,
|
|
total_revenue = EXCLUDED.total_revenue,
|
|
avg_margin = EXCLUDED.avg_margin
|
|
`);
|
|
|
|
processedCount = Math.floor(totalProducts * 0.99);
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Brand time-based metrics calculated',
|
|
current: processedCount,
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: estimateRemaining(startTime, processedCount, totalProducts),
|
|
rate: calculateRate(startTime, processedCount),
|
|
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
|
|
timing: {
|
|
start_time: new Date(startTime).toISOString(),
|
|
end_time: new Date().toISOString(),
|
|
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
|
|
}
|
|
});
|
|
|
|
// If we get here, everything completed successfully
|
|
success = true;
|
|
|
|
// Update calculate_status
|
|
await connection.query(`
|
|
INSERT INTO calculate_status (module_name, last_calculation_timestamp)
|
|
VALUES ('brand_metrics', NOW())
|
|
ON CONFLICT (module_name) DO UPDATE
|
|
SET last_calculation_timestamp = NOW()
|
|
`);
|
|
|
|
return {
|
|
processedProducts: processedCount,
|
|
processedOrders,
|
|
processedPurchaseOrders: 0,
|
|
success
|
|
};
|
|
|
|
} catch (error) {
|
|
success = false;
|
|
logError(error, 'Error calculating brand metrics');
|
|
throw error;
|
|
} finally {
|
|
if (connection) {
|
|
connection.release();
|
|
}
|
|
}
|
|
}
|
|
|
|
module.exports = calculateBrandMetrics;
|