214 lines
9.2 KiB
JavaScript
214 lines
9.2 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;
|
|
let processedOrders = 0;
|
|
|
|
try {
|
|
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
|
|
};
|
|
}
|
|
|
|
// Get order count that will be processed
|
|
const orderCount = await connection.query(`
|
|
SELECT COUNT(*) as count
|
|
FROM orders o
|
|
WHERE o.canceled = false
|
|
AND DATE(o.date) >= CURRENT_DATE - INTERVAL '12 months'
|
|
`);
|
|
processedOrders = parseInt(orderCount.rows[0].count);
|
|
|
|
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)
|
|
}
|
|
});
|
|
|
|
// First, calculate beginning inventory values (12 months ago)
|
|
await connection.query(`
|
|
CREATE TEMPORARY TABLE IF NOT EXISTS temp_beginning_inventory AS
|
|
WITH beginning_inventory_calc AS (
|
|
SELECT
|
|
p.pid,
|
|
p.stock_quantity as current_quantity,
|
|
COALESCE(SUM(o.quantity), 0) as sold_quantity,
|
|
COALESCE(SUM(po.received), 0) as received_quantity,
|
|
GREATEST(0, (p.stock_quantity + COALESCE(SUM(o.quantity), 0) - COALESCE(SUM(po.received), 0))) as beginning_quantity,
|
|
p.cost_price
|
|
FROM
|
|
products p
|
|
LEFT JOIN
|
|
orders o ON p.pid = o.pid
|
|
AND o.canceled = false
|
|
AND o.date >= CURRENT_DATE - INTERVAL '12 months'::interval
|
|
LEFT JOIN
|
|
purchase_orders po ON p.pid = po.pid
|
|
AND po.received_date IS NOT NULL
|
|
AND po.received_date >= CURRENT_DATE - INTERVAL '12 months'::interval
|
|
GROUP BY
|
|
p.pid, p.stock_quantity, p.cost_price
|
|
)
|
|
SELECT
|
|
pid,
|
|
beginning_quantity,
|
|
beginning_quantity * cost_price as beginning_value,
|
|
current_quantity * cost_price as current_value,
|
|
((beginning_quantity * cost_price) + (current_quantity * cost_price)) / 2 as average_inventory_value
|
|
FROM
|
|
beginning_inventory_calc
|
|
`);
|
|
|
|
processedCount = Math.floor(totalProducts * 0.60);
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Beginning inventory values calculated, computing financial 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)
|
|
}
|
|
});
|
|
|
|
// Calculate financial metrics with optimized query and standard formulas
|
|
await connection.query(`
|
|
WITH product_financials AS (
|
|
SELECT
|
|
p.pid,
|
|
COALESCE(bi.average_inventory_value, p.cost_price * p.stock_quantity) as avg_inventory_value,
|
|
p.cost_price * p.stock_quantity as current_inventory_value,
|
|
SUM(o.quantity * (o.price - COALESCE(o.discount, 0))) as total_revenue,
|
|
SUM(o.quantity * COALESCE(o.costeach, 0)) as cost_of_goods_sold,
|
|
SUM(o.quantity * (o.price - COALESCE(o.discount, 0) - COALESCE(o.costeach, 0))) as gross_profit,
|
|
MIN(o.date) as first_sale_date,
|
|
MAX(o.date) as last_sale_date,
|
|
EXTRACT(DAY FROM (MAX(o.date)::timestamp with time zone - MIN(o.date)::timestamp with time zone)) + 1 as calculation_period_days,
|
|
COUNT(DISTINCT DATE(o.date)) as active_days
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid
|
|
LEFT JOIN temp_beginning_inventory bi ON p.pid = bi.pid
|
|
WHERE o.canceled = false
|
|
AND DATE(o.date) >= CURRENT_DATE - INTERVAL '12 months'::interval
|
|
GROUP BY p.pid, p.cost_price, p.stock_quantity, bi.average_inventory_value
|
|
)
|
|
UPDATE product_metrics pm
|
|
SET
|
|
inventory_value = COALESCE(pf.current_inventory_value, 0)::decimal(10,3),
|
|
total_revenue = COALESCE(pf.total_revenue, 0)::decimal(10,3),
|
|
cost_of_goods_sold = COALESCE(pf.cost_of_goods_sold, 0)::decimal(10,3),
|
|
gross_profit = COALESCE(pf.gross_profit, 0)::decimal(10,3),
|
|
turnover_rate = CASE
|
|
WHEN COALESCE(pf.avg_inventory_value, 0) > 0 THEN
|
|
COALESCE(pf.cost_of_goods_sold, 0) / NULLIF(pf.avg_inventory_value, 0)
|
|
ELSE 0
|
|
END::decimal(12,3),
|
|
gmroi = CASE
|
|
WHEN COALESCE(pf.avg_inventory_value, 0) > 0 THEN
|
|
COALESCE(pf.gross_profit, 0) / NULLIF(pf.avg_inventory_value, 0)
|
|
ELSE 0
|
|
END::decimal(10,3),
|
|
last_calculated_at = CURRENT_TIMESTAMP
|
|
FROM product_financials pf
|
|
WHERE pm.pid = pf.pid
|
|
`);
|
|
|
|
processedCount = Math.floor(totalProducts * 0.65);
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Base financial metrics calculated, updating time aggregates',
|
|
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
|
|
};
|
|
|
|
// Clean up temporary tables
|
|
await connection.query('DROP TABLE IF EXISTS temp_beginning_inventory');
|
|
|
|
// 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 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 financial metrics');
|
|
throw error;
|
|
} finally {
|
|
if (connection) {
|
|
try {
|
|
// Make sure temporary tables are always cleaned up
|
|
await connection.query('DROP TABLE IF EXISTS temp_beginning_inventory');
|
|
} catch (err) {
|
|
console.error('Error cleaning up temp tables:', err);
|
|
}
|
|
connection.release();
|
|
}
|
|
}
|
|
}
|
|
|
|
module.exports = calculateFinancialMetrics;
|