Add new dashboard backend

This commit is contained in:
2025-01-13 00:14:15 -05:00
parent 024155d054
commit 88c51059bb
14 changed files with 1085 additions and 727 deletions

View File

@@ -179,6 +179,294 @@ function cancelCalculation() {
// Handle SIGTERM signal for cancellation
process.on('SIGTERM', cancelCalculation);
// Calculate GMROI and other financial metrics
async function calculateFinancialMetrics(connection, startTime, totalProducts) {
outputProgress({
status: 'running',
operation: 'Calculating financial metrics',
current: Math.floor(totalProducts * 0.6),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.6), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.6)),
percentage: '60'
});
await connection.query(`
UPDATE product_metrics pm
JOIN (
SELECT
p.product_id,
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
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
WHERE o.canceled = false
AND DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 12 MONTH)
GROUP BY p.product_id
) fin ON pm.product_id = fin.product_id
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
THEN (COALESCE(fin.gross_profit, 0) / COALESCE(fin.inventory_value, 0)) * 100
ELSE 0
END
`);
// Update time-based aggregates with financial metrics
await connection.query(`
UPDATE product_time_aggregates pta
JOIN (
SELECT
p.product_id,
YEAR(o.date) as year,
MONTH(o.date) as month,
p.cost_price * p.stock_quantity as inventory_value,
SUM((o.price - p.cost_price) * o.quantity) /
NULLIF(p.cost_price * p.stock_quantity, 0) * 100 as gmroi
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
WHERE o.canceled = false
GROUP BY p.product_id, YEAR(o.date), MONTH(o.date)
) fin ON pta.product_id = fin.product_id
AND pta.year = fin.year
AND pta.month = fin.month
SET
pta.inventory_value = COALESCE(fin.inventory_value, 0),
pta.gmroi = COALESCE(fin.gmroi, 0)
`);
}
// Calculate vendor metrics
async function calculateVendorMetrics(connection, startTime, totalProducts) {
outputProgress({
status: 'running',
operation: 'Calculating vendor metrics',
current: Math.floor(totalProducts * 0.7),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.7), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.7)),
percentage: '70'
});
await connection.query(`
INSERT INTO vendor_metrics (
vendor,
last_calculated_at,
avg_lead_time_days,
on_time_delivery_rate,
order_fill_rate,
total_orders,
total_late_orders,
total_purchase_value,
avg_order_value
)
SELECT
po.vendor,
NOW() as last_calculated_at,
AVG(
CASE
WHEN po.received_date IS NOT NULL
THEN DATEDIFF(po.received_date, po.date)
ELSE NULL
END
) as avg_lead_time_days,
(
COUNT(CASE WHEN po.received_date <= po.expected_date THEN 1 END) * 100.0 /
NULLIF(COUNT(*), 0)
) as on_time_delivery_rate,
(
SUM(CASE WHEN po.received >= po.ordered THEN 1 ELSE 0 END) * 100.0 /
NULLIF(COUNT(*), 0)
) as order_fill_rate,
COUNT(*) as total_orders,
COUNT(CASE WHEN po.received_date > po.expected_date THEN 1 END) as total_late_orders,
SUM(po.ordered * po.cost_price) as total_purchase_value,
AVG(po.ordered * po.cost_price) as avg_order_value
FROM purchase_orders po
WHERE po.status = 'closed'
AND po.date >= DATE_SUB(CURDATE(), INTERVAL 12 MONTH)
GROUP BY po.vendor
ON DUPLICATE KEY UPDATE
last_calculated_at = VALUES(last_calculated_at),
avg_lead_time_days = VALUES(avg_lead_time_days),
on_time_delivery_rate = VALUES(on_time_delivery_rate),
order_fill_rate = VALUES(order_fill_rate),
total_orders = VALUES(total_orders),
total_late_orders = VALUES(total_late_orders),
total_purchase_value = VALUES(total_purchase_value),
avg_order_value = VALUES(avg_order_value)
`);
}
// Calculate turnover rate metrics
async function calculateTurnoverMetrics(connection, startTime, totalProducts) {
outputProgress({
status: 'running',
operation: 'Calculating turnover metrics',
current: Math.floor(totalProducts * 0.75),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.75), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.75)),
percentage: '75'
});
await connection.query(`
WITH product_turnover AS (
SELECT
p.product_id,
p.vendor,
pc.category_id,
COALESCE(
(SELECT calculation_period_days
FROM turnover_config tc
WHERE tc.category_id = pc.category_id
AND tc.vendor = p.vendor
LIMIT 1),
COALESCE(
(SELECT calculation_period_days
FROM turnover_config tc
WHERE tc.category_id = pc.category_id
AND tc.vendor IS NULL
LIMIT 1),
COALESCE(
(SELECT calculation_period_days
FROM turnover_config tc
WHERE tc.category_id IS NULL
AND tc.vendor = p.vendor
LIMIT 1),
(SELECT calculation_period_days
FROM turnover_config
WHERE category_id IS NULL
AND vendor IS NULL
LIMIT 1)
)
)
) as calculation_period_days,
SUM(o.quantity) as total_quantity_sold,
AVG(p.stock_quantity) as avg_stock_level
FROM products p
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
LEFT JOIN orders o ON p.product_id = o.product_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
AND o.canceled = 0
GROUP BY p.product_id, p.vendor, pc.category_id
)
UPDATE product_metrics pm
JOIN product_turnover pt ON pm.product_id = pt.product_id
SET
pm.turnover_rate = CASE
WHEN pt.avg_stock_level > 0
THEN (pt.total_quantity_sold / pt.avg_stock_level) * (30.0 / pt.calculation_period_days)
ELSE 0
END,
pm.last_calculated_at = NOW()
`);
}
// Enhance lead time calculations
async function calculateLeadTimeMetrics(connection, startTime, totalProducts) {
outputProgress({
status: 'running',
operation: 'Calculating lead time metrics',
current: Math.floor(totalProducts * 0.8),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.8), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.8)),
percentage: '80'
});
await connection.query(`
WITH lead_time_stats AS (
SELECT
p.product_id,
p.vendor,
pc.category_id,
AVG(DATEDIFF(po.received_date, po.date)) as current_lead_time,
COALESCE(
(SELECT target_days
FROM lead_time_thresholds lt
WHERE lt.category_id = pc.category_id
AND lt.vendor = p.vendor
LIMIT 1),
COALESCE(
(SELECT target_days
FROM lead_time_thresholds lt
WHERE lt.category_id = pc.category_id
AND lt.vendor IS NULL
LIMIT 1),
COALESCE(
(SELECT target_days
FROM lead_time_thresholds lt
WHERE lt.category_id IS NULL
AND lt.vendor = p.vendor
LIMIT 1),
(SELECT target_days
FROM lead_time_thresholds
WHERE category_id IS NULL
AND vendor IS NULL
LIMIT 1)
)
)
) as target_lead_time,
COALESCE(
(SELECT warning_days
FROM lead_time_thresholds lt
WHERE lt.category_id = pc.category_id
AND lt.vendor = p.vendor
LIMIT 1),
COALESCE(
(SELECT warning_days
FROM lead_time_thresholds lt
WHERE lt.category_id = pc.category_id
AND lt.vendor IS NULL
LIMIT 1),
COALESCE(
(SELECT warning_days
FROM lead_time_thresholds lt
WHERE lt.category_id IS NULL
AND lt.vendor = p.vendor
LIMIT 1),
(SELECT warning_days
FROM lead_time_thresholds
WHERE category_id IS NULL
AND vendor IS NULL
LIMIT 1)
)
)
) as warning_lead_time
FROM products p
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
LEFT JOIN purchase_orders po ON p.product_id = po.product_id
WHERE po.status = 'completed'
AND po.received_date IS NOT NULL
AND po.date >= DATE_SUB(CURDATE(), INTERVAL 90 DAY)
GROUP BY p.product_id, p.vendor, pc.category_id
)
UPDATE product_metrics pm
JOIN lead_time_stats lt ON pm.product_id = lt.product_id
SET
pm.current_lead_time = lt.current_lead_time,
pm.target_lead_time = lt.target_lead_time,
pm.lead_time_status = CASE
WHEN lt.current_lead_time <= lt.target_lead_time THEN 'On Target'
WHEN lt.current_lead_time <= lt.warning_lead_time THEN 'Warning'
ELSE 'Critical'
END,
pm.last_calculated_at = NOW()
`);
}
// Update the main calculation function to include our new calculations
async function calculateMetrics() {
let pool;
const startTime = Date.now();
@@ -191,6 +479,17 @@ async function calculateMetrics() {
const connection = await pool.getConnection();
try {
outputProgress({
status: 'running',
operation: 'Starting metrics calculation',
current: 0,
total: 100,
elapsed: '0s',
remaining: 'Calculating...',
rate: 0,
percentage: '0'
});
// Get total number of products
const [countResult] = await connection.query('SELECT COUNT(*) as total FROM products')
.catch(err => {
@@ -202,7 +501,7 @@ async function calculateMetrics() {
// Initial progress with percentage
outputProgress({
status: 'running',
operation: 'Processing products',
operation: 'Processing sales and stock metrics',
current: processedCount,
total: totalProducts,
elapsed: '0s',
@@ -467,64 +766,6 @@ async function calculateMetrics() {
throw err;
});
// Get stock thresholds for this product's category/vendor
const [thresholds] = await connection.query(`
WITH product_info AS (
SELECT
p.product_id,
p.vendor,
pc.category_id
FROM products p
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
WHERE p.product_id = ?
),
threshold_options AS (
SELECT
st.*,
CASE
WHEN st.category_id = pi.category_id AND st.vendor = pi.vendor THEN 1 -- Category + vendor match
WHEN st.category_id = pi.category_id AND st.vendor IS NULL THEN 2 -- Category match
WHEN st.category_id IS NULL AND st.vendor = pi.vendor THEN 3 -- Vendor match
WHEN st.category_id IS NULL AND st.vendor IS NULL THEN 4 -- Default
ELSE 5
END as priority
FROM product_info pi
CROSS JOIN stock_thresholds st
WHERE (st.category_id = pi.category_id OR st.category_id IS NULL)
AND (st.vendor = pi.vendor OR st.vendor IS NULL)
)
SELECT
COALESCE(
(SELECT critical_days
FROM threshold_options
ORDER BY priority LIMIT 1),
7
) as critical_days,
COALESCE(
(SELECT reorder_days
FROM threshold_options
ORDER BY priority LIMIT 1),
14
) as reorder_days,
COALESCE(
(SELECT overstock_days
FROM threshold_options
ORDER BY priority LIMIT 1),
90
) as overstock_days
`, [product.product_id]).catch(err => {
logError(err, `Failed to get thresholds for product ${product.product_id}`);
throw err;
});
const threshold = thresholds[0] || {
critical_days: 7,
reorder_days: 14,
overstock_days: 90,
safety_stock_days: 14, // Add default safety stock days
service_level: 95.0 // Add default service level
};
// Calculate metrics
const metrics = salesMetrics[0] || {};
const purchases = purchaseMetrics[0] || {};
@@ -544,13 +785,13 @@ async function calculateMetrics() {
// Calculate stock status using configurable thresholds with proper handling of zero sales
const stock_status = daily_sales_avg === 0 ? 'New' :
stock.stock_quantity <= Math.max(1, Math.ceil(daily_sales_avg * threshold.critical_days)) ? 'Critical' :
stock.stock_quantity <= Math.max(1, Math.ceil(daily_sales_avg * threshold.reorder_days)) ? 'Reorder' :
stock.stock_quantity > Math.max(1, daily_sales_avg * threshold.overstock_days) ? 'Overstocked' : 'Healthy';
stock.stock_quantity <= Math.max(1, Math.ceil(daily_sales_avg * config.critical_days)) ? 'Critical' :
stock.stock_quantity <= Math.max(1, Math.ceil(daily_sales_avg * config.reorder_days)) ? 'Reorder' :
stock.stock_quantity > Math.max(1, daily_sales_avg * config.overstock_days) ? 'Overstocked' : 'Healthy';
// Calculate safety stock using configured values with proper defaults
const safety_stock = daily_sales_avg > 0 ?
Math.max(1, Math.ceil(daily_sales_avg * (threshold.safety_stock_days || 14) * ((threshold.service_level || 95.0) / 100))) :
Math.max(1, Math.ceil(daily_sales_avg * (config.safety_stock_days || 14) * ((config.service_level || 95.0) / 100))) :
null;
// Add to batch update
@@ -565,8 +806,8 @@ async function calculateMetrics() {
metrics.last_sale_date || null,
daily_sales_avg > 0 ? stock.stock_quantity / daily_sales_avg : null,
weekly_sales_avg > 0 ? stock.stock_quantity / weekly_sales_avg : null,
daily_sales_avg > 0 ? Math.max(1, Math.ceil(daily_sales_avg * threshold.reorder_days)) : null,
daily_sales_avg > 0 ? Math.max(1, Math.ceil(daily_sales_avg * threshold.critical_days)) : null,
daily_sales_avg > 0 ? Math.max(1, Math.ceil(daily_sales_avg * config.reorder_days)) : null,
safety_stock,
margin_percent,
metrics.total_revenue || 0,
inventory_value || 0,
@@ -633,31 +874,45 @@ async function calculateMetrics() {
}
}
// Update progress for ABC classification
if (isCancelled) {
throw new Error('Operation cancelled');
}
outputProgress({
status: 'running',
operation: 'Starting ABC classification',
current: Math.floor(totalProducts * 0.7), // Start from 70% after product processing
operation: 'Starting financial metrics calculation',
current: Math.floor(totalProducts * 0.6),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.6), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.6)),
percentage: '60'
});
await calculateFinancialMetrics(connection, startTime, totalProducts);
outputProgress({
status: 'running',
operation: 'Starting vendor metrics calculation',
current: Math.floor(totalProducts * 0.7),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.7), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.7)),
percentage: '70'
});
// Calculate ABC classification using configured thresholds
if (isCancelled) {
throw new Error('Operation cancelled');
}
const [abcConfig] = await connection.query('SELECT a_threshold, b_threshold FROM abc_classification_config WHERE id = 1');
const abcThresholds = abcConfig[0] || { a_threshold: 20, b_threshold: 50 };
await calculateVendorMetrics(connection, startTime, totalProducts);
outputProgress({
status: 'running',
operation: 'Calculating ABC rankings',
operation: 'Starting turnover metrics calculation',
current: Math.floor(totalProducts * 0.75),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.75), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.75)),
percentage: '75'
});
await calculateTurnoverMetrics(connection, startTime, totalProducts);
outputProgress({
status: 'running',
operation: 'Starting lead time metrics calculation',
current: Math.floor(totalProducts * 0.8),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
@@ -665,6 +920,25 @@ async function calculateMetrics() {
rate: calculateRate(startTime, Math.floor(totalProducts * 0.8)),
percentage: '80'
});
await calculateLeadTimeMetrics(connection, startTime, totalProducts);
// Calculate ABC classification
if (isCancelled) {
throw new Error('Operation cancelled');
}
outputProgress({
status: 'running',
operation: 'Starting ABC classification',
current: Math.floor(totalProducts * 0.7),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.7), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.7)),
percentage: '70'
});
const [abcConfig] = await connection.query('SELECT a_threshold, b_threshold FROM abc_classification_config WHERE id = 1');
const abcThresholds = abcConfig[0] || { a_threshold: 20, b_threshold: 50 };
await connection.query(`
WITH revenue_rankings AS (
@@ -690,7 +964,7 @@ async function calculateMetrics() {
pm.last_calculated_at = NOW()
`, [abcThresholds.a_threshold, abcThresholds.b_threshold]);
// Update progress for time-based aggregates
// Calculate time-based aggregates
if (isCancelled) {
throw new Error('Operation cancelled');
}
@@ -705,23 +979,8 @@ async function calculateMetrics() {
percentage: '85'
});
// Calculate time-based aggregates
if (isCancelled) {
throw new Error('Operation cancelled');
}
await connection.query('TRUNCATE TABLE product_time_aggregates;');
outputProgress({
status: 'running',
operation: 'Calculating sales aggregates',
current: Math.floor(totalProducts * 0.9),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.9), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.9)),
percentage: '90'
});
await connection.query(`
INSERT INTO product_time_aggregates (
product_id,
@@ -806,83 +1065,6 @@ async function calculateMetrics() {
WHERE s.product_id IS NULL
`);
outputProgress({
status: 'running',
operation: 'Time-based aggregates complete',
current: totalProducts,
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, totalProducts, totalProducts),
rate: calculateRate(startTime, totalProducts),
percentage: '100'
});
// Update progress for vendor metrics
if (isCancelled) {
throw new Error('Operation cancelled');
}
outputProgress({
status: 'running',
operation: 'Starting vendor metrics calculation',
current: Math.floor(totalProducts * 0.95),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.95), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.95)),
percentage: '95'
});
// Calculate vendor metrics with fixed order fill rate calculation
if (isCancelled) {
throw new Error('Operation cancelled');
}
await connection.query(`
INSERT INTO vendor_metrics (
vendor,
last_calculated_at,
avg_lead_time_days,
on_time_delivery_rate,
order_fill_rate,
total_orders,
total_late_orders
)
SELECT
vendor,
NOW() as last_calculated_at,
COALESCE(AVG(DATEDIFF(received_date, date)), 0) as avg_lead_time_days,
COALESCE(
(COUNT(CASE WHEN DATEDIFF(received_date, date) <= 14 THEN 1 END) * 100.0 / NULLIF(COUNT(*), 0)),
0
) as on_time_delivery_rate,
CASE
WHEN SUM(ordered) = 0 THEN 0
ELSE LEAST(100, GREATEST(0, (SUM(CASE WHEN received >= 0 THEN received ELSE 0 END) * 100.0 / SUM(ordered))))
END as order_fill_rate,
COUNT(DISTINCT po_id) as total_orders,
COUNT(CASE WHEN DATEDIFF(received_date, date) > 14 THEN 1 END) as total_late_orders
FROM purchase_orders
WHERE status = 'closed'
GROUP BY vendor
ON DUPLICATE KEY UPDATE
last_calculated_at = VALUES(last_calculated_at),
avg_lead_time_days = VALUES(avg_lead_time_days),
on_time_delivery_rate = VALUES(on_time_delivery_rate),
order_fill_rate = VALUES(order_fill_rate),
total_orders = VALUES(total_orders),
total_late_orders = VALUES(total_late_orders)
`);
outputProgress({
status: 'running',
operation: 'Vendor metrics complete',
current: Math.floor(totalProducts * 0.98),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.98), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.98)),
percentage: '98'
});
// Final success message
outputProgress({
status: 'complete',