Rearrange vendors and purchase orders page content, fix pagination
This commit is contained in:
@@ -15,39 +15,43 @@ router.get('/', async (req, res) => {
|
||||
const sortDirection = req.query.sortDirection || 'asc';
|
||||
|
||||
// Build the WHERE clause based on filters
|
||||
const whereConditions = [];
|
||||
const whereConditions = ['p.vendor IS NOT NULL AND p.vendor != \'\''];
|
||||
const params = [];
|
||||
|
||||
if (search) {
|
||||
whereConditions.push('(LOWER(p.vendor) LIKE LOWER(?) OR LOWER(vd.contact_name) LIKE LOWER(?))');
|
||||
params.push(`%${search}%`, `%${search}%`);
|
||||
whereConditions.push('LOWER(p.vendor) LIKE LOWER(?)');
|
||||
params.push(`%${search}%`);
|
||||
}
|
||||
|
||||
if (status !== 'all') {
|
||||
whereConditions.push('vm.status = ?');
|
||||
whereConditions.push(`
|
||||
CASE
|
||||
WHEN COALESCE(vm.total_orders, 0) > 0 AND COALESCE(vm.order_fill_rate, 0) >= 75 THEN 'active'
|
||||
WHEN COALESCE(vm.total_orders, 0) > 0 THEN 'inactive'
|
||||
ELSE 'pending'
|
||||
END = ?
|
||||
`);
|
||||
params.push(status);
|
||||
}
|
||||
|
||||
if (performance !== 'all') {
|
||||
switch (performance) {
|
||||
case 'excellent':
|
||||
whereConditions.push('vm.order_fill_rate >= 95');
|
||||
whereConditions.push('COALESCE(vm.order_fill_rate, 0) >= 95');
|
||||
break;
|
||||
case 'good':
|
||||
whereConditions.push('vm.order_fill_rate >= 85 AND vm.order_fill_rate < 95');
|
||||
whereConditions.push('COALESCE(vm.order_fill_rate, 0) >= 85 AND COALESCE(vm.order_fill_rate, 0) < 95');
|
||||
break;
|
||||
case 'fair':
|
||||
whereConditions.push('vm.order_fill_rate >= 75 AND vm.order_fill_rate < 85');
|
||||
whereConditions.push('COALESCE(vm.order_fill_rate, 0) >= 75 AND COALESCE(vm.order_fill_rate, 0) < 85');
|
||||
break;
|
||||
case 'poor':
|
||||
whereConditions.push('vm.order_fill_rate < 75');
|
||||
whereConditions.push('COALESCE(vm.order_fill_rate, 0) < 75');
|
||||
break;
|
||||
}
|
||||
}
|
||||
|
||||
const whereClause = whereConditions.length > 0
|
||||
? 'WHERE ' + whereConditions.join(' AND ')
|
||||
: '';
|
||||
const whereClause = 'WHERE ' + whereConditions.join(' AND ');
|
||||
|
||||
// Get total count for pagination
|
||||
const [countResult] = await pool.query(`
|
||||
@@ -59,57 +63,105 @@ router.get('/', async (req, res) => {
|
||||
|
||||
// Get vendors with metrics
|
||||
const [vendors] = await pool.query(`
|
||||
SELECT
|
||||
SELECT DISTINCT
|
||||
p.vendor as name,
|
||||
vd.contact_name,
|
||||
vd.email,
|
||||
vd.phone,
|
||||
vm.status,
|
||||
vm.avg_lead_time_days,
|
||||
vm.on_time_delivery_rate,
|
||||
vm.order_fill_rate,
|
||||
vm.total_orders,
|
||||
COUNT(DISTINCT p.product_id) as active_products
|
||||
COALESCE(vm.active_products, 0) as active_products,
|
||||
COALESCE(vm.total_orders, 0) as total_orders,
|
||||
COALESCE(vm.avg_lead_time_days, 0) as avg_lead_time_days,
|
||||
COALESCE(vm.on_time_delivery_rate, 0) as on_time_delivery_rate,
|
||||
COALESCE(vm.order_fill_rate, 0) as order_fill_rate,
|
||||
CASE
|
||||
WHEN COALESCE(vm.total_orders, 0) > 0 AND COALESCE(vm.order_fill_rate, 0) >= 75 THEN 'active'
|
||||
WHEN COALESCE(vm.total_orders, 0) > 0 THEN 'inactive'
|
||||
ELSE 'pending'
|
||||
END as status
|
||||
FROM products p
|
||||
LEFT JOIN vendor_metrics vm ON p.vendor = vm.vendor
|
||||
LEFT JOIN vendor_details vd ON p.vendor = vd.vendor
|
||||
${whereClause}
|
||||
GROUP BY p.vendor
|
||||
AND p.vendor IS NOT NULL AND p.vendor != ''
|
||||
ORDER BY ${sortColumn} ${sortDirection}
|
||||
LIMIT ? OFFSET ?
|
||||
`, [...params, limit, offset]);
|
||||
|
||||
// Get cost metrics for these vendors
|
||||
const vendorNames = vendors.map(v => v.name);
|
||||
const [costMetrics] = await pool.query(`
|
||||
SELECT
|
||||
vendor,
|
||||
ROUND(SUM(ordered * cost_price) / NULLIF(SUM(ordered), 0), 2) as avg_unit_cost,
|
||||
SUM(ordered * cost_price) as total_spend
|
||||
FROM purchase_orders
|
||||
WHERE status = 'closed'
|
||||
AND cost_price IS NOT NULL
|
||||
AND ordered > 0
|
||||
AND vendor IN (?)
|
||||
GROUP BY vendor
|
||||
`, [vendorNames]);
|
||||
|
||||
// Create a map of cost metrics by vendor
|
||||
const costMetricsMap = costMetrics.reduce((acc, curr) => {
|
||||
acc[curr.vendor] = {
|
||||
avg_unit_cost: curr.avg_unit_cost,
|
||||
total_spend: curr.total_spend
|
||||
};
|
||||
return acc;
|
||||
}, {});
|
||||
|
||||
// Get overall stats
|
||||
const [stats] = await pool.query(`
|
||||
SELECT
|
||||
COUNT(DISTINCT p.vendor) as totalVendors,
|
||||
COUNT(DISTINCT CASE WHEN vm.status = 'active' THEN p.vendor END) as activeVendors,
|
||||
COALESCE(ROUND(AVG(NULLIF(vm.avg_lead_time_days, 0)), 1), 0) as avgLeadTime,
|
||||
COALESCE(ROUND(AVG(NULLIF(vm.order_fill_rate, 0)), 1), 0) as avgFillRate,
|
||||
COALESCE(ROUND(AVG(NULLIF(vm.on_time_delivery_rate, 0)), 1), 0) as avgOnTimeDelivery
|
||||
COUNT(DISTINCT CASE
|
||||
WHEN COALESCE(vm.total_orders, 0) > 0 AND COALESCE(vm.order_fill_rate, 0) >= 75
|
||||
THEN p.vendor
|
||||
END) as activeVendors,
|
||||
ROUND(AVG(NULLIF(vm.avg_lead_time_days, 0)), 1) as avgLeadTime,
|
||||
ROUND(AVG(NULLIF(vm.order_fill_rate, 0)), 1) as avgFillRate,
|
||||
ROUND(AVG(NULLIF(vm.on_time_delivery_rate, 0)), 1) as avgOnTimeDelivery
|
||||
FROM products p
|
||||
LEFT JOIN vendor_metrics vm ON p.vendor = vm.vendor
|
||||
WHERE p.vendor IS NOT NULL AND p.vendor != ''
|
||||
`);
|
||||
|
||||
// Get overall cost metrics
|
||||
const [overallCostMetrics] = await pool.query(`
|
||||
SELECT
|
||||
ROUND(SUM(ordered * cost_price) / NULLIF(SUM(ordered), 0), 2) as avg_unit_cost,
|
||||
SUM(ordered * cost_price) as total_spend
|
||||
FROM purchase_orders
|
||||
WHERE status = 'closed'
|
||||
AND cost_price IS NOT NULL
|
||||
AND ordered > 0
|
||||
AND vendor IS NOT NULL AND vendor != ''
|
||||
`);
|
||||
|
||||
res.json({
|
||||
vendors: vendors.map(vendor => ({
|
||||
...vendor,
|
||||
vendor_id: vendor.vendor_id || vendor.name,
|
||||
name: vendor.name,
|
||||
status: vendor.status,
|
||||
avg_lead_time_days: parseFloat(vendor.avg_lead_time_days || 0),
|
||||
on_time_delivery_rate: parseFloat(vendor.on_time_delivery_rate || 0),
|
||||
order_fill_rate: parseFloat(vendor.order_fill_rate || 0),
|
||||
total_orders: parseInt(vendor.total_orders || 0),
|
||||
active_products: parseInt(vendor.active_products || 0)
|
||||
active_products: parseInt(vendor.active_products || 0),
|
||||
avg_unit_cost: parseFloat(costMetricsMap[vendor.name]?.avg_unit_cost || 0),
|
||||
total_spend: parseFloat(costMetricsMap[vendor.name]?.total_spend || 0)
|
||||
})),
|
||||
stats: {
|
||||
...stats[0],
|
||||
totalVendors: parseInt(stats[0].totalVendors || 0),
|
||||
activeVendors: parseInt(stats[0].activeVendors || 0),
|
||||
avgLeadTime: parseFloat(stats[0].avgLeadTime || 0),
|
||||
avgFillRate: parseFloat(stats[0].avgFillRate || 0),
|
||||
avgOnTimeDelivery: parseFloat(stats[0].avgOnTimeDelivery || 0)
|
||||
avgOnTimeDelivery: parseFloat(stats[0].avgOnTimeDelivery || 0),
|
||||
avgUnitCost: parseFloat(overallCostMetrics[0].avg_unit_cost || 0),
|
||||
totalSpend: parseFloat(overallCostMetrics[0].total_spend || 0)
|
||||
},
|
||||
pagination: {
|
||||
total: countResult[0].total,
|
||||
pages: Math.ceil(countResult[0].total / limit),
|
||||
current: page,
|
||||
total: parseInt(countResult[0].total || 0),
|
||||
currentPage: page,
|
||||
pages: Math.ceil(parseInt(countResult[0].total || 0) / limit),
|
||||
limit
|
||||
}
|
||||
});
|
||||
} catch (error) {
|
||||
|
||||
Reference in New Issue
Block a user