Fix calculate errors
This commit is contained in:
@@ -7,13 +7,13 @@ require('dotenv').config({ path: path.resolve(__dirname, '..', '.env') });
|
|||||||
|
|
||||||
// Configuration flags for controlling which metrics to calculate
|
// Configuration flags for controlling which metrics to calculate
|
||||||
// Set to 1 to skip the corresponding calculation, 0 to run it
|
// Set to 1 to skip the corresponding calculation, 0 to run it
|
||||||
const SKIP_PRODUCT_METRICS = 1; // Skip all product metrics
|
const SKIP_PRODUCT_METRICS = 1;
|
||||||
const SKIP_TIME_AGGREGATES = 1; // Skip time aggregates
|
const SKIP_TIME_AGGREGATES = 1;
|
||||||
const SKIP_FINANCIAL_METRICS = 1; // Skip financial metrics
|
const SKIP_FINANCIAL_METRICS = 0;
|
||||||
const SKIP_VENDOR_METRICS = 1; // Skip vendor metrics
|
const SKIP_VENDOR_METRICS = 0;
|
||||||
const SKIP_CATEGORY_METRICS = 1; // Skip category metrics
|
const SKIP_CATEGORY_METRICS = 0;
|
||||||
const SKIP_BRAND_METRICS = 1; // Skip brand metrics
|
const SKIP_BRAND_METRICS = 0;
|
||||||
const SKIP_SALES_FORECASTS = 1; // Skip sales forecasts
|
const SKIP_SALES_FORECASTS = 0;
|
||||||
|
|
||||||
// Add error handler for uncaught exceptions
|
// Add error handler for uncaught exceptions
|
||||||
process.on('uncaughtException', (error) => {
|
process.on('uncaughtException', (error) => {
|
||||||
|
|||||||
@@ -151,7 +151,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
|||||||
WITH current_period AS (
|
WITH current_period AS (
|
||||||
SELECT
|
SELECT
|
||||||
pc.cat_id,
|
pc.cat_id,
|
||||||
SUM(o.quantity * o.price) / (1 + COALESCE(ss.seasonality_factor, 0)) as revenue
|
SUM(o.quantity * o.price / (1 + COALESCE(ss.seasonality_factor, 0))) as revenue
|
||||||
FROM product_categories pc
|
FROM product_categories pc
|
||||||
JOIN products p ON pc.pid = p.pid
|
JOIN products p ON pc.pid = p.pid
|
||||||
JOIN orders o ON p.pid = o.pid
|
JOIN orders o ON p.pid = o.pid
|
||||||
@@ -163,7 +163,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
|||||||
previous_period AS (
|
previous_period AS (
|
||||||
SELECT
|
SELECT
|
||||||
pc.cat_id,
|
pc.cat_id,
|
||||||
SUM(o.quantity * o.price) / (1 + COALESCE(ss.seasonality_factor, 0)) as revenue
|
SUM(o.quantity * o.price / (1 + COALESCE(ss.seasonality_factor, 0))) as revenue
|
||||||
FROM product_categories pc
|
FROM product_categories pc
|
||||||
JOIN products p ON pc.pid = p.pid
|
JOIN products p ON pc.pid = p.pid
|
||||||
JOIN orders o ON p.pid = o.pid
|
JOIN orders o ON p.pid = o.pid
|
||||||
@@ -177,7 +177,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
|||||||
SELECT
|
SELECT
|
||||||
pc.cat_id,
|
pc.cat_id,
|
||||||
MONTH(o.date) as month,
|
MONTH(o.date) as month,
|
||||||
SUM(o.quantity * o.price) / (1 + COALESCE(ss.seasonality_factor, 0)) as revenue,
|
SUM(o.quantity * o.price / (1 + COALESCE(ss.seasonality_factor, 0))) as revenue,
|
||||||
COUNT(DISTINCT DATE(o.date)) as days_in_month
|
COUNT(DISTINCT DATE(o.date)) as days_in_month
|
||||||
FROM product_categories pc
|
FROM product_categories pc
|
||||||
JOIN products p ON pc.pid = p.pid
|
JOIN products p ON pc.pid = p.pid
|
||||||
@@ -187,14 +187,24 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
|||||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH)
|
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH)
|
||||||
GROUP BY pc.cat_id, MONTH(o.date)
|
GROUP BY pc.cat_id, MONTH(o.date)
|
||||||
),
|
),
|
||||||
trend_analysis AS (
|
trend_stats AS (
|
||||||
SELECT
|
SELECT
|
||||||
cat_id,
|
cat_id,
|
||||||
REGR_SLOPE(revenue / days_in_month, MONTH) as trend_slope,
|
COUNT(*) as n,
|
||||||
AVG(revenue / days_in_month) as avg_daily_revenue
|
AVG(month) as avg_x,
|
||||||
|
AVG(revenue / days_in_month) as avg_y,
|
||||||
|
SUM(month * (revenue / days_in_month)) as sum_xy,
|
||||||
|
SUM(month * month) as sum_xx
|
||||||
FROM trend_data
|
FROM trend_data
|
||||||
GROUP BY cat_id
|
GROUP BY cat_id
|
||||||
HAVING COUNT(*) >= 6
|
HAVING COUNT(*) >= 6
|
||||||
|
),
|
||||||
|
trend_analysis AS (
|
||||||
|
SELECT
|
||||||
|
cat_id,
|
||||||
|
((n * sum_xy) - (avg_x * n * avg_y)) / ((n * sum_xx) - (n * avg_x * avg_x)) as trend_slope,
|
||||||
|
avg_y as avg_daily_revenue
|
||||||
|
FROM trend_stats
|
||||||
)
|
)
|
||||||
UPDATE category_metrics cm
|
UPDATE category_metrics cm
|
||||||
LEFT JOIN current_period cp ON cm.category_id = cp.cat_id
|
LEFT JOIN current_period cp ON cm.category_id = cp.cat_id
|
||||||
@@ -265,13 +275,23 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
|||||||
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid END) as active_products,
|
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid END) as active_products,
|
||||||
SUM(p.stock_quantity * p.cost_price) as total_value,
|
SUM(p.stock_quantity * p.cost_price) as total_value,
|
||||||
SUM(o.quantity * o.price) as total_revenue,
|
SUM(o.quantity * o.price) as total_revenue,
|
||||||
|
CASE
|
||||||
|
WHEN SUM(o.quantity * o.price) > 0 THEN
|
||||||
|
LEAST(
|
||||||
|
GREATEST(
|
||||||
|
SUM(o.quantity * (o.price - GREATEST(p.cost_price, 0))) * 100.0 /
|
||||||
|
SUM(o.quantity * o.price),
|
||||||
|
-100
|
||||||
|
),
|
||||||
|
100
|
||||||
|
)
|
||||||
|
ELSE 0
|
||||||
|
END as avg_margin,
|
||||||
COALESCE(
|
COALESCE(
|
||||||
SUM(o.quantity * (o.price - p.cost_price)) * 100.0 /
|
LEAST(
|
||||||
NULLIF(SUM(o.quantity * o.price), 0),
|
SUM(o.quantity) / NULLIF(AVG(GREATEST(p.stock_quantity, 0)), 0),
|
||||||
0
|
999.99
|
||||||
) as avg_margin,
|
),
|
||||||
COALESCE(
|
|
||||||
SUM(o.quantity) / NULLIF(AVG(GREATEST(p.stock_quantity, 0)), 0),
|
|
||||||
0
|
0
|
||||||
) as turnover_rate
|
) as turnover_rate
|
||||||
FROM product_categories pc
|
FROM product_categories pc
|
||||||
@@ -286,8 +306,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
|||||||
total_value = VALUES(total_value),
|
total_value = VALUES(total_value),
|
||||||
total_revenue = VALUES(total_revenue),
|
total_revenue = VALUES(total_revenue),
|
||||||
avg_margin = VALUES(avg_margin),
|
avg_margin = VALUES(avg_margin),
|
||||||
turnover_rate = VALUES(turnover_rate),
|
turnover_rate = VALUES(turnover_rate)
|
||||||
last_calculated_at = CURRENT_TIMESTAMP
|
|
||||||
`);
|
`);
|
||||||
|
|
||||||
processedCount = Math.floor(totalProducts * 0.99);
|
processedCount = Math.floor(totalProducts * 0.99);
|
||||||
@@ -342,7 +361,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
|||||||
sales_data AS (
|
sales_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
pc.cat_id,
|
pc.cat_id,
|
||||||
p.brand,
|
COALESCE(p.brand, 'Unknown') as brand,
|
||||||
dr.period_start,
|
dr.period_start,
|
||||||
dr.period_end,
|
dr.period_end,
|
||||||
COUNT(DISTINCT p.pid) as num_products,
|
COUNT(DISTINCT p.pid) as num_products,
|
||||||
|
|||||||
@@ -119,8 +119,7 @@ async function calculateFinancialMetrics(startTime, totalProducts, processedCoun
|
|||||||
WHEN COALESCE(mf.inventory_value, 0) > 0 AND mf.active_days > 0 THEN
|
WHEN COALESCE(mf.inventory_value, 0) > 0 AND mf.active_days > 0 THEN
|
||||||
(COALESCE(mf.gross_profit, 0) * (365.0 / mf.active_days)) / COALESCE(mf.inventory_value, 0)
|
(COALESCE(mf.gross_profit, 0) * (365.0 / mf.active_days)) / COALESCE(mf.inventory_value, 0)
|
||||||
ELSE 0
|
ELSE 0
|
||||||
END,
|
END
|
||||||
pta.last_calculated_at = CURRENT_TIMESTAMP
|
|
||||||
`);
|
`);
|
||||||
|
|
||||||
processedCount = Math.floor(totalProducts * 0.70);
|
processedCount = Math.floor(totalProducts * 0.70);
|
||||||
|
|||||||
@@ -35,6 +35,13 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
|||||||
return processedCount;
|
return processedCount;
|
||||||
}
|
}
|
||||||
|
|
||||||
|
// First ensure all products have a metrics record
|
||||||
|
await connection.query(`
|
||||||
|
INSERT IGNORE INTO product_metrics (pid, last_calculated_at)
|
||||||
|
SELECT pid, NOW()
|
||||||
|
FROM products
|
||||||
|
`);
|
||||||
|
|
||||||
// Calculate base product metrics
|
// Calculate base product metrics
|
||||||
if (!SKIP_PRODUCT_BASE_METRICS) {
|
if (!SKIP_PRODUCT_BASE_METRICS) {
|
||||||
outputProgress({
|
outputProgress({
|
||||||
@@ -59,6 +66,8 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
|||||||
JOIN (
|
JOIN (
|
||||||
SELECT
|
SELECT
|
||||||
p.pid,
|
p.pid,
|
||||||
|
p.stock_quantity,
|
||||||
|
p.cost_price,
|
||||||
p.cost_price * p.stock_quantity as inventory_value,
|
p.cost_price * p.stock_quantity as inventory_value,
|
||||||
SUM(o.quantity) as total_quantity,
|
SUM(o.quantity) as total_quantity,
|
||||||
COUNT(DISTINCT o.order_number) as number_of_orders,
|
COUNT(DISTINCT o.order_number) as number_of_orders,
|
||||||
@@ -71,7 +80,7 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
|||||||
COUNT(DISTINCT DATE(o.date)) as active_days
|
COUNT(DISTINCT DATE(o.date)) as active_days
|
||||||
FROM products p
|
FROM products p
|
||||||
LEFT JOIN orders o ON p.pid = o.pid AND o.canceled = false
|
LEFT JOIN orders o ON p.pid = o.pid AND o.canceled = false
|
||||||
GROUP BY p.pid
|
GROUP BY p.pid, p.stock_quantity, p.cost_price
|
||||||
) stats ON pm.pid = stats.pid
|
) stats ON pm.pid = stats.pid
|
||||||
SET
|
SET
|
||||||
pm.inventory_value = COALESCE(stats.inventory_value, 0),
|
pm.inventory_value = COALESCE(stats.inventory_value, 0),
|
||||||
@@ -89,12 +98,12 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
|||||||
pm.last_sale_date = stats.last_sale_date,
|
pm.last_sale_date = stats.last_sale_date,
|
||||||
pm.days_of_inventory = CASE
|
pm.days_of_inventory = CASE
|
||||||
WHEN COALESCE(stats.total_quantity / NULLIF(stats.active_days, 0), 0) > 0
|
WHEN COALESCE(stats.total_quantity / NULLIF(stats.active_days, 0), 0) > 0
|
||||||
THEN FLOOR(p.stock_quantity / (stats.total_quantity / stats.active_days))
|
THEN FLOOR(stats.stock_quantity / (stats.total_quantity / stats.active_days))
|
||||||
ELSE NULL
|
ELSE NULL
|
||||||
END,
|
END,
|
||||||
pm.weeks_of_inventory = CASE
|
pm.weeks_of_inventory = CASE
|
||||||
WHEN COALESCE(stats.total_quantity / NULLIF(stats.active_days, 0), 0) > 0
|
WHEN COALESCE(stats.total_quantity / NULLIF(stats.active_days, 0), 0) > 0
|
||||||
THEN FLOOR(p.stock_quantity / (stats.total_quantity / stats.active_days) / 7)
|
THEN FLOOR(stats.stock_quantity / (stats.total_quantity / stats.active_days) / 7)
|
||||||
ELSE NULL
|
ELSE NULL
|
||||||
END,
|
END,
|
||||||
pm.gmroi = CASE
|
pm.gmroi = CASE
|
||||||
@@ -239,8 +248,7 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
|||||||
avg_price = VALUES(avg_price),
|
avg_price = VALUES(avg_price),
|
||||||
profit_margin = VALUES(profit_margin),
|
profit_margin = VALUES(profit_margin),
|
||||||
inventory_value = VALUES(inventory_value),
|
inventory_value = VALUES(inventory_value),
|
||||||
gmroi = VALUES(gmroi),
|
gmroi = VALUES(gmroi)
|
||||||
last_calculated_at = CURRENT_TIMESTAMP
|
|
||||||
`);
|
`);
|
||||||
|
|
||||||
processedCount = Math.floor(totalProducts * 0.6);
|
processedCount = Math.floor(totalProducts * 0.6);
|
||||||
|
|||||||
@@ -52,7 +52,9 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
|||||||
stock_received,
|
stock_received,
|
||||||
stock_ordered,
|
stock_ordered,
|
||||||
avg_price,
|
avg_price,
|
||||||
profit_margin
|
profit_margin,
|
||||||
|
inventory_value,
|
||||||
|
gmroi
|
||||||
)
|
)
|
||||||
WITH sales_data AS (
|
WITH sales_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
@@ -69,11 +71,12 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
|||||||
ELSE ((SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) -
|
ELSE ((SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) -
|
||||||
SUM(COALESCE(p.cost_price, 0) * o.quantity)) /
|
SUM(COALESCE(p.cost_price, 0) * o.quantity)) /
|
||||||
SUM((o.price - COALESCE(o.discount, 0)) * o.quantity)) * 100
|
SUM((o.price - COALESCE(o.discount, 0)) * o.quantity)) * 100
|
||||||
END as profit_margin
|
END as profit_margin,
|
||||||
|
p.cost_price * p.stock_quantity as inventory_value
|
||||||
FROM orders o
|
FROM orders o
|
||||||
JOIN products p ON o.pid = p.pid
|
JOIN products p ON o.pid = p.pid
|
||||||
WHERE o.canceled = 0
|
WHERE o.canceled = 0
|
||||||
GROUP BY o.pid, YEAR(o.date), MONTH(o.date)
|
GROUP BY o.pid, YEAR(o.date), MONTH(o.date), p.cost_price, p.stock_quantity
|
||||||
),
|
),
|
||||||
purchase_data AS (
|
purchase_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
@@ -81,40 +84,9 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
|||||||
YEAR(date) as year,
|
YEAR(date) as year,
|
||||||
MONTH(date) as month,
|
MONTH(date) as month,
|
||||||
SUM(received) as stock_received,
|
SUM(received) as stock_received,
|
||||||
SUM(ordered) as stock_ordered,
|
SUM(ordered) as stock_ordered
|
||||||
COUNT(DISTINCT CASE WHEN receiving_status = 40 THEN id END) as fulfilled_orders,
|
|
||||||
COUNT(DISTINCT id) as total_orders,
|
|
||||||
AVG(CASE
|
|
||||||
WHEN receiving_status = 40
|
|
||||||
THEN DATEDIFF(received_date, date)
|
|
||||||
END) as avg_lead_time,
|
|
||||||
SUM(CASE
|
|
||||||
WHEN receiving_status = 40 AND received_date > expected_date
|
|
||||||
THEN 1 ELSE 0
|
|
||||||
END) as late_deliveries
|
|
||||||
FROM purchase_orders
|
FROM purchase_orders
|
||||||
GROUP BY pid, YEAR(date), MONTH(date)
|
GROUP BY pid, YEAR(date), MONTH(date)
|
||||||
),
|
|
||||||
stock_trends AS (
|
|
||||||
SELECT
|
|
||||||
p.pid,
|
|
||||||
YEAR(po.date) as year,
|
|
||||||
MONTH(po.date) as month,
|
|
||||||
AVG(p.stock_quantity) as avg_stock_level,
|
|
||||||
STDDEV(p.stock_quantity) as stock_volatility,
|
|
||||||
SUM(CASE
|
|
||||||
WHEN p.stock_quantity <= COALESCE(pm.reorder_point, 5)
|
|
||||||
THEN 1 ELSE 0
|
|
||||||
END) as days_below_reorder,
|
|
||||||
COUNT(*) as total_days
|
|
||||||
FROM products p
|
|
||||||
CROSS JOIN (
|
|
||||||
SELECT DISTINCT DATE(date) as date
|
|
||||||
FROM purchase_orders
|
|
||||||
WHERE date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
|
||||||
) po
|
|
||||||
LEFT JOIN product_metrics pm ON p.pid = pm.pid
|
|
||||||
GROUP BY p.pid, YEAR(po.date), MONTH(po.date)
|
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
s.pid,
|
s.pid,
|
||||||
@@ -128,23 +100,17 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
|||||||
COALESCE(p.stock_ordered, 0) as stock_ordered,
|
COALESCE(p.stock_ordered, 0) as stock_ordered,
|
||||||
s.avg_price,
|
s.avg_price,
|
||||||
s.profit_margin,
|
s.profit_margin,
|
||||||
COALESCE(p.fulfilled_orders, 0) as fulfilled_orders,
|
s.inventory_value,
|
||||||
COALESCE(p.total_orders, 0) as total_orders,
|
CASE
|
||||||
COALESCE(p.avg_lead_time, 0) as avg_lead_time,
|
WHEN s.inventory_value > 0 THEN
|
||||||
COALESCE(p.late_deliveries, 0) as late_deliveries,
|
(s.total_revenue - s.total_cost) / s.inventory_value
|
||||||
COALESCE(st.avg_stock_level, 0) as avg_stock_level,
|
ELSE 0
|
||||||
COALESCE(st.stock_volatility, 0) as stock_volatility,
|
END as gmroi
|
||||||
COALESCE(st.days_below_reorder, 0) as days_below_reorder,
|
|
||||||
COALESCE(st.total_days, 0) as total_days
|
|
||||||
FROM sales_data s
|
FROM sales_data s
|
||||||
LEFT JOIN purchase_data p
|
LEFT JOIN purchase_data p
|
||||||
ON s.pid = p.pid
|
ON s.pid = p.pid
|
||||||
AND s.year = p.year
|
AND s.year = p.year
|
||||||
AND s.month = p.month
|
AND s.month = p.month
|
||||||
LEFT JOIN stock_trends st
|
|
||||||
ON s.pid = st.pid
|
|
||||||
AND s.year = st.year
|
|
||||||
AND s.month = st.month
|
|
||||||
UNION
|
UNION
|
||||||
SELECT
|
SELECT
|
||||||
p.pid,
|
p.pid,
|
||||||
@@ -158,23 +124,13 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
|||||||
p.stock_ordered,
|
p.stock_ordered,
|
||||||
0 as avg_price,
|
0 as avg_price,
|
||||||
0 as profit_margin,
|
0 as profit_margin,
|
||||||
p.fulfilled_orders,
|
(SELECT cost_price * stock_quantity FROM products WHERE pid = p.pid) as inventory_value,
|
||||||
p.total_orders,
|
0 as gmroi
|
||||||
p.avg_lead_time,
|
|
||||||
p.late_deliveries,
|
|
||||||
st.avg_stock_level,
|
|
||||||
st.stock_volatility,
|
|
||||||
st.days_below_reorder,
|
|
||||||
st.total_days
|
|
||||||
FROM purchase_data p
|
FROM purchase_data p
|
||||||
LEFT JOIN sales_data s
|
LEFT JOIN sales_data s
|
||||||
ON p.pid = s.pid
|
ON p.pid = s.pid
|
||||||
AND p.year = s.year
|
AND p.year = s.year
|
||||||
AND p.month = s.month
|
AND p.month = s.month
|
||||||
LEFT JOIN stock_trends st
|
|
||||||
ON p.pid = st.pid
|
|
||||||
AND p.year = st.year
|
|
||||||
AND p.month = st.month
|
|
||||||
WHERE s.pid IS NULL
|
WHERE s.pid IS NULL
|
||||||
ON DUPLICATE KEY UPDATE
|
ON DUPLICATE KEY UPDATE
|
||||||
total_quantity_sold = VALUES(total_quantity_sold),
|
total_quantity_sold = VALUES(total_quantity_sold),
|
||||||
@@ -185,7 +141,8 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
|||||||
stock_ordered = VALUES(stock_ordered),
|
stock_ordered = VALUES(stock_ordered),
|
||||||
avg_price = VALUES(avg_price),
|
avg_price = VALUES(avg_price),
|
||||||
profit_margin = VALUES(profit_margin),
|
profit_margin = VALUES(profit_margin),
|
||||||
last_calculated_at = CURRENT_TIMESTAMP
|
inventory_value = VALUES(inventory_value),
|
||||||
|
gmroi = VALUES(gmroi)
|
||||||
`);
|
`);
|
||||||
|
|
||||||
processedCount = Math.floor(totalProducts * 0.60);
|
processedCount = Math.floor(totalProducts * 0.60);
|
||||||
@@ -231,8 +188,7 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
|||||||
WHEN COALESCE(fin.inventory_value, 0) > 0 AND fin.days_in_period > 0 THEN
|
WHEN COALESCE(fin.inventory_value, 0) > 0 AND fin.days_in_period > 0 THEN
|
||||||
(COALESCE(fin.gross_profit, 0) * (365.0 / fin.days_in_period)) / COALESCE(fin.inventory_value, 0)
|
(COALESCE(fin.gross_profit, 0) * (365.0 / fin.days_in_period)) / COALESCE(fin.inventory_value, 0)
|
||||||
ELSE 0
|
ELSE 0
|
||||||
END,
|
END
|
||||||
pta.last_calculated_at = CURRENT_TIMESTAMP
|
|
||||||
`);
|
`);
|
||||||
|
|
||||||
processedCount = Math.floor(totalProducts * 0.65);
|
processedCount = Math.floor(totalProducts * 0.65);
|
||||||
|
|||||||
@@ -218,6 +218,7 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
|||||||
JOIN orders o ON p.pid = o.pid
|
JOIN orders o ON p.pid = o.pid
|
||||||
WHERE o.canceled = false
|
WHERE o.canceled = false
|
||||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
||||||
|
AND p.vendor IS NOT NULL
|
||||||
GROUP BY p.vendor, YEAR(o.date), MONTH(o.date)
|
GROUP BY p.vendor, YEAR(o.date), MONTH(o.date)
|
||||||
),
|
),
|
||||||
monthly_po AS (
|
monthly_po AS (
|
||||||
@@ -238,6 +239,7 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
|||||||
FROM products p
|
FROM products p
|
||||||
JOIN purchase_orders po ON p.pid = po.pid
|
JOIN purchase_orders po ON p.pid = po.pid
|
||||||
WHERE po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
WHERE po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
||||||
|
AND p.vendor IS NOT NULL
|
||||||
GROUP BY p.vendor, YEAR(po.date), MONTH(po.date)
|
GROUP BY p.vendor, YEAR(po.date), MONTH(po.date)
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
@@ -248,7 +250,7 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
|||||||
COALESCE(mp.late_orders, 0) as late_orders,
|
COALESCE(mp.late_orders, 0) as late_orders,
|
||||||
COALESCE(mp.avg_lead_time_days, 0) as avg_lead_time_days,
|
COALESCE(mp.avg_lead_time_days, 0) as avg_lead_time_days,
|
||||||
COALESCE(mp.total_purchase_value, 0) as total_purchase_value,
|
COALESCE(mp.total_purchase_value, 0) as total_purchase_value,
|
||||||
COALESCE(mo.total_revenue, 0) as total_revenue,
|
mo.total_revenue,
|
||||||
CASE
|
CASE
|
||||||
WHEN mo.total_revenue > 0
|
WHEN mo.total_revenue > 0
|
||||||
THEN (mo.total_margin / mo.total_revenue) * 100
|
THEN (mo.total_margin / mo.total_revenue) * 100
|
||||||
@@ -258,6 +260,22 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
|||||||
LEFT JOIN monthly_po mp ON mo.vendor = mp.vendor
|
LEFT JOIN monthly_po mp ON mo.vendor = mp.vendor
|
||||||
AND mo.year = mp.year
|
AND mo.year = mp.year
|
||||||
AND mo.month = mp.month
|
AND mo.month = mp.month
|
||||||
|
UNION
|
||||||
|
SELECT
|
||||||
|
mp.vendor,
|
||||||
|
mp.year,
|
||||||
|
mp.month,
|
||||||
|
mp.total_po as total_orders,
|
||||||
|
mp.late_orders,
|
||||||
|
mp.avg_lead_time_days,
|
||||||
|
mp.total_purchase_value,
|
||||||
|
0 as total_revenue,
|
||||||
|
0 as avg_margin_percent
|
||||||
|
FROM monthly_po mp
|
||||||
|
LEFT JOIN monthly_orders mo ON mp.vendor = mo.vendor
|
||||||
|
AND mp.year = mo.year
|
||||||
|
AND mp.month = mo.month
|
||||||
|
WHERE mo.vendor IS NULL
|
||||||
ON DUPLICATE KEY UPDATE
|
ON DUPLICATE KEY UPDATE
|
||||||
total_orders = VALUES(total_orders),
|
total_orders = VALUES(total_orders),
|
||||||
late_orders = VALUES(late_orders),
|
late_orders = VALUES(late_orders),
|
||||||
|
|||||||
Reference in New Issue
Block a user