Add analytics page
This commit is contained in:
379
inventory-server/src/routes/analytics.js
Normal file
379
inventory-server/src/routes/analytics.js
Normal file
@@ -0,0 +1,379 @@
|
||||
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
|
||||
COALESCE(p.categories, 'Uncategorized') 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
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
GROUP BY p.categories
|
||||
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 turnover by category
|
||||
const [turnoverByCategory] = await pool.query(`
|
||||
SELECT
|
||||
COALESCE(p.categories, 'Uncategorized') 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
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
GROUP BY p.categories
|
||||
HAVING turnoverRate > 0
|
||||
ORDER BY turnoverRate DESC
|
||||
LIMIT 10
|
||||
`);
|
||||
|
||||
// Get stock levels over time (last 30 days)
|
||||
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 = 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)
|
||||
GROUP BY DATE_FORMAT(o.date, '%Y-%m-%d')
|
||||
ORDER BY date
|
||||
`);
|
||||
|
||||
// Get critical stock items
|
||||
const [criticalItems] = await pool.query(`
|
||||
SELECT
|
||||
p.title as product,
|
||||
p.SKU as sku,
|
||||
p.stock_quantity as stockQuantity,
|
||||
GREATEST(ROUND(AVG(o.quantity) * 7), 5) 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))
|
||||
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)
|
||||
AND p.managing_stock = true
|
||||
GROUP BY p.product_id
|
||||
HAVING daysUntilStockout < 30 AND daysUntilStockout >= 0
|
||||
ORDER BY daysUntilStockout
|
||||
LIMIT 10
|
||||
`);
|
||||
|
||||
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
|
||||
COALESCE(p.categories, 'Uncategorized') 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
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
|
||||
GROUP BY p.categories
|
||||
HAVING revenue > 0
|
||||
ORDER BY revenue DESC
|
||||
LIMIT 10
|
||||
`);
|
||||
|
||||
// Get category revenue distribution
|
||||
const [distribution] = await pool.query(`
|
||||
SELECT
|
||||
COALESCE(p.categories, 'Uncategorized') as category,
|
||||
SUM(o.price * o.quantity) as value
|
||||
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.categories
|
||||
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;
|
||||
@@ -3,10 +3,12 @@ const fs = require('fs');
|
||||
const express = require('express');
|
||||
const mysql = require('mysql2/promise');
|
||||
const { corsMiddleware, corsErrorHandler } = require('./middleware/cors');
|
||||
const { initPool } = require('./utils/db');
|
||||
const productsRouter = require('./routes/products');
|
||||
const dashboardRouter = require('./routes/dashboard');
|
||||
const ordersRouter = require('./routes/orders');
|
||||
const csvRouter = require('./routes/csv');
|
||||
const analyticsRouter = require('./routes/analytics');
|
||||
|
||||
// Get the absolute path to the .env file
|
||||
const envPath = path.resolve(process.cwd(), '.env');
|
||||
@@ -55,11 +57,28 @@ app.use(corsMiddleware);
|
||||
app.use(express.json());
|
||||
app.use(express.urlencoded({ extended: true }));
|
||||
|
||||
// Initialize database pool
|
||||
const pool = initPool({
|
||||
host: process.env.DB_HOST,
|
||||
user: process.env.DB_USER,
|
||||
password: process.env.DB_PASSWORD,
|
||||
database: process.env.DB_NAME,
|
||||
waitForConnections: true,
|
||||
connectionLimit: process.env.NODE_ENV === 'production' ? 20 : 10,
|
||||
queueLimit: 0,
|
||||
enableKeepAlive: true,
|
||||
keepAliveInitialDelay: 0
|
||||
});
|
||||
|
||||
// Make pool available to routes
|
||||
app.locals.pool = pool;
|
||||
|
||||
// Routes
|
||||
app.use('/api/products', productsRouter);
|
||||
app.use('/api/dashboard', dashboardRouter);
|
||||
app.use('/api/orders', ordersRouter);
|
||||
app.use('/api/csv', csvRouter);
|
||||
app.use('/api/analytics', analyticsRouter);
|
||||
|
||||
// Basic health check route
|
||||
app.get('/health', (req, res) => {
|
||||
@@ -95,22 +114,6 @@ process.on('unhandledRejection', (reason, promise) => {
|
||||
console.error(`[${new Date().toISOString()}] Unhandled Rejection at:`, promise, 'reason:', reason);
|
||||
});
|
||||
|
||||
// Database connection pool
|
||||
const pool = mysql.createPool({
|
||||
host: process.env.DB_HOST,
|
||||
user: process.env.DB_USER,
|
||||
password: process.env.DB_PASSWORD,
|
||||
database: process.env.DB_NAME,
|
||||
waitForConnections: true,
|
||||
connectionLimit: process.env.NODE_ENV === 'production' ? 20 : 10,
|
||||
queueLimit: 0,
|
||||
enableKeepAlive: true,
|
||||
keepAliveInitialDelay: 0
|
||||
});
|
||||
|
||||
// Make pool available to routes
|
||||
app.locals.pool = pool;
|
||||
|
||||
// Test database connection
|
||||
pool.getConnection()
|
||||
.then(connection => {
|
||||
|
||||
21
inventory-server/src/utils/db.js
Normal file
21
inventory-server/src/utils/db.js
Normal file
@@ -0,0 +1,21 @@
|
||||
const mysql = require('mysql2/promise');
|
||||
|
||||
let pool;
|
||||
|
||||
function initPool(config) {
|
||||
pool = mysql.createPool(config);
|
||||
return pool;
|
||||
}
|
||||
|
||||
async function getConnection() {
|
||||
if (!pool) {
|
||||
throw new Error('Database pool not initialized');
|
||||
}
|
||||
return pool.getConnection();
|
||||
}
|
||||
|
||||
module.exports = {
|
||||
initPool,
|
||||
getConnection,
|
||||
getPool: () => pool
|
||||
};
|
||||
Reference in New Issue
Block a user