Integrate config tables into existing scripts, add new config tables and settings pages
This commit is contained in:
@@ -189,6 +189,21 @@ router.get('/stock', async (req, res) => {
|
||||
try {
|
||||
const pool = req.app.locals.pool;
|
||||
|
||||
// Get global configuration values
|
||||
const [configs] = await pool.query(`
|
||||
SELECT
|
||||
st.low_stock_threshold,
|
||||
tc.calculation_period_days as turnover_period
|
||||
FROM stock_thresholds st
|
||||
CROSS JOIN turnover_config tc
|
||||
WHERE st.id = 1 AND tc.id = 1
|
||||
`);
|
||||
|
||||
const config = configs[0] || {
|
||||
low_stock_threshold: 5,
|
||||
turnover_period: 30
|
||||
};
|
||||
|
||||
// Get turnover by category
|
||||
const [turnoverByCategory] = await pool.query(`
|
||||
SELECT
|
||||
@@ -200,48 +215,84 @@ router.get('/stock', async (req, res) => {
|
||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||
JOIN product_categories pc ON p.product_id = pc.product_id
|
||||
JOIN categories c ON pc.category_id = c.id
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
|
||||
GROUP BY c.name
|
||||
HAVING turnoverRate > 0
|
||||
ORDER BY turnoverRate DESC
|
||||
LIMIT 10
|
||||
`);
|
||||
`, [config.turnover_period]);
|
||||
|
||||
// Get stock levels over time (last 30 days)
|
||||
// Get stock levels over time
|
||||
const [stockLevels] = await pool.query(`
|
||||
SELECT
|
||||
DATE_FORMAT(o.date, '%Y-%m-%d') as date,
|
||||
SUM(CASE WHEN p.stock_quantity > 5 THEN 1 ELSE 0 END) as inStock,
|
||||
SUM(CASE WHEN p.stock_quantity <= 5 AND p.stock_quantity > 0 THEN 1 ELSE 0 END) as lowStock,
|
||||
SUM(CASE WHEN p.stock_quantity > ? THEN 1 ELSE 0 END) as inStock,
|
||||
SUM(CASE WHEN p.stock_quantity <= ? AND p.stock_quantity > 0 THEN 1 ELSE 0 END) as lowStock,
|
||||
SUM(CASE WHEN p.stock_quantity = 0 THEN 1 ELSE 0 END) as outOfStock
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
|
||||
GROUP BY DATE_FORMAT(o.date, '%Y-%m-%d')
|
||||
ORDER BY date
|
||||
`);
|
||||
`, [
|
||||
config.low_stock_threshold,
|
||||
config.low_stock_threshold,
|
||||
config.turnover_period
|
||||
]);
|
||||
|
||||
// Get critical stock items
|
||||
const [criticalItems] = await pool.query(`
|
||||
WITH product_thresholds AS (
|
||||
SELECT
|
||||
p.product_id,
|
||||
COALESCE(
|
||||
(SELECT reorder_days
|
||||
FROM stock_thresholds st
|
||||
JOIN product_categories pc ON st.category_id = pc.category_id
|
||||
WHERE pc.product_id = p.product_id
|
||||
AND st.vendor = p.vendor LIMIT 1),
|
||||
(SELECT reorder_days
|
||||
FROM stock_thresholds st
|
||||
JOIN product_categories pc ON st.category_id = pc.category_id
|
||||
WHERE pc.product_id = p.product_id
|
||||
AND st.vendor IS NULL LIMIT 1),
|
||||
(SELECT reorder_days
|
||||
FROM stock_thresholds st
|
||||
WHERE st.category_id IS NULL
|
||||
AND st.vendor = p.vendor LIMIT 1),
|
||||
(SELECT reorder_days
|
||||
FROM stock_thresholds st
|
||||
WHERE st.category_id IS NULL
|
||||
AND st.vendor IS NULL LIMIT 1),
|
||||
14
|
||||
) as reorder_days
|
||||
FROM products p
|
||||
)
|
||||
SELECT
|
||||
p.title as product,
|
||||
p.SKU as sku,
|
||||
p.stock_quantity as stockQuantity,
|
||||
GREATEST(ROUND(AVG(o.quantity) * 7), 5) as reorderPoint,
|
||||
GREATEST(ROUND(AVG(o.quantity) * pt.reorder_days), ?) as reorderPoint,
|
||||
ROUND(SUM(o.quantity) / NULLIF(p.stock_quantity, 0), 1) as turnoverRate,
|
||||
CASE
|
||||
WHEN p.stock_quantity = 0 THEN 0
|
||||
ELSE ROUND(p.stock_quantity / NULLIF((SUM(o.quantity) / 30), 0))
|
||||
ELSE ROUND(p.stock_quantity / NULLIF((SUM(o.quantity) / ?), 0))
|
||||
END as daysUntilStockout
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
JOIN product_thresholds pt ON p.product_id = pt.product_id
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
|
||||
AND p.managing_stock = true
|
||||
GROUP BY p.product_id
|
||||
HAVING daysUntilStockout < 30 AND daysUntilStockout >= 0
|
||||
HAVING daysUntilStockout < ? AND daysUntilStockout >= 0
|
||||
ORDER BY daysUntilStockout
|
||||
LIMIT 10
|
||||
`);
|
||||
`, [
|
||||
config.low_stock_threshold,
|
||||
config.turnover_period,
|
||||
config.turnover_period,
|
||||
config.turnover_period
|
||||
]);
|
||||
|
||||
res.json({ turnoverByCategory, stockLevels, criticalItems });
|
||||
} catch (error) {
|
||||
|
||||
@@ -267,12 +267,27 @@ router.get('/trending-products', async (req, res) => {
|
||||
router.get('/inventory-metrics', async (req, res) => {
|
||||
const pool = req.app.locals.pool;
|
||||
try {
|
||||
// Get global configuration values
|
||||
const [configs] = await pool.query(`
|
||||
SELECT
|
||||
st.low_stock_threshold,
|
||||
tc.calculation_period_days as turnover_period
|
||||
FROM stock_thresholds st
|
||||
CROSS JOIN turnover_config tc
|
||||
WHERE st.id = 1 AND tc.id = 1
|
||||
`);
|
||||
|
||||
const config = configs[0] || {
|
||||
low_stock_threshold: 5,
|
||||
turnover_period: 30
|
||||
};
|
||||
|
||||
// Get stock levels by category
|
||||
const [stockLevels] = await pool.query(`
|
||||
SELECT
|
||||
c.name as category,
|
||||
SUM(CASE WHEN stock_quantity > 5 THEN 1 ELSE 0 END) as inStock,
|
||||
SUM(CASE WHEN stock_quantity > 0 AND stock_quantity <= 5 THEN 1 ELSE 0 END) as lowStock,
|
||||
SUM(CASE WHEN stock_quantity > ? THEN 1 ELSE 0 END) as inStock,
|
||||
SUM(CASE WHEN stock_quantity > 0 AND stock_quantity <= ? THEN 1 ELSE 0 END) as lowStock,
|
||||
SUM(CASE WHEN stock_quantity = 0 THEN 1 ELSE 0 END) as outOfStock
|
||||
FROM products p
|
||||
JOIN product_categories pc ON p.product_id = pc.product_id
|
||||
@@ -280,7 +295,7 @@ router.get('/inventory-metrics', async (req, res) => {
|
||||
WHERE visible = true
|
||||
GROUP BY c.name
|
||||
ORDER BY c.name ASC
|
||||
`);
|
||||
`, [config.low_stock_threshold, config.low_stock_threshold]);
|
||||
|
||||
// Get top vendors with product counts and average stock
|
||||
const [topVendors] = await pool.query(`
|
||||
@@ -298,7 +313,6 @@ router.get('/inventory-metrics', async (req, res) => {
|
||||
`);
|
||||
|
||||
// Calculate stock turnover rate by category
|
||||
// Turnover = Units sold in last 30 days / Average inventory level
|
||||
const [stockTurnover] = await pool.query(`
|
||||
WITH CategorySales AS (
|
||||
SELECT
|
||||
@@ -309,7 +323,7 @@ router.get('/inventory-metrics', async (req, res) => {
|
||||
JOIN product_categories pc ON p.product_id = pc.product_id
|
||||
JOIN categories c ON pc.category_id = c.id
|
||||
WHERE o.canceled = false
|
||||
AND DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
AND DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
|
||||
GROUP BY c.name
|
||||
),
|
||||
CategoryStock AS (
|
||||
@@ -331,25 +345,9 @@ router.get('/inventory-metrics', async (req, res) => {
|
||||
FROM CategorySales cs
|
||||
JOIN CategoryStock cst ON cs.category = cst.category
|
||||
ORDER BY rate DESC
|
||||
`);
|
||||
`, [config.turnover_period]);
|
||||
|
||||
res.json({
|
||||
stockLevels: stockLevels.map(row => ({
|
||||
...row,
|
||||
inStock: parseInt(row.inStock || 0),
|
||||
lowStock: parseInt(row.lowStock || 0),
|
||||
outOfStock: parseInt(row.outOfStock || 0)
|
||||
})),
|
||||
topVendors: topVendors.map(row => ({
|
||||
vendor: row.vendor,
|
||||
productCount: parseInt(row.productCount || 0),
|
||||
averageStockLevel: parseFloat(row.averageStockLevel || 0)
|
||||
})),
|
||||
stockTurnover: stockTurnover.map(row => ({
|
||||
category: row.category,
|
||||
rate: parseFloat(row.rate || 0)
|
||||
}))
|
||||
});
|
||||
res.json({ stockLevels, topVendors, stockTurnover });
|
||||
} catch (error) {
|
||||
console.error('Error fetching inventory metrics:', error);
|
||||
res.status(500).json({ error: 'Failed to fetch inventory metrics' });
|
||||
|
||||
Reference in New Issue
Block a user