Files
inventory/inventory-server/src/routes/analytics.js

438 lines
14 KiB
JavaScript

const express = require('express');
const router = express.Router();
// Get overall analytics stats
router.get('/stats', async (req, res) => {
try {
const pool = req.app.locals.pool;
const [results] = await pool.query(`
SELECT
COALESCE(
ROUND(
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1
),
0
) as profitMargin,
COALESCE(
ROUND(
(AVG(p.price / NULLIF(p.cost_price, 0) - 1) * 100), 1
),
0
) as averageMarkup,
COALESCE(
ROUND(
SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0), 2
),
0
) as stockTurnoverRate,
COALESCE(COUNT(DISTINCT p.vendor), 0) as vendorCount,
COALESCE(COUNT(DISTINCT p.categories), 0) as categoryCount,
COALESCE(
ROUND(
AVG(o.price * o.quantity), 2
),
0
) as averageOrderValue
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
`);
// Ensure all values are numbers
const stats = {
profitMargin: Number(results[0].profitMargin) || 0,
averageMarkup: Number(results[0].averageMarkup) || 0,
stockTurnoverRate: Number(results[0].stockTurnoverRate) || 0,
vendorCount: Number(results[0].vendorCount) || 0,
categoryCount: Number(results[0].categoryCount) || 0,
averageOrderValue: Number(results[0].averageOrderValue) || 0
};
res.json(stats);
} catch (error) {
console.error('Error fetching analytics stats:', error);
res.status(500).json({ error: 'Failed to fetch analytics stats' });
}
});
// Get profit analysis data
router.get('/profit', async (req, res) => {
try {
const pool = req.app.locals.pool;
// Get profit margins by category
const [byCategory] = await pool.query(`
SELECT
c.name as category,
ROUND(
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1
) as profitMargin,
SUM(o.price * o.quantity) as revenue,
SUM(p.cost_price * o.quantity) as cost
FROM products p
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)
GROUP BY c.name
ORDER BY profitMargin DESC
LIMIT 10
`);
// Get profit margin trend over time
const [overTime] = await pool.query(`
SELECT
formatted_date as date,
ROUND(
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1
) as profitMargin,
SUM(o.price * o.quantity) as revenue,
SUM(p.cost_price * o.quantity) as cost
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
CROSS JOIN (
SELECT DATE_FORMAT(o.date, '%Y-%m-%d') as formatted_date
FROM orders o
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
GROUP BY DATE_FORMAT(o.date, '%Y-%m-%d')
) dates
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
AND DATE_FORMAT(o.date, '%Y-%m-%d') = dates.formatted_date
GROUP BY formatted_date
ORDER BY formatted_date
`);
// Get top performing products
const [topProducts] = await pool.query(`
SELECT
p.title as product,
ROUND(
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1
) as profitMargin,
SUM(o.price * o.quantity) as revenue,
SUM(p.cost_price * o.quantity) as cost
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
GROUP BY p.product_id, p.title
HAVING revenue > 0
ORDER BY profitMargin DESC
LIMIT 10
`);
res.json({ byCategory, overTime, topProducts });
} catch (error) {
console.error('Error fetching profit analysis:', error);
res.status(500).json({ error: 'Failed to fetch profit analysis' });
}
});
// Get vendor performance data
router.get('/vendors', async (req, res) => {
try {
const pool = req.app.locals.pool;
// Get vendor performance metrics
const [performance] = await pool.query(`
SELECT
p.vendor,
SUM(o.price * o.quantity) as salesVolume,
ROUND(
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1
) as profitMargin,
ROUND(
SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0), 1
) as stockTurnover,
COUNT(DISTINCT p.product_id) as productCount
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
AND p.vendor IS NOT NULL
GROUP BY p.vendor
HAVING salesVolume > 0
ORDER BY salesVolume DESC
LIMIT 10
`);
// Get vendor comparison data
const [comparison] = await pool.query(`
SELECT
p.vendor,
ROUND(SUM(o.price * o.quantity) / NULLIF(COUNT(DISTINCT p.product_id), 0), 2) as salesPerProduct,
ROUND(AVG((o.price - p.cost_price) / NULLIF(o.price, 0) * 100), 1) as averageMargin,
COUNT(DISTINCT p.product_id) as size
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
AND p.vendor IS NOT NULL
GROUP BY p.vendor
HAVING salesPerProduct > 0
ORDER BY salesPerProduct DESC
LIMIT 20
`);
res.json({ performance, comparison });
} catch (error) {
console.error('Error fetching vendor performance:', error);
res.status(500).json({ error: 'Failed to fetch vendor performance' });
}
});
// Get stock analysis data
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
c.name as category,
ROUND(SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0), 1) as turnoverRate,
ROUND(AVG(p.stock_quantity), 0) as averageStock,
SUM(o.quantity) as totalSales
FROM products p
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 ? DAY)
GROUP BY c.name
HAVING turnoverRate > 0
ORDER BY turnoverRate DESC
LIMIT 10
`, [config.turnover_period]);
// 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 > ? 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 ? 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) * 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) / ?), 0))
END as daysUntilStockout
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
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 < ? 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) {
console.error('Error fetching stock analysis:', error);
res.status(500).json({ error: 'Failed to fetch stock analysis' });
}
});
// Get price analysis data
router.get('/pricing', async (req, res) => {
try {
const pool = req.app.locals.pool;
// Get price points analysis
const [pricePoints] = await pool.query(`
SELECT
p.price,
SUM(o.quantity) as salesVolume,
SUM(o.price * o.quantity) as revenue,
p.categories as category
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
GROUP BY p.price, p.categories
HAVING salesVolume > 0
ORDER BY revenue DESC
LIMIT 50
`);
// Get price elasticity data (price changes vs demand)
const [elasticity] = await pool.query(`
SELECT
DATE_FORMAT(o.date, '%Y-%m-%d') as date,
AVG(o.price) as price,
SUM(o.quantity) as demand
FROM orders o
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
GROUP BY DATE_FORMAT(o.date, '%Y-%m-%d')
ORDER BY date
`);
// Get price optimization recommendations
const [recommendations] = await pool.query(`
SELECT
p.title as product,
p.price as currentPrice,
ROUND(
CASE
WHEN AVG(o.quantity) > 10 THEN p.price * 1.1
WHEN AVG(o.quantity) < 2 THEN p.price * 0.9
ELSE p.price
END, 2
) as recommendedPrice,
ROUND(
SUM(o.price * o.quantity) *
CASE
WHEN AVG(o.quantity) > 10 THEN 1.15
WHEN AVG(o.quantity) < 2 THEN 0.95
ELSE 1
END, 2
) as potentialRevenue,
CASE
WHEN AVG(o.quantity) > 10 THEN 85
WHEN AVG(o.quantity) < 2 THEN 75
ELSE 65
END as confidence
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
GROUP BY p.product_id
HAVING ABS(recommendedPrice - currentPrice) > 0
ORDER BY potentialRevenue - SUM(o.price * o.quantity) DESC
LIMIT 10
`);
res.json({ pricePoints, elasticity, recommendations });
} catch (error) {
console.error('Error fetching price analysis:', error);
res.status(500).json({ error: 'Failed to fetch price analysis' });
}
});
// Get category performance data
router.get('/categories', async (req, res) => {
try {
const pool = req.app.locals.pool;
// Get category performance metrics
const [performance] = await pool.query(`
SELECT
c.name as category,
SUM(o.price * o.quantity) as revenue,
SUM(o.price * o.quantity - p.cost_price * o.quantity) as profit,
ROUND(
((SUM(CASE
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) /
NULLIF(SUM(CASE
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
AND o.date < DATE_SUB(CURDATE(), INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END), 0)) - 1) * 100,
1
) as growth,
COUNT(DISTINCT p.product_id) as productCount
FROM products p
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 60 DAY)
GROUP BY c.name
HAVING revenue > 0
ORDER BY revenue DESC
LIMIT 10
`);
// Get category revenue distribution
const [distribution] = await pool.query(`
SELECT
c.name as category,
SUM(o.price * o.quantity) as value
FROM products p
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)
GROUP BY c.name
HAVING value > 0
ORDER BY value DESC
LIMIT 6
`);
res.json({ performance, distribution });
} catch (error) {
console.error('Error fetching category performance:', error);
res.status(500).json({ error: 'Failed to fetch category performance' });
}
});
module.exports = router;