Update calculate scripts and routes for PO table split
This commit is contained in:
@@ -110,36 +110,31 @@ router.get('/purchase/metrics', async (req, res) => {
|
||||
const { rows: [poMetrics] } = await executeQuery(`
|
||||
SELECT
|
||||
COALESCE(COUNT(DISTINCT CASE
|
||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
||||
THEN po.po_id
|
||||
END), 0)::integer as active_pos,
|
||||
COALESCE(COUNT(DISTINCT CASE
|
||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
||||
AND po.expected_date < CURRENT_DATE
|
||||
THEN po.po_id
|
||||
END), 0)::integer as overdue_pos,
|
||||
COALESCE(SUM(CASE
|
||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
||||
THEN po.ordered
|
||||
ELSE 0
|
||||
END), 0)::integer as total_units,
|
||||
ROUND(COALESCE(SUM(CASE
|
||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
||||
THEN po.ordered * po.cost_price
|
||||
THEN po.ordered * po.po_cost_price
|
||||
ELSE 0
|
||||
END), 0)::numeric, 3) as total_cost,
|
||||
ROUND(COALESCE(SUM(CASE
|
||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
||||
WHEN po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
||||
THEN po.ordered * pm.current_price
|
||||
ELSE 0
|
||||
END), 0)::numeric, 3) as total_retail
|
||||
@@ -152,15 +147,14 @@ router.get('/purchase/metrics', async (req, res) => {
|
||||
po.vendor,
|
||||
COUNT(DISTINCT po.po_id)::integer as orders,
|
||||
COALESCE(SUM(po.ordered), 0)::integer as units,
|
||||
ROUND(COALESCE(SUM(po.ordered * po.cost_price), 0)::numeric, 3) as cost,
|
||||
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
|
||||
JOIN product_metrics pm ON po.pid = pm.pid
|
||||
WHERE po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
||||
WHERE po.status NOT IN ('canceled', 'done')
|
||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
||||
GROUP BY po.vendor
|
||||
HAVING ROUND(COALESCE(SUM(po.ordered * po.cost_price), 0)::numeric, 3) > 0
|
||||
HAVING ROUND(COALESCE(SUM(po.ordered * po.po_cost_price), 0)::numeric, 3) > 0
|
||||
ORDER BY cost DESC
|
||||
`);
|
||||
|
||||
|
||||
@@ -26,23 +26,6 @@ const STATUS_MAPPING = {
|
||||
'done': STATUS.DONE
|
||||
};
|
||||
|
||||
const RECEIVING_STATUS = {
|
||||
CANCELED: 0,
|
||||
CREATED: 1,
|
||||
PARTIAL_RECEIVED: 30,
|
||||
FULL_RECEIVED: 40,
|
||||
PAID: 50
|
||||
};
|
||||
|
||||
// Receiving status mapping from database string values to frontend numeric codes
|
||||
const RECEIVING_STATUS_MAPPING = {
|
||||
'canceled': RECEIVING_STATUS.CANCELED,
|
||||
'created': RECEIVING_STATUS.CREATED,
|
||||
'partial_received': RECEIVING_STATUS.PARTIAL_RECEIVED,
|
||||
'full_received': RECEIVING_STATUS.FULL_RECEIVED,
|
||||
'paid': RECEIVING_STATUS.PAID
|
||||
};
|
||||
|
||||
// Helper for SQL status value comparison with string values in DB
|
||||
function getStatusWhereClause(statusNum) {
|
||||
const dbStatuses = Object.keys(STATUS_MAPPING).filter(key =>
|
||||
@@ -98,22 +81,32 @@ router.get('/', async (req, res) => {
|
||||
SELECT
|
||||
po_id,
|
||||
SUM(ordered) as total_ordered,
|
||||
SUM(received) as total_received,
|
||||
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_cost
|
||||
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost
|
||||
FROM purchase_orders po
|
||||
WHERE ${whereClause}
|
||||
GROUP BY po_id
|
||||
),
|
||||
receiving_totals AS (
|
||||
SELECT
|
||||
r.receiving_id,
|
||||
po.po_id,
|
||||
SUM(r.qty_each) as total_received
|
||||
FROM receivings r
|
||||
JOIN purchase_orders po ON r.pid = po.pid
|
||||
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
||||
GROUP BY r.receiving_id, po.po_id
|
||||
)
|
||||
SELECT
|
||||
COUNT(DISTINCT po_id) as order_count,
|
||||
SUM(total_ordered) as total_ordered,
|
||||
SUM(total_received) as total_received,
|
||||
COUNT(DISTINCT po.po_id) as order_count,
|
||||
SUM(po.total_ordered) as total_ordered,
|
||||
COALESCE(SUM(r.total_received), 0) as total_received,
|
||||
ROUND(
|
||||
(SUM(total_received)::numeric / NULLIF(SUM(total_ordered), 0)), 3
|
||||
(COALESCE(SUM(r.total_received), 0)::numeric / NULLIF(SUM(po.total_ordered), 0)), 3
|
||||
) as fulfillment_rate,
|
||||
ROUND(SUM(total_cost)::numeric, 3) as total_value,
|
||||
ROUND(AVG(total_cost)::numeric, 3) as avg_cost
|
||||
FROM po_totals
|
||||
ROUND(SUM(po.total_cost)::numeric, 3) as total_value,
|
||||
ROUND(AVG(po.total_cost)::numeric, 3) as avg_cost
|
||||
FROM po_totals po
|
||||
LEFT JOIN receiving_totals r ON po.po_id = r.po_id
|
||||
`, params);
|
||||
|
||||
// Get total count for pagination
|
||||
@@ -157,30 +150,36 @@ router.get('/', async (req, res) => {
|
||||
vendor,
|
||||
date,
|
||||
status,
|
||||
receiving_status,
|
||||
COUNT(DISTINCT pid) as total_items,
|
||||
SUM(ordered) as total_quantity,
|
||||
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_cost,
|
||||
SUM(received) as total_received,
|
||||
ROUND(
|
||||
(SUM(received)::numeric / NULLIF(SUM(ordered), 0)), 3
|
||||
) as fulfillment_rate
|
||||
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost
|
||||
FROM purchase_orders po
|
||||
WHERE ${whereClause}
|
||||
GROUP BY po_id, vendor, date, status, receiving_status
|
||||
GROUP BY po_id, vendor, date, status
|
||||
),
|
||||
receiving_totals AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
SUM(r.qty_each) as total_received
|
||||
FROM receivings r
|
||||
JOIN purchase_orders po ON r.pid = po.pid
|
||||
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
||||
GROUP BY po.po_id
|
||||
)
|
||||
SELECT
|
||||
pt.po_id as id,
|
||||
pt.vendor as vendor_name,
|
||||
to_char(pt.date, 'YYYY-MM-DD') as order_date,
|
||||
pt.status,
|
||||
pt.receiving_status,
|
||||
pt.total_items,
|
||||
pt.total_quantity,
|
||||
pt.total_cost,
|
||||
pt.total_received,
|
||||
pt.fulfillment_rate
|
||||
COALESCE(rt.total_received, 0) as total_received,
|
||||
ROUND(
|
||||
(COALESCE(rt.total_received, 0)::numeric / NULLIF(pt.total_quantity, 0)), 3
|
||||
) as fulfillment_rate
|
||||
FROM po_totals pt
|
||||
LEFT JOIN receiving_totals rt ON pt.po_id = rt.po_id
|
||||
ORDER BY ${orderByClause}
|
||||
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
|
||||
`, [...params, Number(limit), offset]);
|
||||
@@ -230,7 +229,6 @@ router.get('/', async (req, res) => {
|
||||
vendor_name: vendorMappings[order.id] || order.vendor_name,
|
||||
order_date: order.order_date,
|
||||
status: STATUS_MAPPING[order.status] || 0, // Map string status to numeric code
|
||||
receiving_status: RECEIVING_STATUS_MAPPING[order.receiving_status] || 0, // Map string receiving status to numeric code
|
||||
total_items: Number(order.total_items) || 0,
|
||||
total_quantity: Number(order.total_quantity) || 0,
|
||||
total_cost: Number(order.total_cost) || 0,
|
||||
@@ -274,23 +272,44 @@ router.get('/vendor-metrics', async (req, res) => {
|
||||
const pool = req.app.locals.pool;
|
||||
|
||||
const { rows: metrics } = await pool.query(`
|
||||
WITH delivery_metrics AS (
|
||||
WITH po_data AS (
|
||||
SELECT
|
||||
vendor,
|
||||
po_id,
|
||||
ordered,
|
||||
received,
|
||||
cost_price,
|
||||
CASE
|
||||
WHEN status IN ('receiving_started', 'done')
|
||||
AND receiving_status IN ('partial_received', 'full_received', 'paid')
|
||||
AND received_date IS NOT NULL AND date IS NOT NULL
|
||||
THEN (received_date - date)::integer
|
||||
ELSE NULL
|
||||
END as delivery_days
|
||||
po_cost_price,
|
||||
date
|
||||
FROM purchase_orders
|
||||
WHERE vendor IS NOT NULL AND vendor != ''
|
||||
AND status != 'canceled' -- Exclude canceled orders
|
||||
),
|
||||
receiving_data AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.vendor,
|
||||
r.pid,
|
||||
r.qty_each as received,
|
||||
r.received_date
|
||||
FROM receivings r
|
||||
JOIN purchase_orders po ON r.pid = po.pid
|
||||
WHERE po.vendor IS NOT NULL AND po.vendor != ''
|
||||
AND po.status != 'canceled'
|
||||
),
|
||||
delivery_metrics AS (
|
||||
SELECT
|
||||
po.vendor,
|
||||
po.po_id,
|
||||
po.ordered,
|
||||
COALESCE(SUM(r.received), 0) as received,
|
||||
po.po_cost_price,
|
||||
CASE
|
||||
WHEN MIN(r.received_date) IS NOT NULL AND po.date IS NOT NULL
|
||||
THEN (MIN(r.received_date) - po.date)::integer
|
||||
ELSE NULL
|
||||
END as delivery_days
|
||||
FROM po_data po
|
||||
LEFT JOIN receiving_data r ON po.po_id = r.po_id
|
||||
GROUP BY po.vendor, po.po_id, po.ordered, po.po_cost_price, po.date
|
||||
)
|
||||
SELECT
|
||||
vendor as vendor_name,
|
||||
@@ -301,9 +320,9 @@ router.get('/vendor-metrics', async (req, res) => {
|
||||
(SUM(received)::numeric / NULLIF(SUM(ordered), 0)), 3
|
||||
) as fulfillment_rate,
|
||||
ROUND(
|
||||
(SUM(ordered * cost_price)::numeric / NULLIF(SUM(ordered), 0)), 2
|
||||
(SUM(ordered * po_cost_price)::numeric / NULLIF(SUM(ordered), 0)), 2
|
||||
) as avg_unit_cost,
|
||||
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_spend,
|
||||
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_spend,
|
||||
ROUND(
|
||||
AVG(NULLIF(delivery_days, 0))::numeric, 1
|
||||
) as avg_delivery_days
|
||||
@@ -343,11 +362,9 @@ router.get('/cost-analysis', async (req, res) => {
|
||||
SELECT
|
||||
c.name as category,
|
||||
po.pid,
|
||||
po.cost_price,
|
||||
po.po_cost_price as cost_price,
|
||||
po.ordered,
|
||||
po.received,
|
||||
po.status,
|
||||
po.receiving_status
|
||||
po.status
|
||||
FROM purchase_orders po
|
||||
JOIN product_categories pc ON po.pid = pc.pid
|
||||
JOIN categories c ON pc.cat_id = c.cat_id
|
||||
@@ -411,7 +428,7 @@ router.get('/cost-analysis', async (req, res) => {
|
||||
}
|
||||
});
|
||||
|
||||
// Get receiving status metrics
|
||||
// Get order status metrics
|
||||
router.get('/receiving-status', async (req, res) => {
|
||||
try {
|
||||
const pool = req.app.locals.pool;
|
||||
@@ -421,36 +438,44 @@ router.get('/receiving-status', async (req, res) => {
|
||||
SELECT
|
||||
po_id,
|
||||
status,
|
||||
receiving_status,
|
||||
SUM(ordered) as total_ordered,
|
||||
SUM(received) as total_received,
|
||||
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_cost
|
||||
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost
|
||||
FROM purchase_orders
|
||||
WHERE status != 'canceled'
|
||||
GROUP BY po_id, status, receiving_status
|
||||
GROUP BY po_id, status
|
||||
),
|
||||
receiving_totals AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
SUM(r.qty_each) as total_received
|
||||
FROM receivings r
|
||||
JOIN purchase_orders po ON r.pid = po.pid
|
||||
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
||||
GROUP BY po.po_id
|
||||
)
|
||||
SELECT
|
||||
COUNT(DISTINCT po_id) as order_count,
|
||||
SUM(total_ordered) as total_ordered,
|
||||
SUM(total_received) as total_received,
|
||||
COUNT(DISTINCT po.po_id) as order_count,
|
||||
SUM(po.total_ordered) as total_ordered,
|
||||
COALESCE(SUM(r.total_received), 0) as total_received,
|
||||
ROUND(
|
||||
SUM(total_received) / NULLIF(SUM(total_ordered), 0), 3
|
||||
COALESCE(SUM(r.total_received), 0) / NULLIF(SUM(po.total_ordered), 0), 3
|
||||
) as fulfillment_rate,
|
||||
ROUND(SUM(total_cost)::numeric, 3) as total_value,
|
||||
ROUND(AVG(total_cost)::numeric, 3) as avg_cost,
|
||||
ROUND(SUM(po.total_cost)::numeric, 3) as total_value,
|
||||
ROUND(AVG(po.total_cost)::numeric, 3) as avg_cost,
|
||||
COUNT(DISTINCT CASE
|
||||
WHEN receiving_status = 'created' THEN po_id
|
||||
WHEN po.status = 'created' THEN po.po_id
|
||||
END) as pending_count,
|
||||
COUNT(DISTINCT CASE
|
||||
WHEN receiving_status = 'partial_received' THEN po_id
|
||||
WHEN po.status = 'receiving_started' THEN po.po_id
|
||||
END) as partial_count,
|
||||
COUNT(DISTINCT CASE
|
||||
WHEN receiving_status IN ('full_received', 'paid') THEN po_id
|
||||
WHEN po.status = 'done' THEN po.po_id
|
||||
END) as completed_count,
|
||||
COUNT(DISTINCT CASE
|
||||
WHEN receiving_status = 'canceled' THEN po_id
|
||||
WHEN po.status = 'canceled' THEN po.po_id
|
||||
END) as canceled_count
|
||||
FROM po_totals
|
||||
FROM po_totals po
|
||||
LEFT JOIN receiving_totals r ON po.po_id = r.po_id
|
||||
`);
|
||||
|
||||
// Parse numeric values
|
||||
@@ -482,22 +507,41 @@ router.get('/order-vs-received', async (req, res) => {
|
||||
const pool = req.app.locals.pool;
|
||||
|
||||
const { rows: quantities } = await pool.query(`
|
||||
WITH order_data AS (
|
||||
SELECT
|
||||
p.pid,
|
||||
p.title,
|
||||
p.SKU,
|
||||
SUM(po.ordered) as ordered_quantity,
|
||||
COUNT(DISTINCT po.po_id) as order_count
|
||||
FROM products p
|
||||
JOIN purchase_orders po ON p.pid = po.pid
|
||||
WHERE po.date >= (CURRENT_DATE - INTERVAL '90 days')
|
||||
GROUP BY p.pid, p.title, p.SKU
|
||||
),
|
||||
receiving_data AS (
|
||||
SELECT
|
||||
r.pid,
|
||||
SUM(r.qty_each) as received_quantity
|
||||
FROM receivings r
|
||||
JOIN products p ON r.pid = p.pid
|
||||
WHERE r.received_date >= (CURRENT_DATE - INTERVAL '90 days')
|
||||
GROUP BY r.pid
|
||||
)
|
||||
SELECT
|
||||
p.pid as product_id,
|
||||
p.title as product,
|
||||
p.SKU as sku,
|
||||
SUM(po.ordered) as ordered_quantity,
|
||||
SUM(po.received) as received_quantity,
|
||||
o.pid as product_id,
|
||||
o.title as product,
|
||||
o.SKU as sku,
|
||||
o.ordered_quantity,
|
||||
COALESCE(r.received_quantity, 0) as received_quantity,
|
||||
ROUND(
|
||||
SUM(po.received) / NULLIF(SUM(po.ordered), 0) * 100, 1
|
||||
COALESCE(r.received_quantity, 0) / NULLIF(o.ordered_quantity, 0) * 100, 1
|
||||
) as fulfillment_rate,
|
||||
COUNT(DISTINCT po.po_id) as order_count
|
||||
FROM products p
|
||||
JOIN purchase_orders po ON p.pid = po.pid
|
||||
WHERE po.date >= (CURRENT_DATE - INTERVAL '90 days')
|
||||
GROUP BY p.pid, p.title, p.SKU
|
||||
HAVING COUNT(DISTINCT po.po_id) > 0
|
||||
ORDER BY SUM(po.ordered) DESC
|
||||
o.order_count
|
||||
FROM order_data o
|
||||
LEFT JOIN receiving_data r ON o.pid = r.pid
|
||||
HAVING o.order_count > 0
|
||||
ORDER BY o.ordered_quantity DESC
|
||||
LIMIT 20
|
||||
`);
|
||||
|
||||
|
||||
Reference in New Issue
Block a user