Fix o3 issues on product-metrics script
This commit is contained in:
@@ -1,4 +1,4 @@
|
||||
1. **Missing Updates for Reorder Point and Safety Stock**
|
||||
1. **Missing Updates for Reorder Point and Safety Stock** [RESOLVED - product-metrics.js]
|
||||
- **Problem:** In the **product_metrics** table (used by the inventory health view), the fields **reorder_point** and **safety_stock** are never updated in the product metrics calculations. Although a helper function (`calculateReorderQuantities`) exists and computes these values, the update query in the `calculateProductMetrics` function does not assign any values to these columns.
|
||||
- **Effect:** The inventory health view relies on these fields (using COALESCE to default them to 0), which means that stock might never be classified as "Reorder" or "Healthy" based on the proper reorder point or safety stock calculations.
|
||||
- **Example:** Even if a product's base metrics would require a reorder (for example, if its days of inventory are low), the view always shows a value of 0 for reorder_point and safety_stock.
|
||||
@@ -10,7 +10,7 @@
|
||||
- **Example:** An external caller expecting to run `calculateMetrics` would instead receive the `calculateProductMetrics` function.
|
||||
- **Fix:** Make sure each script resides in its own module file. Verify that the module boundaries and exports are not accidentally merged or overwritten when deployed.
|
||||
|
||||
3. **Potential Formula Issue in EOQ Calculation (Reorder Qty)**
|
||||
3. **Potential Formula Issue in EOQ Calculation (Reorder Qty)** [RESOLVED - product-metrics.js]
|
||||
- **Problem:** The helper function `calculateReorderQuantities` uses an EOQ formula with a holding cost expressed as a percentage (0.25) rather than a per‐unit cost.
|
||||
- **Effect:** If the intent was to use the traditional EOQ formula (which expects a holding cost per unit rather than a percentage), this could lead to an incorrect reorder quantity.
|
||||
- **Example:** For a given annual demand and fixed order cost, the computed reorder quantity might be higher or lower than expected.
|
||||
|
||||
@@ -153,7 +153,7 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
LEFT JOIN temp_sales_metrics sm ON pm.pid = sm.pid
|
||||
LEFT JOIN temp_purchase_metrics lm ON pm.pid = lm.pid
|
||||
SET
|
||||
pm.inventory_value = p.stock_quantity * p.cost_price,
|
||||
pm.inventory_value = p.stock_quantity * NULLIF(p.cost_price, 0),
|
||||
pm.daily_sales_avg = COALESCE(sm.daily_sales_avg, 0),
|
||||
pm.weekly_sales_avg = COALESCE(sm.weekly_sales_avg, 0),
|
||||
pm.monthly_sales_avg = COALESCE(sm.monthly_sales_avg, 0),
|
||||
@@ -164,12 +164,12 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
pm.avg_lead_time_days = COALESCE(lm.avg_lead_time_days, 30),
|
||||
pm.days_of_inventory = CASE
|
||||
WHEN COALESCE(sm.daily_sales_avg, 0) > 0
|
||||
THEN FLOOR(p.stock_quantity / sm.daily_sales_avg)
|
||||
THEN FLOOR(p.stock_quantity / NULLIF(sm.daily_sales_avg, 0))
|
||||
ELSE NULL
|
||||
END,
|
||||
pm.weeks_of_inventory = CASE
|
||||
WHEN COALESCE(sm.weekly_sales_avg, 0) > 0
|
||||
THEN FLOOR(p.stock_quantity / sm.weekly_sales_avg)
|
||||
THEN FLOOR(p.stock_quantity / NULLIF(sm.weekly_sales_avg, 0))
|
||||
ELSE NULL
|
||||
END,
|
||||
pm.stock_status = CASE
|
||||
@@ -181,10 +181,21 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
WHEN p.stock_quantity / NULLIF(sm.daily_sales_avg, 0) > ? THEN 'Overstocked'
|
||||
ELSE 'Healthy'
|
||||
END,
|
||||
pm.reorder_qty = CASE
|
||||
pm.safety_stock = CASE
|
||||
WHEN COALESCE(sm.daily_sales_avg, 0) > 0 THEN
|
||||
CEIL(sm.daily_sales_avg * SQRT(COALESCE(lm.avg_lead_time_days, 30)) * 1.96)
|
||||
ELSE ?
|
||||
END,
|
||||
pm.reorder_point = CASE
|
||||
WHEN COALESCE(sm.daily_sales_avg, 0) > 0 THEN
|
||||
CEIL(sm.daily_sales_avg * COALESCE(lm.avg_lead_time_days, 30)) +
|
||||
CEIL(sm.daily_sales_avg * SQRT(COALESCE(lm.avg_lead_time_days, 30)) * 1.96)
|
||||
ELSE ?
|
||||
END,
|
||||
pm.reorder_qty = CASE
|
||||
WHEN COALESCE(sm.daily_sales_avg, 0) > 0 AND NULLIF(p.cost_price, 0) IS NOT NULL THEN
|
||||
GREATEST(
|
||||
CEIL(sm.daily_sales_avg * COALESCE(lm.avg_lead_time_days, 30) * 1.96),
|
||||
CEIL(SQRT((2 * (sm.daily_sales_avg * 365) * 25) / (NULLIF(p.cost_price, 0) * 0.25))),
|
||||
?
|
||||
)
|
||||
ELSE ?
|
||||
@@ -195,18 +206,22 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
ELSE 0
|
||||
END,
|
||||
pm.last_calculated_at = NOW()
|
||||
WHERE p.pid IN (?)
|
||||
`, [
|
||||
WHERE p.pid IN (${batch.map(() => '?').join(',')})
|
||||
`,
|
||||
[
|
||||
defaultThresholds.low_stock_threshold,
|
||||
defaultThresholds.critical_days,
|
||||
defaultThresholds.reorder_days,
|
||||
defaultThresholds.overstock_days,
|
||||
defaultThresholds.low_stock_threshold,
|
||||
defaultThresholds.low_stock_threshold,
|
||||
defaultThresholds.low_stock_threshold,
|
||||
defaultThresholds.low_stock_threshold,
|
||||
defaultThresholds.overstock_days,
|
||||
defaultThresholds.overstock_days,
|
||||
batch.map(row => row.pid)
|
||||
]);
|
||||
...batch.map(row => row.pid)
|
||||
]
|
||||
);
|
||||
|
||||
lastPid = batch[batch.length - 1].pid;
|
||||
processedCount += batch.length;
|
||||
@@ -603,9 +618,9 @@ function calculateReorderQuantities(stock, stock_status, daily_sales_avg, avg_le
|
||||
if (daily_sales_avg > 0) {
|
||||
const annual_demand = daily_sales_avg * 365;
|
||||
const order_cost = 25; // Fixed cost per order
|
||||
const holding_cost_percent = 0.25; // 25% annual holding cost
|
||||
const holding_cost = config.cost_price * 0.25; // 25% of unit cost as annual holding cost
|
||||
|
||||
reorder_qty = Math.ceil(Math.sqrt((2 * annual_demand * order_cost) / holding_cost_percent));
|
||||
reorder_qty = Math.ceil(Math.sqrt((2 * annual_demand * order_cost) / holding_cost));
|
||||
} else {
|
||||
// If no sales data, use a basic calculation
|
||||
reorder_qty = Math.max(safety_stock, config.low_stock_threshold);
|
||||
|
||||
Reference in New Issue
Block a user