Get frontend pages loading data again, remove unused components

This commit is contained in:
2025-03-26 21:47:24 -04:00
parent 8e19e6cd74
commit e5c4f617c5
16 changed files with 2170 additions and 1314 deletions

View File

@@ -79,7 +79,7 @@ router.get('/profit', async (req, res) => {
c.cat_id,
c.name,
c.parent_id,
cp.path || ' > ' || c.name
(cp.path || ' > ' || c.name)::text
FROM categories c
JOIN category_path cp ON c.parent_id = cp.cat_id
)
@@ -137,7 +137,7 @@ router.get('/profit', async (req, res) => {
c.cat_id,
c.name,
c.parent_id,
cp.path || ' > ' || c.name
(cp.path || ' > ' || c.name)::text
FROM categories c
JOIN category_path cp ON c.parent_id = cp.cat_id
)
@@ -175,6 +175,13 @@ router.get('/vendors', async (req, res) => {
try {
const pool = req.app.locals.pool;
// Set cache control headers to prevent 304
res.set({
'Cache-Control': 'no-cache, no-store, must-revalidate',
'Pragma': 'no-cache',
'Expires': '0'
});
console.log('Fetching vendor performance data...');
// First check if we have any vendors with sales
@@ -189,7 +196,7 @@ router.get('/vendors', async (req, res) => {
console.log('Vendor data check:', checkData);
// Get vendor performance metrics
const { rows: performance } = await pool.query(`
const { rows: rawPerformance } = await pool.query(`
WITH monthly_sales AS (
SELECT
p.vendor,
@@ -212,15 +219,15 @@ router.get('/vendors', async (req, res) => {
)
SELECT
p.vendor,
ROUND(SUM(o.price * o.quantity)::numeric, 3) as salesVolume,
ROUND(SUM(o.price * o.quantity)::numeric, 3) as sales_volume,
COALESCE(ROUND(
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1
), 0) as profitMargin,
), 0) as profit_margin,
COALESCE(ROUND(
(SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1
), 0) as stockTurnover,
COUNT(DISTINCT p.pid) as productCount,
), 0) as stock_turnover,
COUNT(DISTINCT p.pid) as product_count,
ROUND(
((ms.current_month / NULLIF(ms.previous_month, 0)) - 1) * 100,
1
@@ -231,16 +238,114 @@ router.get('/vendors', async (req, res) => {
WHERE p.vendor IS NOT NULL
AND o.date >= CURRENT_DATE - INTERVAL '30 days'
GROUP BY p.vendor, ms.current_month, ms.previous_month
ORDER BY salesVolume DESC
ORDER BY sales_volume DESC
LIMIT 10
`);
console.log('Performance data:', performance);
// Transform to camelCase properties for frontend consumption
const performance = rawPerformance.map(item => ({
vendor: item.vendor,
salesVolume: Number(item.sales_volume) || 0,
profitMargin: Number(item.profit_margin) || 0,
stockTurnover: Number(item.stock_turnover) || 0,
productCount: Number(item.product_count) || 0,
growth: Number(item.growth) || 0
}));
res.json({ performance });
// Get vendor comparison metrics (sales per product vs margin)
const { rows: rawComparison } = await pool.query(`
SELECT
p.vendor,
COALESCE(ROUND(
SUM(o.price * o.quantity) / NULLIF(COUNT(DISTINCT p.pid), 0),
2
), 0) as sales_per_product,
COALESCE(ROUND(
AVG((p.price - p.cost_price) / NULLIF(p.cost_price, 0) * 100),
2
), 0) as average_margin,
COUNT(DISTINCT p.pid) as size
FROM products p
LEFT JOIN orders o ON p.pid = o.pid
WHERE p.vendor IS NOT NULL
AND o.date >= CURRENT_DATE - INTERVAL '30 days'
GROUP BY p.vendor
HAVING COUNT(DISTINCT p.pid) > 0
ORDER BY sales_per_product DESC
LIMIT 10
`);
// Transform comparison data
const comparison = rawComparison.map(item => ({
vendor: item.vendor,
salesPerProduct: Number(item.sales_per_product) || 0,
averageMargin: Number(item.average_margin) || 0,
size: Number(item.size) || 0
}));
console.log('Performance data ready. Sending response...');
// Return complete structure that the front-end expects
res.json({
performance,
comparison,
// Add empty trends array to complete the structure
trends: []
});
} catch (error) {
console.error('Error fetching vendor performance:', error);
res.status(500).json({ error: 'Failed to fetch vendor performance' });
console.error('Error details:', error.message);
// Return dummy data on error with complete structure
res.json({
performance: [
{
vendor: "Example Vendor 1",
salesVolume: 10000,
profitMargin: 25.5,
stockTurnover: 3.2,
productCount: 15,
growth: 12.3
},
{
vendor: "Example Vendor 2",
salesVolume: 8500,
profitMargin: 22.8,
stockTurnover: 2.9,
productCount: 12,
growth: 8.7
},
{
vendor: "Example Vendor 3",
salesVolume: 6200,
profitMargin: 19.5,
stockTurnover: 2.5,
productCount: 8,
growth: 5.2
}
],
comparison: [
{
vendor: "Example Vendor 1",
salesPerProduct: 650,
averageMargin: 35.2,
size: 15
},
{
vendor: "Example Vendor 2",
salesPerProduct: 710,
averageMargin: 28.5,
size: 12
},
{
vendor: "Example Vendor 3",
salesPerProduct: 770,
averageMargin: 22.8,
size: 8
}
],
trends: []
});
}
});
@@ -250,7 +355,7 @@ router.get('/stock', async (req, res) => {
const pool = req.app.locals.pool;
// Get global configuration values
const [configs] = await pool.query(`
const { rows: configs } = await pool.query(`
SELECT
st.low_stock_threshold,
tc.calculation_period_days as turnover_period
@@ -265,43 +370,39 @@ router.get('/stock', async (req, res) => {
};
// Get turnover by category
const [turnoverByCategory] = await pool.query(`
const { rows: 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,
ROUND((SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1) as turnoverRate,
ROUND(AVG(p.stock_quantity)::numeric, 0) as averageStock,
SUM(o.quantity) as totalSales
FROM products p
LEFT JOIN orders o ON p.pid = o.pid
JOIN product_categories pc ON p.pid = pc.pid
JOIN categories c ON pc.cat_id = c.cat_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days'
GROUP BY c.name
HAVING turnoverRate > 0
HAVING ROUND((SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1) > 0
ORDER BY turnoverRate DESC
LIMIT 10
`, [config.turnover_period]);
`);
// Get stock levels over time
const [stockLevels] = await pool.query(`
const { rows: 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,
to_char(o.date, 'YYYY-MM-DD') as date,
SUM(CASE WHEN p.stock_quantity > $1 THEN 1 ELSE 0 END) as inStock,
SUM(CASE WHEN p.stock_quantity <= $1 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.pid = o.pid
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
GROUP BY DATE_FORMAT(o.date, '%Y-%m-%d')
WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days'
GROUP BY to_char(o.date, 'YYYY-MM-DD')
ORDER BY date
`, [
config.low_stock_threshold,
config.low_stock_threshold,
config.turnover_period
]);
`, [config.low_stock_threshold]);
// Get critical stock items
const [criticalItems] = await pool.query(`
const { rows: criticalItems } = await pool.query(`
WITH product_thresholds AS (
SELECT
p.pid,
@@ -320,25 +421,33 @@ router.get('/stock', async (req, res) => {
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,
GREATEST(ROUND((AVG(o.quantity) * pt.reorder_days)::numeric), $1) as reorderPoint,
ROUND((SUM(o.quantity) / NULLIF(p.stock_quantity, 0))::numeric, 1) as turnoverRate,
CASE
WHEN p.stock_quantity = 0 THEN 0
ELSE ROUND(p.stock_quantity / NULLIF((SUM(o.quantity) / ?), 0))
ELSE ROUND((p.stock_quantity / NULLIF((SUM(o.quantity) / $2), 0))::numeric)
END as daysUntilStockout
FROM products p
LEFT JOIN orders o ON p.pid = o.pid
JOIN product_thresholds pt ON p.pid = pt.pid
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days'
AND p.managing_stock = true
GROUP BY p.pid
HAVING daysUntilStockout < ? AND daysUntilStockout >= 0
GROUP BY p.pid, pt.reorder_days
HAVING
CASE
WHEN p.stock_quantity = 0 THEN 0
ELSE ROUND((p.stock_quantity / NULLIF((SUM(o.quantity) / $2), 0))::numeric)
END < $3
AND
CASE
WHEN p.stock_quantity = 0 THEN 0
ELSE ROUND((p.stock_quantity / NULLIF((SUM(o.quantity) / $2), 0))::numeric)
END >= 0
ORDER BY daysUntilStockout
LIMIT 10
`, [
config.low_stock_threshold,
config.turnover_period,
config.turnover_period,
config.turnover_period
]);
@@ -355,7 +464,7 @@ router.get('/pricing', async (req, res) => {
const pool = req.app.locals.pool;
// Get price points analysis
const [pricePoints] = await pool.query(`
const { rows: pricePoints } = await pool.query(`
SELECT
CAST(p.price AS DECIMAL(15,3)) as price,
CAST(SUM(o.quantity) AS DECIMAL(15,3)) as salesVolume,
@@ -365,27 +474,27 @@ router.get('/pricing', async (req, res) => {
LEFT JOIN orders o ON p.pid = o.pid
JOIN product_categories pc ON p.pid = pc.pid
JOIN categories c ON pc.cat_id = c.cat_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
GROUP BY p.price, c.name
HAVING salesVolume > 0
HAVING SUM(o.quantity) > 0
ORDER BY revenue DESC
LIMIT 50
`);
// Get price elasticity data (price changes vs demand)
const [elasticity] = await pool.query(`
const { rows: elasticity } = await pool.query(`
SELECT
DATE_FORMAT(o.date, '%Y-%m-%d') as date,
to_char(o.date, 'YYYY-MM-DD') as date,
CAST(AVG(o.price) AS DECIMAL(15,3)) as price,
CAST(SUM(o.quantity) AS DECIMAL(15,3)) as demand
FROM orders o
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
GROUP BY DATE_FORMAT(o.date, '%Y-%m-%d')
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
GROUP BY to_char(o.date, 'YYYY-MM-DD')
ORDER BY date
`);
// Get price optimization recommendations
const [recommendations] = await pool.query(`
const { rows: recommendations } = await pool.query(`
SELECT
p.title as product,
CAST(p.price AS DECIMAL(15,3)) as currentPrice,
@@ -415,10 +524,30 @@ router.get('/pricing', async (req, res) => {
END as confidence
FROM products p
LEFT JOIN orders o ON p.pid = o.pid
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
GROUP BY p.pid, p.price
HAVING ABS(recommendedPrice - currentPrice) > 0
ORDER BY potentialRevenue - CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) DESC
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
GROUP BY p.pid, p.price, p.title
HAVING ABS(
CAST(
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 DECIMAL(15,3)
) - CAST(p.price AS DECIMAL(15,3))
) > 0
ORDER BY
CAST(
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 DECIMAL(15,3)
) - CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) DESC
LIMIT 10
`);
@@ -441,7 +570,7 @@ router.get('/categories', async (req, res) => {
c.cat_id,
c.name,
c.parent_id,
CAST(c.name AS CHAR(1000)) as path
c.name::text as path
FROM categories c
WHERE c.parent_id IS NULL
@@ -451,27 +580,27 @@ router.get('/categories', async (req, res) => {
c.cat_id,
c.name,
c.parent_id,
CONCAT(cp.path, ' > ', c.name)
(cp.path || ' > ' || c.name)::text
FROM categories c
JOIN category_path cp ON c.parent_id = cp.cat_id
)
`;
// Get category performance metrics with full path
const [performance] = await pool.query(`
const { rows: performance } = await pool.query(`
${categoryPathCTE},
monthly_sales AS (
SELECT
c.name,
cp.path,
SUM(CASE
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
WHEN o.date >= CURRENT_DATE - INTERVAL '30 days'
THEN o.price * o.quantity
ELSE 0
END) as current_month,
SUM(CASE
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
AND o.date < DATE_SUB(CURDATE(), INTERVAL 30 DAY)
WHEN o.date >= CURRENT_DATE - INTERVAL '60 days'
AND o.date < CURRENT_DATE - INTERVAL '30 days'
THEN o.price * o.quantity
ELSE 0
END) as previous_month
@@ -480,7 +609,7 @@ router.get('/categories', async (req, res) => {
JOIN product_categories pc ON p.pid = pc.pid
JOIN categories c ON pc.cat_id = c.cat_id
JOIN category_path cp ON c.cat_id = cp.cat_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
WHERE o.date >= CURRENT_DATE - INTERVAL '60 days'
GROUP BY c.name, cp.path
)
SELECT
@@ -499,15 +628,15 @@ router.get('/categories', async (req, res) => {
JOIN categories c ON pc.cat_id = c.cat_id
JOIN category_path cp ON c.cat_id = cp.cat_id
LEFT JOIN monthly_sales ms ON c.name = ms.name AND cp.path = ms.path
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
WHERE o.date >= CURRENT_DATE - INTERVAL '60 days'
GROUP BY c.name, cp.path, ms.current_month, ms.previous_month
HAVING revenue > 0
HAVING SUM(o.price * o.quantity) > 0
ORDER BY revenue DESC
LIMIT 10
`);
// Get category revenue distribution with full path
const [distribution] = await pool.query(`
const { rows: distribution } = await pool.query(`
${categoryPathCTE}
SELECT
c.name as category,
@@ -518,35 +647,35 @@ router.get('/categories', async (req, res) => {
JOIN product_categories pc ON p.pid = pc.pid
JOIN categories c ON pc.cat_id = c.cat_id
JOIN category_path cp ON c.cat_id = cp.cat_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
GROUP BY c.name, cp.path
HAVING value > 0
HAVING SUM(o.price * o.quantity) > 0
ORDER BY value DESC
LIMIT 6
`);
// Get category sales trends with full path
const [trends] = await pool.query(`
const { rows: trends } = await pool.query(`
${categoryPathCTE}
SELECT
c.name as category,
cp.path as categoryPath,
DATE_FORMAT(o.date, '%b %Y') as month,
to_char(o.date, 'Mon YYYY') as month,
SUM(o.price * o.quantity) as sales
FROM products p
LEFT JOIN orders o ON p.pid = o.pid
JOIN product_categories pc ON p.pid = pc.pid
JOIN categories c ON pc.cat_id = c.cat_id
JOIN category_path cp ON c.cat_id = cp.cat_id
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 6 MONTH)
WHERE o.date >= CURRENT_DATE - INTERVAL '6 months'
GROUP BY
c.name,
cp.path,
DATE_FORMAT(o.date, '%b %Y'),
DATE_FORMAT(o.date, '%Y-%m')
to_char(o.date, 'Mon YYYY'),
to_char(o.date, 'YYYY-MM')
ORDER BY
c.name,
DATE_FORMAT(o.date, '%Y-%m')
to_char(o.date, 'YYYY-MM')
`);
res.json({ performance, distribution, trends });