Add new frontend dashboard components and update scripts/schema

This commit is contained in:
2025-01-17 15:21:19 -05:00
parent 609490895b
commit 48c7ab9134
14 changed files with 1451 additions and 92 deletions

View File

@@ -63,6 +63,10 @@ CREATE TABLE IF NOT EXISTS product_metrics (
current_lead_time INT,
target_lead_time INT,
lead_time_status VARCHAR(20),
-- Forecast metrics
forecast_accuracy DECIMAL(5,2) DEFAULT NULL,
forecast_bias DECIMAL(5,2) DEFAULT NULL,
last_forecast_date DATE DEFAULT NULL,
PRIMARY KEY (product_id),
FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE,
INDEX idx_metrics_revenue (total_revenue),
@@ -71,7 +75,8 @@ CREATE TABLE IF NOT EXISTS product_metrics (
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)
INDEX idx_metrics_sales (daily_sales_avg, weekly_sales_avg, monthly_sales_avg),
INDEX idx_metrics_forecast (forecast_accuracy, forecast_bias)
);
-- New table for time-based aggregates
@@ -97,6 +102,20 @@ CREATE TABLE IF NOT EXISTS product_time_aggregates (
INDEX idx_date (year, month)
);
-- Create vendor details table
CREATE TABLE IF NOT EXISTS vendor_details (
vendor VARCHAR(100) NOT NULL,
contact_name VARCHAR(100),
email VARCHAR(100),
phone VARCHAR(20),
status VARCHAR(20) DEFAULT 'active',
notes TEXT,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (vendor),
INDEX idx_vendor_status (status)
);
-- New table for vendor metrics
CREATE TABLE IF NOT EXISTS vendor_metrics (
vendor VARCHAR(100) NOT NULL,
@@ -200,10 +219,95 @@ CREATE TABLE IF NOT EXISTS category_sales_metrics (
INDEX idx_period (period_start, period_end)
);
-- New table for brand metrics
CREATE TABLE IF NOT EXISTS brand_metrics (
brand VARCHAR(100) NOT NULL,
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
-- Product metrics
product_count INT DEFAULT 0,
active_products INT DEFAULT 0,
-- Stock metrics
total_stock_units INT DEFAULT 0,
total_stock_cost DECIMAL(10,2) DEFAULT 0,
total_stock_retail DECIMAL(10,2) DEFAULT 0,
-- Sales metrics
total_revenue DECIMAL(10,2) DEFAULT 0,
avg_margin DECIMAL(5,2) DEFAULT 0,
growth_rate DECIMAL(5,2) DEFAULT 0,
PRIMARY KEY (brand),
INDEX idx_brand_metrics_last_calculated (last_calculated_at),
INDEX idx_brand_metrics_revenue (total_revenue),
INDEX idx_brand_metrics_growth (growth_rate)
);
-- New table for brand time-based metrics
CREATE TABLE IF NOT EXISTS brand_time_metrics (
brand VARCHAR(100) NOT NULL,
year INT NOT NULL,
month INT NOT NULL,
-- Product metrics
product_count INT DEFAULT 0,
active_products INT DEFAULT 0,
-- Stock metrics
total_stock_units INT DEFAULT 0,
total_stock_cost DECIMAL(10,2) DEFAULT 0,
total_stock_retail DECIMAL(10,2) DEFAULT 0,
-- Sales metrics
total_revenue DECIMAL(10,2) DEFAULT 0,
avg_margin DECIMAL(5,2) DEFAULT 0,
PRIMARY KEY (brand, year, month),
INDEX idx_brand_date (year, month)
);
-- New table for sales forecasts
CREATE TABLE IF NOT EXISTS sales_forecasts (
product_id BIGINT NOT NULL,
forecast_date DATE NOT NULL,
forecast_units DECIMAL(10,2) DEFAULT 0,
forecast_revenue DECIMAL(10,2) DEFAULT 0,
confidence_level DECIMAL(5,2) DEFAULT 0,
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (product_id, forecast_date),
FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE,
INDEX idx_forecast_date (forecast_date),
INDEX idx_forecast_last_calculated (last_calculated_at)
);
-- New table for category forecasts
CREATE TABLE IF NOT EXISTS category_forecasts (
category_id BIGINT NOT NULL,
forecast_date DATE NOT NULL,
forecast_units DECIMAL(10,2) DEFAULT 0,
forecast_revenue DECIMAL(10,2) DEFAULT 0,
confidence_level DECIMAL(5,2) DEFAULT 0,
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (category_id, forecast_date),
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
INDEX idx_category_forecast_date (forecast_date),
INDEX idx_category_forecast_last_calculated (last_calculated_at)
);
-- Create table for sales seasonality factors
CREATE TABLE IF NOT EXISTS sales_seasonality (
month INT NOT NULL,
seasonality_factor DECIMAL(5,3) DEFAULT 0,
last_updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (month),
CHECK (month BETWEEN 1 AND 12),
CHECK (seasonality_factor BETWEEN -1.0 AND 1.0)
);
-- Insert default seasonality factors (neutral)
INSERT INTO sales_seasonality (month, seasonality_factor)
VALUES
(1, 0), (2, 0), (3, 0), (4, 0), (5, 0), (6, 0),
(7, 0), (8, 0), (9, 0), (10, 0), (11, 0), (12, 0)
ON DUPLICATE KEY UPDATE last_updated = CURRENT_TIMESTAMP;
-- Re-enable foreign key checks
SET FOREIGN_KEY_CHECKS = 1;
-- Create view for inventory health (after all tables are created)
-- Create view for inventory health
CREATE OR REPLACE VIEW inventory_health AS
WITH product_thresholds AS (
SELECT
@@ -298,77 +402,6 @@ LEFT JOIN
WHERE
p.managing_stock = true;
-- Create view for sales trends analysis
CREATE OR REPLACE VIEW product_sales_trends AS
SELECT
p.product_id,
p.SKU,
p.title,
COALESCE(SUM(o.quantity), 0) as total_sold,
COALESCE(AVG(o.quantity), 0) as avg_quantity_per_order,
COALESCE(COUNT(DISTINCT o.order_number), 0) as number_of_orders,
MIN(o.date) as first_sale_date,
MAX(o.date) as last_sale_date
FROM
products p
LEFT JOIN
orders o ON p.product_id = o.product_id
WHERE
o.canceled = false
GROUP BY
p.product_id, p.SKU, p.title;
-- Create view for category sales trends
CREATE OR REPLACE VIEW category_sales_trends AS
SELECT
c.id as category_id,
c.name as category_name,
p.brand,
COUNT(DISTINCT p.product_id) as num_products,
COALESCE(AVG(o.quantity), 0) as avg_daily_sales,
COALESCE(SUM(o.quantity), 0) as total_sold,
COALESCE(AVG(o.price), 0) as avg_price,
MIN(o.date) as first_sale_date,
MAX(o.date) as last_sale_date
FROM
categories c
JOIN
product_categories pc ON c.id = pc.category_id
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
GROUP BY
c.id, c.name, p.brand;
-- Create view for vendor performance trends
CREATE OR REPLACE VIEW vendor_performance_trends AS
SELECT
v.vendor,
v.contact_name,
v.status,
vm.avg_lead_time_days,
vm.on_time_delivery_rate,
vm.order_fill_rate,
vm.total_orders,
vm.total_late_orders,
vm.total_purchase_value,
vm.avg_order_value,
vm.active_products,
vm.total_products,
vm.total_revenue,
vm.avg_margin_percent,
CASE
WHEN vm.order_fill_rate >= 95 THEN 'Excellent'
WHEN vm.order_fill_rate >= 85 THEN 'Good'
WHEN vm.order_fill_rate >= 75 THEN 'Fair'
ELSE 'Poor'
END as performance_rating
FROM
vendor_details v
LEFT JOIN
vendor_metrics vm ON v.vendor = vm.vendor;
-- Create view for category performance trends
CREATE OR REPLACE VIEW category_performance_trends AS
SELECT

View File

@@ -974,6 +974,319 @@ async function calculateSafetyStock(connection, startTime, totalProducts) {
`);
}
// Add new function for brand metrics calculation
async function calculateBrandMetrics(connection, startTime, totalProducts) {
outputProgress({
status: 'running',
operation: 'Calculating brand metrics',
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 brand metrics
await connection.query(`
INSERT INTO brand_metrics (
brand,
product_count,
active_products,
total_stock_units,
total_stock_cost,
total_stock_retail,
total_revenue,
avg_margin,
growth_rate
)
WITH brand_data AS (
SELECT
p.brand,
COUNT(DISTINCT p.product_id) as product_count,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
SUM(p.stock_quantity) as total_stock_units,
SUM(p.stock_quantity * p.cost_price) as total_stock_cost,
SUM(p.stock_quantity * p.price) as total_stock_retail,
SUM(o.price * o.quantity) as total_revenue,
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,
-- 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
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
WHERE p.brand IS NOT NULL
GROUP BY p.brand
)
SELECT
brand,
product_count,
active_products,
total_stock_units,
total_stock_cost,
total_stock_retail,
total_revenue,
avg_margin,
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
FROM brand_data
ON DUPLICATE KEY UPDATE
product_count = VALUES(product_count),
active_products = VALUES(active_products),
total_stock_units = VALUES(total_stock_units),
total_stock_cost = VALUES(total_stock_cost),
total_stock_retail = VALUES(total_stock_retail),
total_revenue = VALUES(total_revenue),
avg_margin = VALUES(avg_margin),
growth_rate = VALUES(growth_rate),
last_calculated_at = CURRENT_TIMESTAMP
`);
// Calculate brand time-based metrics
await connection.query(`
INSERT INTO brand_time_metrics (
brand,
year,
month,
product_count,
active_products,
total_stock_units,
total_stock_cost,
total_stock_retail,
total_revenue,
avg_margin
)
SELECT
p.brand,
YEAR(o.date) as year,
MONTH(o.date) as month,
COUNT(DISTINCT p.product_id) as product_count,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
SUM(p.stock_quantity) as total_stock_units,
SUM(p.stock_quantity * p.cost_price) as total_stock_cost,
SUM(p.stock_quantity * p.price) as total_stock_retail,
SUM(o.price * o.quantity) as total_revenue,
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
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
WHERE p.brand IS NOT NULL
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
GROUP BY p.brand, YEAR(o.date), MONTH(o.date)
ON DUPLICATE KEY UPDATE
product_count = VALUES(product_count),
active_products = VALUES(active_products),
total_stock_units = VALUES(total_stock_units),
total_stock_cost = VALUES(total_stock_cost),
total_stock_retail = VALUES(total_stock_retail),
total_revenue = VALUES(total_revenue),
avg_margin = VALUES(avg_margin)
`);
}
// Add new function for sales forecast calculation
async function calculateSalesForecasts(connection, startTime, totalProducts) {
outputProgress({
status: 'running',
operation: 'Calculating sales forecasts',
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'
});
// Calculate product-level forecasts
await connection.query(`
INSERT INTO sales_forecasts (
product_id,
forecast_date,
forecast_units,
forecast_revenue,
confidence_level,
last_calculated_at
)
WITH daily_sales AS (
SELECT
o.product_id,
DATE(o.date) as sale_date,
SUM(o.quantity) as daily_quantity,
SUM(o.price * o.quantity) as daily_revenue
FROM orders o
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 90 DAY)
GROUP BY o.product_id, DATE(o.date)
),
forecast_dates AS (
SELECT
DATE_ADD(CURRENT_DATE, INTERVAL n DAY) as forecast_date
FROM (
SELECT 0 as n UNION SELECT 1 UNION SELECT 2 UNION SELECT 3 UNION SELECT 4 UNION
SELECT 5 UNION SELECT 6 UNION SELECT 7 UNION SELECT 14 UNION SELECT 30 UNION
SELECT 60 UNION SELECT 90
) numbers
),
product_stats AS (
SELECT
ds.product_id,
AVG(ds.daily_quantity) as avg_daily_quantity,
STDDEV_SAMP(ds.daily_quantity) as std_daily_quantity,
AVG(ds.daily_revenue) as avg_daily_revenue,
STDDEV_SAMP(ds.daily_revenue) as std_daily_revenue,
COUNT(*) as data_points
FROM daily_sales ds
GROUP BY ds.product_id
)
SELECT
ps.product_id,
fd.forecast_date,
GREATEST(0,
ps.avg_daily_quantity *
(1 + COALESCE(
(SELECT seasonality_factor
FROM sales_seasonality
WHERE MONTH(fd.forecast_date) = month
LIMIT 1),
0
))
) as forecast_units,
GREATEST(0,
ps.avg_daily_revenue *
(1 + COALESCE(
(SELECT seasonality_factor
FROM sales_seasonality
WHERE MONTH(fd.forecast_date) = month
LIMIT 1),
0
))
) as forecast_revenue,
CASE
WHEN ps.data_points >= 60 THEN 90
WHEN ps.data_points >= 30 THEN 80
WHEN ps.data_points >= 14 THEN 70
ELSE 60
END as confidence_level,
NOW() as last_calculated_at
FROM product_stats ps
CROSS JOIN forecast_dates fd
WHERE ps.avg_daily_quantity > 0
ON DUPLICATE KEY UPDATE
forecast_units = VALUES(forecast_units),
forecast_revenue = VALUES(forecast_revenue),
confidence_level = VALUES(confidence_level),
last_calculated_at = NOW()
`);
// Calculate category-level forecasts
await connection.query(`
INSERT INTO category_forecasts (
category_id,
forecast_date,
forecast_units,
forecast_revenue,
confidence_level,
last_calculated_at
)
WITH category_daily_sales AS (
SELECT
pc.category_id,
DATE(o.date) as sale_date,
SUM(o.quantity) as daily_quantity,
SUM(o.price * o.quantity) as daily_revenue
FROM orders o
JOIN product_categories pc ON o.product_id = pc.product_id
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 90 DAY)
GROUP BY pc.category_id, DATE(o.date)
),
forecast_dates AS (
SELECT
DATE_ADD(CURRENT_DATE, INTERVAL n DAY) as forecast_date
FROM (
SELECT 0 as n UNION SELECT 1 UNION SELECT 2 UNION SELECT 3 UNION SELECT 4 UNION
SELECT 5 UNION SELECT 6 UNION SELECT 7 UNION SELECT 14 UNION SELECT 30 UNION
SELECT 60 UNION SELECT 90
) numbers
),
category_stats AS (
SELECT
cds.category_id,
AVG(cds.daily_quantity) as avg_daily_quantity,
STDDEV_SAMP(cds.daily_quantity) as std_daily_quantity,
AVG(cds.daily_revenue) as avg_daily_revenue,
STDDEV_SAMP(cds.daily_revenue) as std_daily_revenue,
COUNT(*) as data_points
FROM category_daily_sales cds
GROUP BY cds.category_id
)
SELECT
cs.category_id,
fd.forecast_date,
GREATEST(0,
cs.avg_daily_quantity *
(1 + COALESCE(
(SELECT seasonality_factor
FROM sales_seasonality
WHERE MONTH(fd.forecast_date) = month
LIMIT 1),
0
))
) as forecast_units,
GREATEST(0,
cs.avg_daily_revenue *
(1 + COALESCE(
(SELECT seasonality_factor
FROM sales_seasonality
WHERE MONTH(fd.forecast_date) = month
LIMIT 1),
0
))
) as forecast_revenue,
CASE
WHEN cs.data_points >= 60 THEN 90
WHEN cs.data_points >= 30 THEN 80
WHEN cs.data_points >= 14 THEN 70
ELSE 60
END as confidence_level,
NOW() as last_calculated_at
FROM category_stats cs
CROSS JOIN forecast_dates fd
WHERE cs.avg_daily_quantity > 0
ON DUPLICATE KEY UPDATE
forecast_units = VALUES(forecast_units),
forecast_revenue = VALUES(forecast_revenue),
confidence_level = VALUES(confidence_level),
last_calculated_at = NOW()
`);
}
// Update the main calculation function to include the new metrics
async function calculateMetrics() {
let pool;
@@ -1727,6 +2040,10 @@ async function calculateMetrics() {
WHERE s.product_id IS NULL
`);
// Add new metric calculations before final success message
await calculateBrandMetrics(connection, startTime, totalProducts);
await calculateSalesForecasts(connection, startTime, totalProducts);
// Final success message
outputProgress({
status: 'complete',

View File

@@ -17,15 +17,21 @@ function outputProgress(data) {
// Explicitly define all metrics-related tables
const METRICS_TABLES = [
'temp_sales_metrics',
'temp_purchase_metrics',
'brand_metrics',
'brand_time_metrics',
'category_forecasts',
'category_metrics',
'category_sales_metrics',
'category_time_metrics',
'product_metrics',
'product_time_aggregates',
'vendor_metrics',
'vendor_time_metrics',
'category_metrics',
'category_time_metrics',
'category_sales_metrics'
'sales_forecasts',
'sales_seasonality',
'temp_purchase_metrics',
'temp_sales_metrics',
'vendor_metrics', //before vendor_details for foreign key
'vendor_time_metrics', //before vendor_details for foreign key
'vendor_details'
];
// Config tables that must exist