Add PO details accordion to purchase orders page
This commit is contained in:
@@ -966,6 +966,164 @@ router.get('/order-vs-received', async (req, res) => {
|
||||
}
|
||||
});
|
||||
|
||||
// Get purchase order items
|
||||
router.get('/:id/items', async (req, res) => {
|
||||
try {
|
||||
const pool = req.app.locals.pool;
|
||||
const { id } = req.params;
|
||||
|
||||
if (!id) {
|
||||
return res.status(400).json({ error: 'Purchase order ID is required' });
|
||||
}
|
||||
|
||||
// Query to get purchase order items with product details
|
||||
const { rows: items } = await pool.query(`
|
||||
WITH po_items AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
po.sku,
|
||||
COALESCE(po.name, p.title) as product_name,
|
||||
po.po_cost_price,
|
||||
po.ordered,
|
||||
po.status
|
||||
FROM purchase_orders po
|
||||
LEFT JOIN products p ON po.pid = p.pid
|
||||
WHERE po.po_id = $1
|
||||
),
|
||||
receiving_items AS (
|
||||
SELECT
|
||||
r.receiving_id,
|
||||
r.pid,
|
||||
r.sku,
|
||||
SUM(r.qty_each) as received
|
||||
FROM receivings r
|
||||
WHERE r.receiving_id = $1
|
||||
GROUP BY r.receiving_id, r.pid, r.sku
|
||||
)
|
||||
SELECT
|
||||
pi.po_id as id,
|
||||
pi.pid,
|
||||
pi.sku,
|
||||
pi.product_name,
|
||||
p.barcode,
|
||||
pi.po_cost_price,
|
||||
pi.ordered,
|
||||
COALESCE(ri.received, 0) as received,
|
||||
ROUND(pi.ordered * pi.po_cost_price, 2) as total_cost,
|
||||
CASE
|
||||
WHEN ri.received IS NULL THEN 'Not Received'
|
||||
WHEN ri.received = 0 THEN 'Not Received'
|
||||
WHEN ri.received < pi.ordered THEN 'Partially Received'
|
||||
WHEN ri.received >= pi.ordered THEN 'Fully Received'
|
||||
END as receiving_status
|
||||
FROM po_items pi
|
||||
LEFT JOIN receiving_items ri ON pi.pid = ri.pid AND pi.sku = ri.sku
|
||||
LEFT JOIN products p ON pi.pid = p.pid
|
||||
ORDER BY pi.product_name
|
||||
`, [id]);
|
||||
|
||||
// Parse numeric values
|
||||
const parsedItems = items.map(item => ({
|
||||
id: `${item.id}_${item.pid}`,
|
||||
pid: item.pid,
|
||||
product_name: item.product_name,
|
||||
sku: item.sku,
|
||||
upc: item.barcode || 'N/A',
|
||||
ordered: Number(item.ordered) || 0,
|
||||
received: Number(item.received) || 0,
|
||||
po_cost_price: Number(item.po_cost_price) || 0,
|
||||
total_cost: Number(item.total_cost) || 0,
|
||||
receiving_status: item.receiving_status
|
||||
}));
|
||||
|
||||
res.json(parsedItems);
|
||||
} catch (error) {
|
||||
console.error('Error fetching purchase order items:', error);
|
||||
res.status(500).json({ error: 'Failed to fetch purchase order items', details: error.message });
|
||||
}
|
||||
});
|
||||
|
||||
// Get receiving items
|
||||
router.get('/receiving/:id/items', async (req, res) => {
|
||||
try {
|
||||
const pool = req.app.locals.pool;
|
||||
const { id } = req.params;
|
||||
|
||||
if (!id) {
|
||||
return res.status(400).json({ error: 'Receiving ID is required' });
|
||||
}
|
||||
|
||||
// Query to get receiving items with related PO information if available
|
||||
const { rows: items } = await pool.query(`
|
||||
WITH receiving_items AS (
|
||||
SELECT
|
||||
r.receiving_id,
|
||||
r.pid,
|
||||
r.sku,
|
||||
COALESCE(r.name, p.title) as product_name,
|
||||
r.cost_each,
|
||||
r.qty_each,
|
||||
r.status
|
||||
FROM receivings r
|
||||
LEFT JOIN products p ON r.pid = p.pid
|
||||
WHERE r.receiving_id = $1
|
||||
),
|
||||
po_items AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
po.sku,
|
||||
po.ordered,
|
||||
po.po_cost_price
|
||||
FROM purchase_orders po
|
||||
WHERE po.po_id = $1
|
||||
)
|
||||
SELECT
|
||||
ri.receiving_id as id,
|
||||
ri.pid,
|
||||
ri.sku,
|
||||
ri.product_name,
|
||||
p.barcode,
|
||||
COALESCE(po.ordered, 0) as ordered,
|
||||
ri.qty_each as received,
|
||||
COALESCE(po.po_cost_price, ri.cost_each) as po_cost_price,
|
||||
ri.cost_each,
|
||||
ROUND(ri.qty_each * ri.cost_each, 2) as total_cost,
|
||||
CASE
|
||||
WHEN po.ordered IS NULL THEN 'Receiving Only'
|
||||
WHEN ri.qty_each < po.ordered THEN 'Partially Received'
|
||||
WHEN ri.qty_each >= po.ordered THEN 'Fully Received'
|
||||
END as receiving_status
|
||||
FROM receiving_items ri
|
||||
LEFT JOIN po_items po ON ri.pid = po.pid AND ri.sku = po.sku
|
||||
LEFT JOIN products p ON ri.pid = p.pid
|
||||
ORDER BY ri.product_name
|
||||
`, [id]);
|
||||
|
||||
// Parse numeric values
|
||||
const parsedItems = items.map(item => ({
|
||||
id: `${item.id}_${item.pid}`,
|
||||
pid: item.pid,
|
||||
product_name: item.product_name,
|
||||
sku: item.sku,
|
||||
upc: item.barcode || 'N/A',
|
||||
ordered: Number(item.ordered) || 0,
|
||||
received: Number(item.received) || 0,
|
||||
po_cost_price: Number(item.po_cost_price) || 0,
|
||||
cost_each: Number(item.cost_each) || 0,
|
||||
qty_each: Number(item.received) || 0,
|
||||
total_cost: Number(item.total_cost) || 0,
|
||||
receiving_status: item.receiving_status
|
||||
}));
|
||||
|
||||
res.json(parsedItems);
|
||||
} catch (error) {
|
||||
console.error('Error fetching receiving items:', error);
|
||||
res.status(500).json({ error: 'Failed to fetch receiving items', details: error.message });
|
||||
}
|
||||
});
|
||||
|
||||
// New endpoint for delivery metrics
|
||||
router.get('/delivery-metrics', async (req, res) => {
|
||||
try {
|
||||
|
||||
Reference in New Issue
Block a user