Tweak layout of purchase orders page and redo header cards
This commit is contained in:
@@ -108,53 +108,52 @@ router.get('/purchase/metrics', async (req, res) => {
|
||||
`);
|
||||
|
||||
const { rows: [poMetrics] } = await executeQuery(`
|
||||
WITH po_metrics AS (
|
||||
SELECT
|
||||
po_id,
|
||||
status,
|
||||
date,
|
||||
expected_date,
|
||||
pid,
|
||||
ordered,
|
||||
po_cost_price
|
||||
FROM purchase_orders po
|
||||
WHERE po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
)
|
||||
SELECT
|
||||
COALESCE(COUNT(DISTINCT CASE
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
THEN po.po_id
|
||||
END), 0)::integer as active_pos,
|
||||
COALESCE(COUNT(DISTINCT CASE
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
AND po.expected_date < CURRENT_DATE
|
||||
THEN po.po_id
|
||||
END), 0)::integer as overdue_pos,
|
||||
COALESCE(SUM(CASE
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
THEN po.ordered
|
||||
ELSE 0
|
||||
END), 0)::integer as total_units,
|
||||
ROUND(COALESCE(SUM(CASE
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
THEN po.ordered * po.po_cost_price
|
||||
ELSE 0
|
||||
END), 0)::numeric, 3) as total_cost,
|
||||
ROUND(COALESCE(SUM(CASE
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
THEN po.ordered * pm.current_price
|
||||
ELSE 0
|
||||
END), 0)::numeric, 3) as total_retail
|
||||
FROM purchase_orders po
|
||||
COUNT(DISTINCT po_id)::integer as active_pos,
|
||||
COUNT(DISTINCT CASE WHEN expected_date < CURRENT_DATE THEN po_id END)::integer as overdue_pos,
|
||||
SUM(ordered)::integer as total_units,
|
||||
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost,
|
||||
ROUND(SUM(ordered * pm.current_price)::numeric, 3) as total_retail
|
||||
FROM po_metrics po
|
||||
JOIN product_metrics pm ON po.pid = pm.pid
|
||||
`);
|
||||
|
||||
const { rows: vendorOrders } = await executeQuery(`
|
||||
WITH po_by_vendor AS (
|
||||
SELECT
|
||||
vendor,
|
||||
po_id,
|
||||
SUM(ordered) as total_ordered,
|
||||
SUM(ordered * po_cost_price) as total_cost
|
||||
FROM purchase_orders
|
||||
WHERE status NOT IN ('canceled', 'done')
|
||||
AND date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
GROUP BY vendor, po_id
|
||||
)
|
||||
SELECT
|
||||
po.vendor,
|
||||
COUNT(DISTINCT po.po_id)::integer as orders,
|
||||
COALESCE(SUM(po.ordered), 0)::integer as units,
|
||||
ROUND(COALESCE(SUM(po.ordered * po.po_cost_price), 0)::numeric, 3) as cost,
|
||||
ROUND(COALESCE(SUM(po.ordered * pm.current_price), 0)::numeric, 3) as retail
|
||||
FROM purchase_orders po
|
||||
pv.vendor,
|
||||
COUNT(DISTINCT pv.po_id)::integer as orders,
|
||||
SUM(pv.total_ordered)::integer as units,
|
||||
ROUND(SUM(pv.total_cost)::numeric, 3) as cost,
|
||||
ROUND(SUM(pv.total_ordered * pm.current_price)::numeric, 3) as retail
|
||||
FROM po_by_vendor pv
|
||||
JOIN purchase_orders po ON pv.po_id = po.po_id
|
||||
JOIN product_metrics pm ON po.pid = pm.pid
|
||||
WHERE po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
GROUP BY po.vendor
|
||||
HAVING ROUND(COALESCE(SUM(po.ordered * po.po_cost_price), 0)::numeric, 3) > 0
|
||||
GROUP BY pv.vendor
|
||||
HAVING ROUND(SUM(pv.total_cost)::numeric, 3) > 0
|
||||
ORDER BY cost DESC
|
||||
`);
|
||||
|
||||
|
||||
Reference in New Issue
Block a user