Files
inventory/inventory-server/scripts/metrics/time-aggregates.js
2025-03-26 14:22:08 -04:00

306 lines
12 KiB
JavaScript

const { outputProgress, formatElapsedTime, estimateRemaining, calculateRate, logError } = require('./utils/progress');
const { getConnection } = require('./utils/db');
async function calculateTimeAggregates(startTime, totalProducts, processedCount = 0, isCancelled = false) {
const connection = await getConnection();
let success = false;
let processedOrders = 0;
try {
if (isCancelled) {
outputProgress({
status: 'cancelled',
operation: 'Time aggregates 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 time aggregates 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)
}
});
// Initial insert of time-based aggregates
await connection.query(`
INSERT INTO product_time_aggregates (
pid,
year,
month,
total_quantity_sold,
total_revenue,
total_cost,
order_count,
stock_received,
stock_ordered,
avg_price,
profit_margin,
inventory_value,
gmroi
)
WITH monthly_sales AS (
SELECT
o.pid,
EXTRACT(YEAR FROM o.date::timestamp with time zone) as year,
EXTRACT(MONTH FROM o.date::timestamp with time zone) as month,
SUM(o.quantity) as total_quantity_sold,
SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) as total_revenue,
SUM(COALESCE(p.cost_price, 0) * o.quantity) as total_cost,
COUNT(DISTINCT o.order_number) as order_count,
AVG(o.price - COALESCE(o.discount, 0)) as avg_price,
CASE
WHEN SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) > 0
THEN ((SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) - SUM(COALESCE(p.cost_price, 0) * o.quantity))
/ SUM((o.price - COALESCE(o.discount, 0)) * o.quantity)) * 100
ELSE 0
END as profit_margin,
p.cost_price * p.stock_quantity as inventory_value,
COUNT(DISTINCT DATE(o.date)) as active_days
FROM orders o
JOIN products p ON o.pid = p.pid
WHERE o.canceled = false
GROUP BY o.pid, EXTRACT(YEAR FROM o.date::timestamp with time zone), EXTRACT(MONTH FROM o.date::timestamp with time zone), p.cost_price, p.stock_quantity
),
monthly_stock AS (
SELECT
pid,
EXTRACT(YEAR FROM date::timestamp with time zone) as year,
EXTRACT(MONTH FROM date::timestamp with time zone) as month,
SUM(received) as stock_received,
SUM(ordered) as stock_ordered
FROM purchase_orders
GROUP BY pid, EXTRACT(YEAR FROM date::timestamp with time zone), EXTRACT(MONTH FROM date::timestamp with time zone)
),
base_products AS (
SELECT
p.pid,
p.cost_price * p.stock_quantity as inventory_value
FROM products p
)
SELECT
COALESCE(s.pid, ms.pid) as pid,
COALESCE(s.year, ms.year) as year,
COALESCE(s.month, ms.month) as month,
COALESCE(s.total_quantity_sold, 0) as total_quantity_sold,
COALESCE(s.total_revenue, 0) as total_revenue,
COALESCE(s.total_cost, 0) as total_cost,
COALESCE(s.order_count, 0) as order_count,
COALESCE(ms.stock_received, 0) as stock_received,
COALESCE(ms.stock_ordered, 0) as stock_ordered,
COALESCE(s.avg_price, 0) as avg_price,
COALESCE(s.profit_margin, 0) as profit_margin,
COALESCE(s.inventory_value, bp.inventory_value, 0) as inventory_value,
CASE
WHEN COALESCE(s.inventory_value, bp.inventory_value, 0) > 0
AND COALESCE(s.active_days, 0) > 0
THEN (COALESCE(s.total_revenue - s.total_cost, 0) * (365.0 / s.active_days))
/ COALESCE(s.inventory_value, bp.inventory_value)
ELSE 0
END as gmroi
FROM (
SELECT * FROM monthly_sales s
UNION ALL
SELECT
ms.pid,
ms.year,
ms.month,
0 as total_quantity_sold,
0 as total_revenue,
0 as total_cost,
0 as order_count,
NULL as avg_price,
0 as profit_margin,
NULL as inventory_value,
0 as active_days
FROM monthly_stock ms
WHERE NOT EXISTS (
SELECT 1 FROM monthly_sales s2
WHERE s2.pid = ms.pid
AND s2.year = ms.year
AND s2.month = ms.month
)
) s
LEFT JOIN monthly_stock ms
ON s.pid = ms.pid
AND s.year = ms.year
AND s.month = ms.month
JOIN base_products bp ON COALESCE(s.pid, ms.pid) = bp.pid
UNION
SELECT
ms.pid,
ms.year,
ms.month,
0 as total_quantity_sold,
0 as total_revenue,
0 as total_cost,
0 as order_count,
ms.stock_received,
ms.stock_ordered,
0 as avg_price,
0 as profit_margin,
bp.inventory_value,
0 as gmroi
FROM monthly_stock ms
JOIN base_products bp ON ms.pid = bp.pid
WHERE NOT EXISTS (
SELECT 1 FROM (
SELECT * FROM monthly_sales
UNION ALL
SELECT
ms2.pid,
ms2.year,
ms2.month,
0, 0, 0, 0, NULL, 0, NULL, 0
FROM monthly_stock ms2
WHERE NOT EXISTS (
SELECT 1 FROM monthly_sales s2
WHERE s2.pid = ms2.pid
AND s2.year = ms2.year
AND s2.month = ms2.month
)
) s
WHERE s.pid = ms.pid
AND s.year = ms.year
AND s.month = ms.month
)
ON CONFLICT (pid, year, month) DO UPDATE
SET
total_quantity_sold = EXCLUDED.total_quantity_sold,
total_revenue = EXCLUDED.total_revenue,
total_cost = EXCLUDED.total_cost,
order_count = EXCLUDED.order_count,
stock_received = EXCLUDED.stock_received,
stock_ordered = EXCLUDED.stock_ordered,
avg_price = EXCLUDED.avg_price,
profit_margin = EXCLUDED.profit_margin,
inventory_value = EXCLUDED.inventory_value,
gmroi = EXCLUDED.gmroi
`);
processedCount = Math.floor(totalProducts * 0.60);
outputProgress({
status: 'running',
operation: 'Base time aggregates calculated, updating 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)
}
});
if (isCancelled) return {
processedProducts: processedCount,
processedOrders,
processedPurchaseOrders: 0,
success
};
// Update with financial metrics
await connection.query(`
UPDATE product_time_aggregates pta
SET inventory_value = COALESCE(fin.inventory_value, 0)
FROM (
SELECT
p.pid,
EXTRACT(YEAR FROM o.date::timestamp with time zone) as year,
EXTRACT(MONTH FROM o.date::timestamp with time zone) as month,
p.cost_price * p.stock_quantity as inventory_value,
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
WHERE o.canceled = false
GROUP BY p.pid, EXTRACT(YEAR FROM o.date::timestamp with time zone), EXTRACT(MONTH FROM o.date::timestamp with time zone), p.cost_price, p.stock_quantity
) fin
WHERE pta.pid = fin.pid
AND pta.year = fin.year
AND pta.month = fin.month
`);
processedCount = Math.floor(totalProducts * 0.65);
outputProgress({
status: 'running',
operation: 'Financial metrics updated',
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 ('time_aggregates', 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 time aggregates');
throw error;
} finally {
if (connection) {
connection.release();
}
}
}
module.exports = calculateTimeAggregates;