Calculate script optimizations, reset metrics script fixes, calculate script fixes
This commit is contained in:
@@ -58,7 +58,7 @@ CREATE TABLE IF NOT EXISTS product_metrics (
|
|||||||
abc_class CHAR(1),
|
abc_class CHAR(1),
|
||||||
stock_status VARCHAR(20),
|
stock_status VARCHAR(20),
|
||||||
-- Turnover metrics
|
-- Turnover metrics
|
||||||
turnover_rate DECIMAL(10,3),
|
turnover_rate DECIMAL(12,3),
|
||||||
-- Lead time metrics
|
-- Lead time metrics
|
||||||
current_lead_time INT,
|
current_lead_time INT,
|
||||||
target_lead_time INT,
|
target_lead_time INT,
|
||||||
@@ -68,7 +68,10 @@ CREATE TABLE IF NOT EXISTS product_metrics (
|
|||||||
INDEX idx_metrics_revenue (total_revenue),
|
INDEX idx_metrics_revenue (total_revenue),
|
||||||
INDEX idx_metrics_stock_status (stock_status),
|
INDEX idx_metrics_stock_status (stock_status),
|
||||||
INDEX idx_metrics_lead_time (lead_time_status),
|
INDEX idx_metrics_lead_time (lead_time_status),
|
||||||
INDEX idx_metrics_turnover (turnover_rate)
|
INDEX idx_metrics_turnover (turnover_rate),
|
||||||
|
INDEX idx_metrics_last_calculated (last_calculated_at),
|
||||||
|
INDEX idx_metrics_abc (abc_class),
|
||||||
|
INDEX idx_metrics_sales (daily_sales_avg, weekly_sales_avg, monthly_sales_avg)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- New table for time-based aggregates
|
-- New table for time-based aggregates
|
||||||
@@ -117,7 +120,9 @@ CREATE TABLE IF NOT EXISTS vendor_metrics (
|
|||||||
PRIMARY KEY (vendor),
|
PRIMARY KEY (vendor),
|
||||||
FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE,
|
FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE,
|
||||||
INDEX idx_vendor_performance (on_time_delivery_rate),
|
INDEX idx_vendor_performance (on_time_delivery_rate),
|
||||||
INDEX idx_vendor_status (status)
|
INDEX idx_vendor_status (status),
|
||||||
|
INDEX idx_metrics_last_calculated (last_calculated_at),
|
||||||
|
INDEX idx_vendor_metrics_orders (total_orders, total_late_orders)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- New table for category metrics
|
-- New table for category metrics
|
||||||
@@ -130,14 +135,16 @@ CREATE TABLE IF NOT EXISTS category_metrics (
|
|||||||
-- Financial metrics
|
-- Financial metrics
|
||||||
total_value DECIMAL(10,3) DEFAULT 0,
|
total_value DECIMAL(10,3) DEFAULT 0,
|
||||||
avg_margin DECIMAL(5,2),
|
avg_margin DECIMAL(5,2),
|
||||||
turnover_rate DECIMAL(10,3),
|
turnover_rate DECIMAL(12,3),
|
||||||
growth_rate DECIMAL(5,2),
|
growth_rate DECIMAL(5,2),
|
||||||
-- Status
|
-- Status
|
||||||
status VARCHAR(20) DEFAULT 'active',
|
status VARCHAR(20) DEFAULT 'active',
|
||||||
PRIMARY KEY (category_id),
|
PRIMARY KEY (category_id),
|
||||||
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
|
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
|
||||||
INDEX idx_category_status (status),
|
INDEX idx_category_status (status),
|
||||||
INDEX idx_category_growth (growth_rate)
|
INDEX idx_category_growth (growth_rate),
|
||||||
|
INDEX idx_metrics_last_calculated (last_calculated_at),
|
||||||
|
INDEX idx_category_metrics_products (product_count, active_products)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- New table for vendor time-based metrics
|
-- New table for vendor time-based metrics
|
||||||
@@ -170,7 +177,7 @@ CREATE TABLE IF NOT EXISTS category_time_metrics (
|
|||||||
total_value DECIMAL(10,3) DEFAULT 0,
|
total_value DECIMAL(10,3) DEFAULT 0,
|
||||||
total_revenue DECIMAL(10,3) DEFAULT 0,
|
total_revenue DECIMAL(10,3) DEFAULT 0,
|
||||||
avg_margin DECIMAL(5,2),
|
avg_margin DECIMAL(5,2),
|
||||||
turnover_rate DECIMAL(10,3),
|
turnover_rate DECIMAL(12,3),
|
||||||
PRIMARY KEY (category_id, year, month),
|
PRIMARY KEY (category_id, year, month),
|
||||||
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
|
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
|
||||||
INDEX idx_category_date (year, month)
|
INDEX idx_category_date (year, month)
|
||||||
|
|||||||
@@ -3,6 +3,9 @@ const path = require('path');
|
|||||||
require('dotenv').config({ path: path.resolve(__dirname, '..', '.env') });
|
require('dotenv').config({ path: path.resolve(__dirname, '..', '.env') });
|
||||||
const fs = require('fs');
|
const fs = require('fs');
|
||||||
|
|
||||||
|
// Configuration flags
|
||||||
|
const SKIP_PRODUCT_METRICS = 0;
|
||||||
|
|
||||||
// Helper function to format elapsed time
|
// Helper function to format elapsed time
|
||||||
function formatElapsedTime(startTime) {
|
function formatElapsedTime(startTime) {
|
||||||
const elapsed = Date.now() - startTime;
|
const elapsed = Date.now() - startTime;
|
||||||
@@ -107,7 +110,27 @@ const dbConfig = {
|
|||||||
database: process.env.DB_NAME,
|
database: process.env.DB_NAME,
|
||||||
waitForConnections: true,
|
waitForConnections: true,
|
||||||
connectionLimit: 10,
|
connectionLimit: 10,
|
||||||
queueLimit: 0
|
queueLimit: 0,
|
||||||
|
// Add performance optimizations
|
||||||
|
namedPlaceholders: true,
|
||||||
|
maxPreparedStatements: 256,
|
||||||
|
enableKeepAlive: true,
|
||||||
|
keepAliveInitialDelay: 0,
|
||||||
|
// Add memory optimizations
|
||||||
|
flags: [
|
||||||
|
'FOUND_ROWS',
|
||||||
|
'LONG_PASSWORD',
|
||||||
|
'PROTOCOL_41',
|
||||||
|
'TRANSACTIONS',
|
||||||
|
'SECURE_CONNECTION',
|
||||||
|
'MULTI_RESULTS',
|
||||||
|
'PS_MULTI_RESULTS',
|
||||||
|
'PLUGIN_AUTH',
|
||||||
|
'CONNECT_ATTRS',
|
||||||
|
'PLUGIN_AUTH_LENENC_CLIENT_DATA',
|
||||||
|
'SESSION_TRACK',
|
||||||
|
'MULTI_STATEMENTS'
|
||||||
|
]
|
||||||
};
|
};
|
||||||
|
|
||||||
// Add cancel handler
|
// Add cancel handler
|
||||||
@@ -200,7 +223,10 @@ async function calculateFinancialMetrics(connection, startTime, totalProducts) {
|
|||||||
p.cost_price * p.stock_quantity as inventory_value,
|
p.cost_price * p.stock_quantity as inventory_value,
|
||||||
SUM(o.quantity * o.price) as total_revenue,
|
SUM(o.quantity * o.price) as total_revenue,
|
||||||
SUM(o.quantity * p.cost_price) as cost_of_goods_sold,
|
SUM(o.quantity * p.cost_price) as cost_of_goods_sold,
|
||||||
SUM(o.quantity * (o.price - p.cost_price)) as gross_profit
|
SUM(o.quantity * (o.price - p.cost_price)) as gross_profit,
|
||||||
|
MIN(o.date) as first_sale_date,
|
||||||
|
MAX(o.date) as last_sale_date,
|
||||||
|
DATEDIFF(MAX(o.date), MIN(o.date)) + 1 as calculation_period_days
|
||||||
FROM products p
|
FROM products p
|
||||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||||
WHERE o.canceled = false
|
WHERE o.canceled = false
|
||||||
@@ -213,8 +239,8 @@ async function calculateFinancialMetrics(connection, startTime, totalProducts) {
|
|||||||
pm.cost_of_goods_sold = COALESCE(fin.cost_of_goods_sold, 0),
|
pm.cost_of_goods_sold = COALESCE(fin.cost_of_goods_sold, 0),
|
||||||
pm.gross_profit = COALESCE(fin.gross_profit, 0),
|
pm.gross_profit = COALESCE(fin.gross_profit, 0),
|
||||||
pm.gmroi = CASE
|
pm.gmroi = CASE
|
||||||
WHEN COALESCE(fin.inventory_value, 0) > 0
|
WHEN COALESCE(fin.inventory_value, 0) > 0 AND fin.calculation_period_days > 0 THEN
|
||||||
THEN (COALESCE(fin.gross_profit, 0) / COALESCE(fin.inventory_value, 0)) * 100
|
(COALESCE(fin.gross_profit, 0) * (365.0 / fin.calculation_period_days)) / COALESCE(fin.inventory_value, 0)
|
||||||
ELSE 0
|
ELSE 0
|
||||||
END
|
END
|
||||||
`);
|
`);
|
||||||
@@ -228,8 +254,8 @@ async function calculateFinancialMetrics(connection, startTime, totalProducts) {
|
|||||||
YEAR(o.date) as year,
|
YEAR(o.date) as year,
|
||||||
MONTH(o.date) as month,
|
MONTH(o.date) as month,
|
||||||
p.cost_price * p.stock_quantity as inventory_value,
|
p.cost_price * p.stock_quantity as inventory_value,
|
||||||
SUM((o.price - p.cost_price) * o.quantity) /
|
SUM(o.quantity * (o.price - p.cost_price)) as gross_profit,
|
||||||
NULLIF(p.cost_price * p.stock_quantity, 0) * 100 as gmroi
|
COUNT(DISTINCT DATE(o.date)) as days_in_period
|
||||||
FROM products p
|
FROM products p
|
||||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||||
WHERE o.canceled = false
|
WHERE o.canceled = false
|
||||||
@@ -239,7 +265,11 @@ async function calculateFinancialMetrics(connection, startTime, totalProducts) {
|
|||||||
AND pta.month = fin.month
|
AND pta.month = fin.month
|
||||||
SET
|
SET
|
||||||
pta.inventory_value = COALESCE(fin.inventory_value, 0),
|
pta.inventory_value = COALESCE(fin.inventory_value, 0),
|
||||||
pta.gmroi = COALESCE(fin.gmroi, 0)
|
pta.gmroi = CASE
|
||||||
|
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)
|
||||||
|
ELSE 0
|
||||||
|
END
|
||||||
`);
|
`);
|
||||||
}
|
}
|
||||||
|
|
||||||
@@ -256,6 +286,15 @@ async function calculateVendorMetrics(connection, startTime, totalProducts) {
|
|||||||
percentage: '70'
|
percentage: '70'
|
||||||
});
|
});
|
||||||
|
|
||||||
|
// First, ensure all vendors exist in vendor_details
|
||||||
|
await connection.query(`
|
||||||
|
INSERT IGNORE INTO vendor_details (vendor, status)
|
||||||
|
SELECT DISTINCT vendor, 'active' as status
|
||||||
|
FROM products
|
||||||
|
WHERE vendor IS NOT NULL
|
||||||
|
AND vendor NOT IN (SELECT vendor FROM vendor_details)
|
||||||
|
`);
|
||||||
|
|
||||||
// Calculate vendor performance metrics
|
// Calculate vendor performance metrics
|
||||||
await connection.query(`
|
await connection.query(`
|
||||||
INSERT INTO vendor_metrics (
|
INSERT INTO vendor_metrics (
|
||||||
@@ -273,30 +312,59 @@ async function calculateVendorMetrics(connection, startTime, totalProducts) {
|
|||||||
avg_margin_percent,
|
avg_margin_percent,
|
||||||
status
|
status
|
||||||
)
|
)
|
||||||
|
WITH vendor_orders AS (
|
||||||
SELECT
|
SELECT
|
||||||
vd.vendor,
|
po.vendor,
|
||||||
-- Lead time metrics
|
|
||||||
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
|
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
|
||||||
-- On-time delivery rate
|
COUNT(*) as total_orders,
|
||||||
(COUNT(CASE WHEN po.received_date <= po.expected_date THEN 1 END) / COUNT(*)) * 100 as on_time_delivery_rate,
|
COUNT(CASE WHEN po.received_date > po.expected_date THEN 1 END) as total_late_orders,
|
||||||
-- Order fill rate
|
|
||||||
(SUM(po.received) / SUM(po.ordered)) * 100 as order_fill_rate,
|
|
||||||
COUNT(DISTINCT po.po_id) as total_orders,
|
|
||||||
COUNT(DISTINCT CASE WHEN po.received_date > po.expected_date THEN po.po_id END) as total_late_orders,
|
|
||||||
SUM(po.cost_price * po.ordered) as total_purchase_value,
|
SUM(po.cost_price * po.ordered) as total_purchase_value,
|
||||||
AVG(po.cost_price * po.ordered) as avg_order_value,
|
AVG(po.cost_price * po.ordered) as avg_order_value,
|
||||||
-- Product counts
|
CASE
|
||||||
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
|
WHEN COUNT(*) > 0 THEN
|
||||||
|
(COUNT(CASE WHEN po.received = po.ordered THEN 1 END) * 100.0) / COUNT(*)
|
||||||
|
ELSE 0
|
||||||
|
END as order_fill_rate
|
||||||
|
FROM purchase_orders po
|
||||||
|
WHERE po.status = 'closed'
|
||||||
|
GROUP BY po.vendor
|
||||||
|
),
|
||||||
|
vendor_products AS (
|
||||||
|
SELECT
|
||||||
|
p.vendor,
|
||||||
COUNT(DISTINCT p.product_id) as total_products,
|
COUNT(DISTINCT p.product_id) as total_products,
|
||||||
-- Financial metrics
|
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
|
||||||
SUM(o.price * o.quantity) as total_revenue,
|
SUM(o.price * o.quantity) as total_revenue,
|
||||||
AVG(((o.price - p.cost_price) / o.price) * 100) as avg_margin_percent,
|
CASE
|
||||||
|
WHEN SUM(o.price * o.quantity) > 0 THEN
|
||||||
|
(SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
|
||||||
|
ELSE 0
|
||||||
|
END as avg_margin_percent
|
||||||
|
FROM products p
|
||||||
|
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
|
||||||
|
GROUP BY p.vendor
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
vd.vendor,
|
||||||
|
COALESCE(vo.avg_lead_time_days, 0) as avg_lead_time_days,
|
||||||
|
CASE
|
||||||
|
WHEN COALESCE(vo.total_orders, 0) > 0 THEN
|
||||||
|
((COALESCE(vo.total_orders, 0) - COALESCE(vo.total_late_orders, 0)) * 100.0) / COALESCE(vo.total_orders, 1)
|
||||||
|
ELSE 0
|
||||||
|
END as on_time_delivery_rate,
|
||||||
|
COALESCE(vo.order_fill_rate, 0) as order_fill_rate,
|
||||||
|
COALESCE(vo.total_orders, 0) as total_orders,
|
||||||
|
COALESCE(vo.total_late_orders, 0) as total_late_orders,
|
||||||
|
COALESCE(vo.total_purchase_value, 0) as total_purchase_value,
|
||||||
|
COALESCE(vo.avg_order_value, 0) as avg_order_value,
|
||||||
|
COALESCE(vp.active_products, 0) as active_products,
|
||||||
|
COALESCE(vp.total_products, 0) as total_products,
|
||||||
|
COALESCE(vp.total_revenue, 0) as total_revenue,
|
||||||
|
COALESCE(vp.avg_margin_percent, 0) as avg_margin_percent,
|
||||||
vd.status
|
vd.status
|
||||||
FROM vendor_details vd
|
FROM vendor_details vd
|
||||||
LEFT JOIN products p ON vd.vendor = p.vendor
|
LEFT JOIN vendor_orders vo ON vd.vendor = vo.vendor
|
||||||
LEFT JOIN purchase_orders po ON p.product_id = po.product_id
|
LEFT JOIN vendor_products vp ON vd.vendor = vp.vendor
|
||||||
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
|
|
||||||
GROUP BY vd.vendor, vd.status
|
|
||||||
ON DUPLICATE KEY UPDATE
|
ON DUPLICATE KEY UPDATE
|
||||||
avg_lead_time_days = VALUES(avg_lead_time_days),
|
avg_lead_time_days = VALUES(avg_lead_time_days),
|
||||||
on_time_delivery_rate = VALUES(on_time_delivery_rate),
|
on_time_delivery_rate = VALUES(on_time_delivery_rate),
|
||||||
@@ -326,6 +394,7 @@ async function calculateVendorMetrics(connection, startTime, totalProducts) {
|
|||||||
total_revenue,
|
total_revenue,
|
||||||
avg_margin_percent
|
avg_margin_percent
|
||||||
)
|
)
|
||||||
|
WITH vendor_time_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
vd.vendor,
|
vd.vendor,
|
||||||
YEAR(po.date) as year,
|
YEAR(po.date) as year,
|
||||||
@@ -335,13 +404,29 @@ async function calculateVendorMetrics(connection, startTime, totalProducts) {
|
|||||||
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
|
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
|
||||||
SUM(po.cost_price * po.ordered) as total_purchase_value,
|
SUM(po.cost_price * po.ordered) as total_purchase_value,
|
||||||
SUM(o.price * o.quantity) as total_revenue,
|
SUM(o.price * o.quantity) as total_revenue,
|
||||||
AVG(((o.price - p.cost_price) / o.price) * 100) as avg_margin_percent
|
CASE
|
||||||
|
WHEN SUM(o.price * o.quantity) > 0 THEN
|
||||||
|
(SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
|
||||||
|
ELSE 0
|
||||||
|
END as avg_margin_percent
|
||||||
FROM vendor_details vd
|
FROM vendor_details vd
|
||||||
LEFT JOIN products p ON vd.vendor = p.vendor
|
LEFT JOIN products p ON vd.vendor = p.vendor
|
||||||
LEFT JOIN purchase_orders po ON p.product_id = po.product_id
|
LEFT JOIN purchase_orders po ON p.product_id = po.product_id
|
||||||
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
|
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
|
||||||
WHERE po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
WHERE po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
||||||
GROUP BY vd.vendor, YEAR(po.date), MONTH(po.date)
|
GROUP BY vd.vendor, YEAR(po.date), MONTH(po.date)
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
vendor,
|
||||||
|
year,
|
||||||
|
month,
|
||||||
|
COALESCE(total_orders, 0) as total_orders,
|
||||||
|
COALESCE(late_orders, 0) as late_orders,
|
||||||
|
COALESCE(avg_lead_time_days, 0) as avg_lead_time_days,
|
||||||
|
COALESCE(total_purchase_value, 0) as total_purchase_value,
|
||||||
|
COALESCE(total_revenue, 0) as total_revenue,
|
||||||
|
COALESCE(avg_margin_percent, 0) as avg_margin_percent
|
||||||
|
FROM vendor_time_data
|
||||||
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),
|
||||||
@@ -376,28 +461,74 @@ async function calculateCategoryMetrics(connection, startTime, totalProducts) {
|
|||||||
growth_rate,
|
growth_rate,
|
||||||
status
|
status
|
||||||
)
|
)
|
||||||
|
WITH category_sales AS (
|
||||||
SELECT
|
SELECT
|
||||||
c.id as category_id,
|
c.id as category_id,
|
||||||
COUNT(DISTINCT p.product_id) as product_count,
|
COUNT(DISTINCT p.product_id) as product_count,
|
||||||
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
|
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
|
||||||
SUM(p.stock_quantity * p.cost_price) as total_value,
|
SUM(p.stock_quantity * p.cost_price) as total_value,
|
||||||
AVG(((p.price - p.cost_price) / p.price) * 100) as avg_margin,
|
CASE
|
||||||
-- Turnover rate calculation
|
WHEN SUM(o.price * o.quantity) > 0
|
||||||
SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0) as turnover_rate,
|
THEN (SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
|
||||||
-- Growth rate calculation (comparing current month to previous month)
|
ELSE 0
|
||||||
((
|
END as avg_margin,
|
||||||
SUM(CASE WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) THEN o.quantity ELSE 0 END) -
|
CASE
|
||||||
SUM(CASE WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 2 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) THEN o.quantity ELSE 0 END)
|
WHEN AVG(GREATEST(p.stock_quantity, 0)) >= 0.01
|
||||||
) / NULLIF(
|
THEN LEAST(
|
||||||
SUM(CASE WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 2 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) THEN o.quantity ELSE 0 END),
|
SUM(CASE
|
||||||
0
|
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 1 YEAR)
|
||||||
) * 100) as growth_rate,
|
THEN COALESCE(o.quantity, 0)
|
||||||
|
ELSE 0
|
||||||
|
END) /
|
||||||
|
GREATEST(
|
||||||
|
AVG(GREATEST(p.stock_quantity, 0)),
|
||||||
|
1.0
|
||||||
|
),
|
||||||
|
999.99
|
||||||
|
)
|
||||||
|
ELSE 0
|
||||||
|
END as turnover_rate,
|
||||||
|
-- Current period (last 3 months)
|
||||||
|
SUM(CASE
|
||||||
|
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 3 MONTH)
|
||||||
|
THEN COALESCE(o.quantity * o.price, 0)
|
||||||
|
ELSE 0
|
||||||
|
END) as current_period_sales,
|
||||||
|
-- Previous year same period
|
||||||
|
SUM(CASE
|
||||||
|
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
|
||||||
|
THEN COALESCE(o.quantity * o.price, 0)
|
||||||
|
ELSE 0
|
||||||
|
END) as previous_year_period_sales,
|
||||||
c.status
|
c.status
|
||||||
FROM categories c
|
FROM categories c
|
||||||
LEFT JOIN product_categories pc ON c.id = pc.category_id
|
LEFT JOIN product_categories pc ON c.id = pc.category_id
|
||||||
LEFT JOIN products p ON pc.product_id = p.product_id
|
LEFT JOIN products p ON pc.product_id = p.product_id
|
||||||
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
|
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
|
||||||
GROUP BY c.id, c.status
|
GROUP BY c.id, c.status
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
category_id,
|
||||||
|
product_count,
|
||||||
|
active_products,
|
||||||
|
total_value,
|
||||||
|
COALESCE(avg_margin, 0) as avg_margin,
|
||||||
|
COALESCE(turnover_rate, 0) as turnover_rate,
|
||||||
|
-- Enhanced YoY growth rate calculation
|
||||||
|
CASE
|
||||||
|
WHEN previous_year_period_sales = 0 AND current_period_sales > 0 THEN 100.0
|
||||||
|
WHEN previous_year_period_sales = 0 THEN 0.0
|
||||||
|
ELSE LEAST(
|
||||||
|
GREATEST(
|
||||||
|
((current_period_sales - previous_year_period_sales) /
|
||||||
|
NULLIF(previous_year_period_sales, 0)) * 100.0,
|
||||||
|
-100.0
|
||||||
|
),
|
||||||
|
999.99
|
||||||
|
)
|
||||||
|
END as growth_rate,
|
||||||
|
status
|
||||||
|
FROM category_sales
|
||||||
ON DUPLICATE KEY UPDATE
|
ON DUPLICATE KEY UPDATE
|
||||||
product_count = VALUES(product_count),
|
product_count = VALUES(product_count),
|
||||||
active_products = VALUES(active_products),
|
active_products = VALUES(active_products),
|
||||||
@@ -430,8 +561,16 @@ async function calculateCategoryMetrics(connection, startTime, totalProducts) {
|
|||||||
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
|
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id 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.price * o.quantity) as total_revenue,
|
SUM(o.price * o.quantity) as total_revenue,
|
||||||
AVG(((p.price - p.cost_price) / p.price) * 100) as avg_margin,
|
CASE
|
||||||
SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0) as turnover_rate
|
WHEN SUM(o.price * o.quantity) > 0
|
||||||
|
THEN (SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
|
||||||
|
ELSE 0
|
||||||
|
END as avg_margin,
|
||||||
|
CASE
|
||||||
|
WHEN AVG(p.stock_quantity) > 0
|
||||||
|
THEN SUM(o.quantity) / AVG(p.stock_quantity)
|
||||||
|
ELSE 0
|
||||||
|
END as turnover_rate
|
||||||
FROM categories c
|
FROM categories c
|
||||||
LEFT JOIN product_categories pc ON c.id = pc.category_id
|
LEFT JOIN product_categories pc ON c.id = pc.category_id
|
||||||
LEFT JOIN products p ON pc.product_id = p.product_id
|
LEFT JOIN products p ON pc.product_id = p.product_id
|
||||||
@@ -493,8 +632,10 @@ async function calculateTurnoverMetrics(connection, startTime, totalProducts) {
|
|||||||
)
|
)
|
||||||
)
|
)
|
||||||
) as calculation_period_days,
|
) as calculation_period_days,
|
||||||
SUM(o.quantity) as total_quantity_sold,
|
-- Calculate average daily sales over the calculation period
|
||||||
AVG(p.stock_quantity) as avg_stock_level
|
SUM(o.quantity) / GREATEST(DATEDIFF(CURDATE(), DATE_SUB(CURDATE(), INTERVAL 30 DAY)), 1) as avg_daily_sales,
|
||||||
|
-- Calculate average stock level, excluding zero stock periods
|
||||||
|
AVG(CASE WHEN p.stock_quantity > 0 THEN p.stock_quantity ELSE NULL END) as avg_stock_level
|
||||||
FROM products p
|
FROM products p
|
||||||
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
|
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
|
||||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||||
@@ -506,8 +647,12 @@ async function calculateTurnoverMetrics(connection, startTime, totalProducts) {
|
|||||||
JOIN product_turnover pt ON pm.product_id = pt.product_id
|
JOIN product_turnover pt ON pm.product_id = pt.product_id
|
||||||
SET
|
SET
|
||||||
pm.turnover_rate = CASE
|
pm.turnover_rate = CASE
|
||||||
WHEN pt.avg_stock_level > 0
|
WHEN pt.avg_stock_level > 0 AND pt.avg_daily_sales > 0 THEN
|
||||||
THEN (pt.total_quantity_sold / pt.avg_stock_level) * (30.0 / pt.calculation_period_days)
|
-- Calculate annualized turnover rate
|
||||||
|
LEAST(
|
||||||
|
(pt.avg_daily_sales * 365) / GREATEST(pt.avg_stock_level, 1),
|
||||||
|
999999.999
|
||||||
|
)
|
||||||
ELSE 0
|
ELSE 0
|
||||||
END,
|
END,
|
||||||
pm.last_calculated_at = NOW()
|
pm.last_calculated_at = NOW()
|
||||||
@@ -534,58 +679,62 @@ async function calculateLeadTimeMetrics(connection, startTime, totalProducts) {
|
|||||||
p.vendor,
|
p.vendor,
|
||||||
pc.category_id,
|
pc.category_id,
|
||||||
AVG(DATEDIFF(po.received_date, po.date)) as current_lead_time,
|
AVG(DATEDIFF(po.received_date, po.date)) as current_lead_time,
|
||||||
COALESCE(
|
(
|
||||||
(SELECT target_days
|
SELECT target_days
|
||||||
FROM lead_time_thresholds lt
|
FROM lead_time_thresholds lt
|
||||||
WHERE lt.category_id = pc.category_id
|
WHERE lt.category_id = pc.category_id
|
||||||
AND lt.vendor = p.vendor
|
AND lt.vendor = p.vendor
|
||||||
LIMIT 1),
|
LIMIT 1
|
||||||
COALESCE(
|
) as target_lead_time_cat_vendor,
|
||||||
(SELECT target_days
|
(
|
||||||
|
SELECT target_days
|
||||||
FROM lead_time_thresholds lt
|
FROM lead_time_thresholds lt
|
||||||
WHERE lt.category_id = pc.category_id
|
WHERE lt.category_id = pc.category_id
|
||||||
AND lt.vendor IS NULL
|
AND lt.vendor IS NULL
|
||||||
LIMIT 1),
|
LIMIT 1
|
||||||
COALESCE(
|
) as target_lead_time_cat,
|
||||||
(SELECT target_days
|
(
|
||||||
|
SELECT target_days
|
||||||
FROM lead_time_thresholds lt
|
FROM lead_time_thresholds lt
|
||||||
WHERE lt.category_id IS NULL
|
WHERE lt.category_id IS NULL
|
||||||
AND lt.vendor = p.vendor
|
AND lt.vendor = p.vendor
|
||||||
LIMIT 1),
|
LIMIT 1
|
||||||
(SELECT target_days
|
) as target_lead_time_vendor,
|
||||||
|
(
|
||||||
|
SELECT target_days
|
||||||
FROM lead_time_thresholds
|
FROM lead_time_thresholds
|
||||||
WHERE category_id IS NULL
|
WHERE category_id IS NULL
|
||||||
AND vendor IS NULL
|
AND vendor IS NULL
|
||||||
LIMIT 1)
|
LIMIT 1
|
||||||
)
|
) as target_lead_time_default,
|
||||||
)
|
(
|
||||||
) as target_lead_time,
|
SELECT warning_days
|
||||||
COALESCE(
|
|
||||||
(SELECT warning_days
|
|
||||||
FROM lead_time_thresholds lt
|
FROM lead_time_thresholds lt
|
||||||
WHERE lt.category_id = pc.category_id
|
WHERE lt.category_id = pc.category_id
|
||||||
AND lt.vendor = p.vendor
|
AND lt.vendor = p.vendor
|
||||||
LIMIT 1),
|
LIMIT 1
|
||||||
COALESCE(
|
) as warning_lead_time_cat_vendor,
|
||||||
(SELECT warning_days
|
(
|
||||||
|
SELECT warning_days
|
||||||
FROM lead_time_thresholds lt
|
FROM lead_time_thresholds lt
|
||||||
WHERE lt.category_id = pc.category_id
|
WHERE lt.category_id = pc.category_id
|
||||||
AND lt.vendor IS NULL
|
AND lt.vendor IS NULL
|
||||||
LIMIT 1),
|
LIMIT 1
|
||||||
COALESCE(
|
) as warning_lead_time_cat,
|
||||||
(SELECT warning_days
|
(
|
||||||
|
SELECT warning_days
|
||||||
FROM lead_time_thresholds lt
|
FROM lead_time_thresholds lt
|
||||||
WHERE lt.category_id IS NULL
|
WHERE lt.category_id IS NULL
|
||||||
AND lt.vendor = p.vendor
|
AND lt.vendor = p.vendor
|
||||||
LIMIT 1),
|
LIMIT 1
|
||||||
(SELECT warning_days
|
) as warning_lead_time_vendor,
|
||||||
|
(
|
||||||
|
SELECT warning_days
|
||||||
FROM lead_time_thresholds
|
FROM lead_time_thresholds
|
||||||
WHERE category_id IS NULL
|
WHERE category_id IS NULL
|
||||||
AND vendor IS NULL
|
AND vendor IS NULL
|
||||||
LIMIT 1)
|
LIMIT 1
|
||||||
)
|
) as warning_lead_time_default
|
||||||
)
|
|
||||||
) as warning_lead_time
|
|
||||||
FROM products p
|
FROM products p
|
||||||
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
|
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
|
||||||
LEFT JOIN purchase_orders po ON p.product_id = po.product_id
|
LEFT JOIN purchase_orders po ON p.product_id = po.product_id
|
||||||
@@ -593,9 +742,29 @@ async function calculateLeadTimeMetrics(connection, startTime, totalProducts) {
|
|||||||
AND po.received_date IS NOT NULL
|
AND po.received_date IS NOT NULL
|
||||||
AND po.date >= DATE_SUB(CURDATE(), INTERVAL 90 DAY)
|
AND po.date >= DATE_SUB(CURDATE(), INTERVAL 90 DAY)
|
||||||
GROUP BY p.product_id, p.vendor, pc.category_id
|
GROUP BY p.product_id, p.vendor, pc.category_id
|
||||||
|
),
|
||||||
|
lead_time_final AS (
|
||||||
|
SELECT
|
||||||
|
product_id,
|
||||||
|
current_lead_time,
|
||||||
|
COALESCE(
|
||||||
|
target_lead_time_cat_vendor,
|
||||||
|
target_lead_time_cat,
|
||||||
|
target_lead_time_vendor,
|
||||||
|
target_lead_time_default,
|
||||||
|
14
|
||||||
|
) as target_lead_time,
|
||||||
|
COALESCE(
|
||||||
|
warning_lead_time_cat_vendor,
|
||||||
|
warning_lead_time_cat,
|
||||||
|
warning_lead_time_vendor,
|
||||||
|
warning_lead_time_default,
|
||||||
|
21
|
||||||
|
) as warning_lead_time
|
||||||
|
FROM lead_time_stats
|
||||||
)
|
)
|
||||||
UPDATE product_metrics pm
|
UPDATE product_metrics pm
|
||||||
JOIN lead_time_stats lt ON pm.product_id = lt.product_id
|
JOIN lead_time_final lt ON pm.product_id = lt.product_id
|
||||||
SET
|
SET
|
||||||
pm.current_lead_time = lt.current_lead_time,
|
pm.current_lead_time = lt.current_lead_time,
|
||||||
pm.target_lead_time = lt.target_lead_time,
|
pm.target_lead_time = lt.target_lead_time,
|
||||||
@@ -689,6 +858,122 @@ async function calculateCategorySalesMetrics(connection, startTime, totalProduct
|
|||||||
`);
|
`);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
// Add new function for safety stock calculation
|
||||||
|
async function calculateSafetyStock(connection, startTime, totalProducts) {
|
||||||
|
outputProgress({
|
||||||
|
status: 'running',
|
||||||
|
operation: 'Calculating safety stock levels',
|
||||||
|
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(`
|
||||||
|
WITH daily_sales AS (
|
||||||
|
SELECT
|
||||||
|
o.product_id,
|
||||||
|
DATE(o.date) as sale_date,
|
||||||
|
SUM(o.quantity) as daily_quantity
|
||||||
|
FROM orders o
|
||||||
|
WHERE o.canceled = false
|
||||||
|
AND o.date >= DATE_SUB(CURDATE(), INTERVAL 90 DAY)
|
||||||
|
GROUP BY o.product_id, DATE(o.date)
|
||||||
|
),
|
||||||
|
sales_stats AS (
|
||||||
|
SELECT
|
||||||
|
ds.product_id,
|
||||||
|
AVG(ds.daily_quantity) as avg_daily_sales,
|
||||||
|
STDDEV_SAMP(ds.daily_quantity) as daily_sales_stddev,
|
||||||
|
COUNT(DISTINCT ds.sale_date) as days_with_sales
|
||||||
|
FROM daily_sales ds
|
||||||
|
GROUP BY ds.product_id
|
||||||
|
),
|
||||||
|
product_config AS (
|
||||||
|
SELECT
|
||||||
|
p.product_id,
|
||||||
|
p.vendor,
|
||||||
|
pc.category_id,
|
||||||
|
COALESCE(
|
||||||
|
(SELECT service_level
|
||||||
|
FROM safety_stock_config sc
|
||||||
|
WHERE sc.category_id = pc.category_id
|
||||||
|
AND sc.vendor = p.vendor
|
||||||
|
LIMIT 1),
|
||||||
|
COALESCE(
|
||||||
|
(SELECT service_level
|
||||||
|
FROM safety_stock_config sc
|
||||||
|
WHERE sc.category_id = pc.category_id
|
||||||
|
AND sc.vendor IS NULL
|
||||||
|
LIMIT 1),
|
||||||
|
COALESCE(
|
||||||
|
(SELECT service_level
|
||||||
|
FROM safety_stock_config sc
|
||||||
|
WHERE sc.category_id IS NULL
|
||||||
|
AND sc.vendor = p.vendor
|
||||||
|
LIMIT 1),
|
||||||
|
(SELECT service_level
|
||||||
|
FROM safety_stock_config
|
||||||
|
WHERE category_id IS NULL
|
||||||
|
AND vendor IS NULL
|
||||||
|
LIMIT 1)
|
||||||
|
)
|
||||||
|
)
|
||||||
|
) as service_level,
|
||||||
|
COALESCE(
|
||||||
|
(SELECT coverage_days
|
||||||
|
FROM safety_stock_config sc
|
||||||
|
WHERE sc.category_id = pc.category_id
|
||||||
|
AND sc.vendor = p.vendor
|
||||||
|
LIMIT 1),
|
||||||
|
COALESCE(
|
||||||
|
(SELECT coverage_days
|
||||||
|
FROM safety_stock_config sc
|
||||||
|
WHERE sc.category_id = pc.category_id
|
||||||
|
AND sc.vendor IS NULL
|
||||||
|
LIMIT 1),
|
||||||
|
COALESCE(
|
||||||
|
(SELECT coverage_days
|
||||||
|
FROM safety_stock_config sc
|
||||||
|
WHERE sc.category_id IS NULL
|
||||||
|
AND sc.vendor = p.vendor
|
||||||
|
LIMIT 1),
|
||||||
|
(SELECT coverage_days
|
||||||
|
FROM safety_stock_config
|
||||||
|
WHERE category_id IS NULL
|
||||||
|
AND vendor IS NULL
|
||||||
|
LIMIT 1)
|
||||||
|
)
|
||||||
|
)
|
||||||
|
) as coverage_days
|
||||||
|
FROM products p
|
||||||
|
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
|
||||||
|
)
|
||||||
|
UPDATE product_metrics pm
|
||||||
|
JOIN sales_stats ss ON pm.product_id = ss.product_id
|
||||||
|
JOIN product_config pc ON pm.product_id = pc.product_id
|
||||||
|
SET pm.safety_stock = GREATEST(1,
|
||||||
|
CEIL(
|
||||||
|
ss.avg_daily_sales * pc.coverage_days *
|
||||||
|
(1 + (
|
||||||
|
COALESCE(ss.daily_sales_stddev, 0) *
|
||||||
|
CASE
|
||||||
|
WHEN pc.service_level >= 99.9 THEN 3.1
|
||||||
|
WHEN pc.service_level >= 99 THEN 2.33
|
||||||
|
WHEN pc.service_level >= 95 THEN 1.65
|
||||||
|
WHEN pc.service_level >= 90 THEN 1.29
|
||||||
|
ELSE 1
|
||||||
|
END
|
||||||
|
))
|
||||||
|
)
|
||||||
|
),
|
||||||
|
pm.last_calculated_at = NOW()
|
||||||
|
WHERE ss.days_with_sales > 0
|
||||||
|
`);
|
||||||
|
}
|
||||||
|
|
||||||
// Update the main calculation function to include the new metrics
|
// Update the main calculation function to include the new metrics
|
||||||
async function calculateMetrics() {
|
async function calculateMetrics() {
|
||||||
let pool;
|
let pool;
|
||||||
@@ -721,6 +1006,7 @@ async function calculateMetrics() {
|
|||||||
});
|
});
|
||||||
totalProducts = countResult[0].total;
|
totalProducts = countResult[0].total;
|
||||||
|
|
||||||
|
if (!SKIP_PRODUCT_METRICS) {
|
||||||
// Initial progress with percentage
|
// Initial progress with percentage
|
||||||
outputProgress({
|
outputProgress({
|
||||||
status: 'running',
|
status: 'running',
|
||||||
@@ -733,8 +1019,8 @@ async function calculateMetrics() {
|
|||||||
percentage: '0'
|
percentage: '0'
|
||||||
});
|
});
|
||||||
|
|
||||||
// Process in batches of 100
|
// Process in batches of 250
|
||||||
const batchSize = 100;
|
const batchSize = 250;
|
||||||
for (let offset = 0; offset < totalProducts; offset += batchSize) {
|
for (let offset = 0; offset < totalProducts; offset += batchSize) {
|
||||||
if (isCancelled) {
|
if (isCancelled) {
|
||||||
throw new Error('Operation cancelled');
|
throw new Error('Operation cancelled');
|
||||||
@@ -1037,6 +1323,16 @@ async function calculateMetrics() {
|
|||||||
const weekly_sales_avg = metrics.rolling_weekly_avg || 0;
|
const weekly_sales_avg = metrics.rolling_weekly_avg || 0;
|
||||||
const monthly_sales_avg = metrics.total_quantity_sold ? metrics.total_quantity_sold / 30 : 0;
|
const monthly_sales_avg = metrics.total_quantity_sold ? metrics.total_quantity_sold / 30 : 0;
|
||||||
|
|
||||||
|
// Calculate days of inventory with safety factor and lead times
|
||||||
|
const days_of_inventory = daily_sales_avg > 0 ?
|
||||||
|
Math.ceil(
|
||||||
|
(stock.stock_quantity / daily_sales_avg) +
|
||||||
|
(purchases.avg_lead_time_days || config.reorder_days) *
|
||||||
|
(1 + (config.service_level / 100))
|
||||||
|
) : null;
|
||||||
|
|
||||||
|
const weeks_of_inventory = days_of_inventory ? Math.ceil(days_of_inventory / 7) : null;
|
||||||
|
|
||||||
// Calculate margin percent with proper handling of zero revenue
|
// Calculate margin percent with proper handling of zero revenue
|
||||||
const margin_percent = metrics.total_revenue > 0 ?
|
const margin_percent = metrics.total_revenue > 0 ?
|
||||||
((metrics.total_revenue - metrics.total_cost) / metrics.total_revenue) * 100 :
|
((metrics.total_revenue - metrics.total_cost) / metrics.total_revenue) * 100 :
|
||||||
@@ -1114,11 +1410,6 @@ async function calculateMetrics() {
|
|||||||
return 'Healthy';
|
return '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 * (config.safety_stock_days || 14) * ((config.service_level || 95.0) / 100))) :
|
|
||||||
null;
|
|
||||||
|
|
||||||
// Calculate reorder quantity and overstocked amount
|
// Calculate reorder quantity and overstocked amount
|
||||||
let reorder_qty = 0;
|
let reorder_qty = 0;
|
||||||
let overstocked_amt = 0;
|
let overstocked_amt = 0;
|
||||||
@@ -1128,7 +1419,7 @@ async function calculateMetrics() {
|
|||||||
const ds = daily_sales_avg || 0;
|
const ds = daily_sales_avg || 0;
|
||||||
const lt = purchases.avg_lead_time_days || 14; // Default to 14 days if no lead time data
|
const lt = purchases.avg_lead_time_days || 14; // Default to 14 days if no lead time data
|
||||||
const sc = config.safety_stock_days || 14;
|
const sc = config.safety_stock_days || 14;
|
||||||
const ss = safety_stock || 0;
|
const ss = config.safety_stock_days || 14;
|
||||||
const dq = stock.stock_quantity || 0;
|
const dq = stock.stock_quantity || 0;
|
||||||
const moq = stock.moq || 1;
|
const moq = stock.moq || 1;
|
||||||
|
|
||||||
@@ -1148,7 +1439,7 @@ async function calculateMetrics() {
|
|||||||
const dq = stock.stock_quantity || 0;
|
const dq = stock.stock_quantity || 0;
|
||||||
const lt = purchases.avg_lead_time_days || 14;
|
const lt = purchases.avg_lead_time_days || 14;
|
||||||
const sc = config.safety_stock_days || 14;
|
const sc = config.safety_stock_days || 14;
|
||||||
const ss = safety_stock || 0;
|
const ss = config.safety_stock_days || 14;
|
||||||
|
|
||||||
// Calculate maximum desired stock based on overstock days configuration
|
// Calculate maximum desired stock based on overstock days configuration
|
||||||
const max_desired_stock = (ds * config.overstock_days) + ss;
|
const max_desired_stock = (ds * config.overstock_days) + ss;
|
||||||
@@ -1157,7 +1448,7 @@ async function calculateMetrics() {
|
|||||||
overstocked_amt = Math.max(0, dq - max_desired_stock);
|
overstocked_amt = Math.max(0, dq - max_desired_stock);
|
||||||
}
|
}
|
||||||
|
|
||||||
// Add to batch update
|
// Add to batch update (remove safety_stock from the array since it's calculated separately)
|
||||||
metricsUpdates.push([
|
metricsUpdates.push([
|
||||||
product.product_id,
|
product.product_id,
|
||||||
daily_sales_avg || null,
|
daily_sales_avg || null,
|
||||||
@@ -1167,10 +1458,9 @@ async function calculateMetrics() {
|
|||||||
metrics.number_of_orders || 0,
|
metrics.number_of_orders || 0,
|
||||||
metrics.first_sale_date || null,
|
metrics.first_sale_date || null,
|
||||||
metrics.last_sale_date || null,
|
metrics.last_sale_date || null,
|
||||||
daily_sales_avg > 0 ? stock.stock_quantity / daily_sales_avg : null,
|
days_of_inventory,
|
||||||
weekly_sales_avg > 0 ? stock.stock_quantity / weekly_sales_avg : null,
|
weeks_of_inventory,
|
||||||
daily_sales_avg > 0 ? Math.max(1, Math.ceil(daily_sales_avg * config.reorder_days)) : null,
|
daily_sales_avg > 0 ? Math.max(1, Math.ceil(daily_sales_avg * config.reorder_days)) : null,
|
||||||
safety_stock,
|
|
||||||
margin_percent,
|
margin_percent,
|
||||||
metrics.total_revenue || 0,
|
metrics.total_revenue || 0,
|
||||||
inventory_value || 0,
|
inventory_value || 0,
|
||||||
@@ -1204,7 +1494,6 @@ async function calculateMetrics() {
|
|||||||
days_of_inventory,
|
days_of_inventory,
|
||||||
weeks_of_inventory,
|
weeks_of_inventory,
|
||||||
reorder_point,
|
reorder_point,
|
||||||
safety_stock,
|
|
||||||
avg_margin_percent,
|
avg_margin_percent,
|
||||||
total_revenue,
|
total_revenue,
|
||||||
inventory_value,
|
inventory_value,
|
||||||
@@ -1228,7 +1517,6 @@ async function calculateMetrics() {
|
|||||||
days_of_inventory = VALUES(days_of_inventory),
|
days_of_inventory = VALUES(days_of_inventory),
|
||||||
weeks_of_inventory = VALUES(weeks_of_inventory),
|
weeks_of_inventory = VALUES(weeks_of_inventory),
|
||||||
reorder_point = VALUES(reorder_point),
|
reorder_point = VALUES(reorder_point),
|
||||||
safety_stock = VALUES(safety_stock),
|
|
||||||
avg_margin_percent = VALUES(avg_margin_percent),
|
avg_margin_percent = VALUES(avg_margin_percent),
|
||||||
total_revenue = VALUES(total_revenue),
|
total_revenue = VALUES(total_revenue),
|
||||||
inventory_value = VALUES(inventory_value),
|
inventory_value = VALUES(inventory_value),
|
||||||
@@ -1245,6 +1533,19 @@ async function calculateMetrics() {
|
|||||||
});
|
});
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
} else {
|
||||||
|
console.log('Skipping product metrics calculation...');
|
||||||
|
outputProgress({
|
||||||
|
status: 'running',
|
||||||
|
operation: 'Skipping product 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'
|
||||||
|
});
|
||||||
|
}
|
||||||
|
|
||||||
outputProgress({
|
outputProgress({
|
||||||
status: 'running',
|
status: 'running',
|
||||||
@@ -1398,8 +1699,8 @@ async function calculateMetrics() {
|
|||||||
s.order_count,
|
s.order_count,
|
||||||
COALESCE(p.stock_received, 0) as stock_received,
|
COALESCE(p.stock_received, 0) as stock_received,
|
||||||
COALESCE(p.stock_ordered, 0) as stock_ordered,
|
COALESCE(p.stock_ordered, 0) as stock_ordered,
|
||||||
s.avg_price,
|
0 as avg_price,
|
||||||
s.profit_margin
|
0 as profit_margin
|
||||||
FROM sales_data s
|
FROM sales_data s
|
||||||
LEFT JOIN purchase_data p
|
LEFT JOIN purchase_data p
|
||||||
ON s.product_id = p.product_id
|
ON s.product_id = p.product_id
|
||||||
|
|||||||
@@ -51,18 +51,23 @@ async function resetMetrics() {
|
|||||||
connection = await mysql.createConnection(dbConfig);
|
connection = await mysql.createConnection(dbConfig);
|
||||||
await connection.beginTransaction();
|
await connection.beginTransaction();
|
||||||
|
|
||||||
// Reset all metrics tables
|
// Drop all metrics tables
|
||||||
for (const table of METRICS_TABLES) {
|
for (const table of METRICS_TABLES) {
|
||||||
console.log(`Truncating table: ${table}`);
|
console.log(`Dropping table: ${table}`);
|
||||||
try {
|
try {
|
||||||
await connection.query(`TRUNCATE TABLE ${table}`);
|
await connection.query(`DROP TABLE IF EXISTS ${table}`);
|
||||||
console.log(`Successfully truncated: ${table}`);
|
console.log(`Successfully dropped: ${table}`);
|
||||||
} catch (err) {
|
} catch (err) {
|
||||||
console.error(`Error truncating ${table}:`, err.message);
|
console.error(`Error dropping ${table}:`, err.message);
|
||||||
throw err;
|
throw err;
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
// Recreate all metrics tables from schema
|
||||||
|
const schemaSQL = fs.readFileSync(path.resolve(__dirname, '../db/metrics-schema.sql'), 'utf8');
|
||||||
|
await connection.query(schemaSQL);
|
||||||
|
console.log('All metrics tables recreated successfully');
|
||||||
|
|
||||||
await connection.commit();
|
await connection.commit();
|
||||||
console.log('All metrics tables reset successfully');
|
console.log('All metrics tables reset successfully');
|
||||||
} catch (error) {
|
} catch (error) {
|
||||||
|
|||||||
@@ -487,7 +487,7 @@ export function DataManagement() {
|
|||||||
}
|
}
|
||||||
};
|
};
|
||||||
|
|
||||||
// Check status on mount and periodically
|
// Check status on mount
|
||||||
useEffect(() => {
|
useEffect(() => {
|
||||||
const checkStatus = async () => {
|
const checkStatus = async () => {
|
||||||
console.log('Checking status...');
|
console.log('Checking status...');
|
||||||
@@ -590,14 +590,8 @@ export function DataManagement() {
|
|||||||
}
|
}
|
||||||
};
|
};
|
||||||
|
|
||||||
console.log('Setting up status check interval');
|
console.log('Checking status on page load');
|
||||||
checkStatus();
|
checkStatus();
|
||||||
const interval = setInterval(checkStatus, 5000);
|
|
||||||
|
|
||||||
return () => {
|
|
||||||
console.log('Cleaning up status check interval');
|
|
||||||
clearInterval(interval);
|
|
||||||
};
|
|
||||||
}, []);
|
}, []);
|
||||||
|
|
||||||
const handleUpdateCSV = async () => {
|
const handleUpdateCSV = async () => {
|
||||||
|
|||||||
Reference in New Issue
Block a user