179 lines
7.0 KiB
JavaScript
179 lines
7.0 KiB
JavaScript
const { outputProgress, formatElapsedTime, estimateRemaining, calculateRate, logError } = require('./utils/progress');
|
|
const { getConnection } = require('./utils/db');
|
|
|
|
async function calculateFinancialMetrics(startTime, totalProducts, processedCount = 0, isCancelled = false) {
|
|
const connection = await getConnection();
|
|
let success = false;
|
|
const BATCH_SIZE = 5000;
|
|
|
|
try {
|
|
// Get last calculation timestamp
|
|
const [lastCalc] = await connection.query(`
|
|
SELECT last_calculation_timestamp
|
|
FROM calculate_status
|
|
WHERE module_name = 'financial_metrics'
|
|
`);
|
|
const lastCalculationTime = lastCalc[0]?.last_calculation_timestamp || '1970-01-01';
|
|
|
|
// Get total count of products needing updates
|
|
if (!totalProducts) {
|
|
const [productCount] = await connection.query(`
|
|
SELECT COUNT(DISTINCT p.pid) as count
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid AND o.updated > ?
|
|
WHERE p.updated > ?
|
|
OR o.pid IS NOT NULL
|
|
`, [lastCalculationTime, lastCalculationTime]);
|
|
totalProducts = productCount[0].count;
|
|
}
|
|
|
|
if (totalProducts === 0) {
|
|
console.log('No products need financial metric updates');
|
|
return {
|
|
processedProducts: 0,
|
|
processedOrders: 0,
|
|
processedPurchaseOrders: 0,
|
|
success: true
|
|
};
|
|
}
|
|
|
|
if (isCancelled) {
|
|
outputProgress({
|
|
status: 'cancelled',
|
|
operation: 'Financial 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
|
|
};
|
|
}
|
|
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Starting financial 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)
|
|
}
|
|
});
|
|
|
|
// Process in batches
|
|
let lastPid = 0;
|
|
while (true) {
|
|
if (isCancelled) break;
|
|
|
|
const [batch] = await connection.query(`
|
|
SELECT DISTINCT p.pid
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid AND o.updated > ?
|
|
WHERE p.pid > ?
|
|
AND (
|
|
p.updated > ?
|
|
OR o.pid IS NOT NULL
|
|
)
|
|
ORDER BY p.pid
|
|
LIMIT ?
|
|
`, [lastCalculationTime, lastPid, lastCalculationTime, BATCH_SIZE]);
|
|
|
|
if (batch.length === 0) break;
|
|
|
|
// Update financial metrics for this batch
|
|
await connection.query(`
|
|
UPDATE product_metrics pm
|
|
JOIN (
|
|
SELECT
|
|
p.pid,
|
|
p.cost_price * p.stock_quantity as inventory_value,
|
|
SUM(o.quantity * o.price) as total_revenue,
|
|
SUM(o.quantity * p.cost_price) as cost_of_goods_sold,
|
|
SUM(o.quantity * (o.price - p.cost_price)) as gross_profit,
|
|
COUNT(DISTINCT DATE(o.date)) as active_days
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid
|
|
AND o.canceled = false
|
|
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 90 DAY)
|
|
WHERE p.pid IN (?)
|
|
GROUP BY p.pid
|
|
) fin ON pm.pid = fin.pid
|
|
SET
|
|
pm.inventory_value = COALESCE(fin.inventory_value, 0),
|
|
pm.total_revenue = COALESCE(fin.total_revenue, 0),
|
|
pm.cost_of_goods_sold = COALESCE(fin.cost_of_goods_sold, 0),
|
|
pm.gross_profit = COALESCE(fin.gross_profit, 0),
|
|
pm.gmroi = CASE
|
|
WHEN COALESCE(fin.inventory_value, 0) > 0 AND fin.active_days > 0
|
|
THEN (COALESCE(fin.gross_profit, 0) * (365.0 / fin.active_days)) / COALESCE(fin.inventory_value, 0)
|
|
ELSE 0
|
|
END,
|
|
pm.last_calculated_at = NOW()
|
|
`, [batch.map(row => row.pid)]);
|
|
|
|
lastPid = batch[batch.length - 1].pid;
|
|
processedCount += batch.length;
|
|
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Processing financial metrics batch',
|
|
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 ('financial_metrics', NOW())
|
|
ON DUPLICATE KEY UPDATE last_calculation_timestamp = NOW()
|
|
`);
|
|
|
|
return {
|
|
processedProducts: processedCount,
|
|
processedOrders: 0,
|
|
processedPurchaseOrders: 0,
|
|
success
|
|
};
|
|
|
|
} catch (error) {
|
|
success = false;
|
|
logError(error, 'Error calculating financial metrics');
|
|
throw error;
|
|
} finally {
|
|
if (connection) {
|
|
connection.release();
|
|
}
|
|
}
|
|
}
|
|
|
|
module.exports = calculateFinancialMetrics;
|