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(`
|
const { rows: [poMetrics] } = await executeQuery(`
|
||||||
|
WITH po_metrics AS (
|
||||||
SELECT
|
SELECT
|
||||||
COALESCE(COUNT(DISTINCT CASE
|
po_id,
|
||||||
WHEN po.status NOT IN ('canceled', 'done')
|
status,
|
||||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
date,
|
||||||
THEN po.po_id
|
expected_date,
|
||||||
END), 0)::integer as active_pos,
|
pid,
|
||||||
COALESCE(COUNT(DISTINCT CASE
|
ordered,
|
||||||
WHEN po.status NOT IN ('canceled', 'done')
|
po_cost_price
|
||||||
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
|
FROM purchase_orders po
|
||||||
|
WHERE po.status NOT IN ('canceled', 'done')
|
||||||
|
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
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
|
JOIN product_metrics pm ON po.pid = pm.pid
|
||||||
`);
|
`);
|
||||||
|
|
||||||
const { rows: vendorOrders } = await executeQuery(`
|
const { rows: vendorOrders } = await executeQuery(`
|
||||||
|
WITH po_by_vendor AS (
|
||||||
SELECT
|
SELECT
|
||||||
po.vendor,
|
vendor,
|
||||||
COUNT(DISTINCT po.po_id)::integer as orders,
|
po_id,
|
||||||
COALESCE(SUM(po.ordered), 0)::integer as units,
|
SUM(ordered) as total_ordered,
|
||||||
ROUND(COALESCE(SUM(po.ordered * po.po_cost_price), 0)::numeric, 3) as cost,
|
SUM(ordered * po_cost_price) as total_cost
|
||||||
ROUND(COALESCE(SUM(po.ordered * pm.current_price), 0)::numeric, 3) as retail
|
FROM purchase_orders
|
||||||
FROM purchase_orders po
|
WHERE status NOT IN ('canceled', 'done')
|
||||||
|
AND date >= CURRENT_DATE - INTERVAL '6 months'
|
||||||
|
GROUP BY vendor, po_id
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
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
|
JOIN product_metrics pm ON po.pid = pm.pid
|
||||||
WHERE po.status NOT IN ('canceled', 'done')
|
GROUP BY pv.vendor
|
||||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
HAVING ROUND(SUM(pv.total_cost)::numeric, 3) > 0
|
||||||
GROUP BY po.vendor
|
|
||||||
HAVING ROUND(COALESCE(SUM(po.ordered * po.po_cost_price), 0)::numeric, 3) > 0
|
|
||||||
ORDER BY cost DESC
|
ORDER BY cost DESC
|
||||||
`);
|
`);
|
||||||
|
|
||||||
|
|||||||
@@ -11,7 +11,12 @@ const STATUS = {
|
|||||||
PREORDERED: 12,
|
PREORDERED: 12,
|
||||||
ELECTRONICALLY_SENT: 13,
|
ELECTRONICALLY_SENT: 13,
|
||||||
RECEIVING_STARTED: 15,
|
RECEIVING_STARTED: 15,
|
||||||
DONE: 50
|
DONE: 50,
|
||||||
|
// Receiving status codes
|
||||||
|
RECEIVING_CREATED: 1,
|
||||||
|
RECEIVING_PARTIAL: 30,
|
||||||
|
RECEIVING_FULL: 40,
|
||||||
|
RECEIVING_PAID: 50
|
||||||
};
|
};
|
||||||
|
|
||||||
// Status mapping from database string values to frontend numeric codes
|
// Status mapping from database string values to frontend numeric codes
|
||||||
@@ -23,7 +28,11 @@ const STATUS_MAPPING = {
|
|||||||
'preordered': STATUS.PREORDERED,
|
'preordered': STATUS.PREORDERED,
|
||||||
'electronically_sent': STATUS.ELECTRONICALLY_SENT,
|
'electronically_sent': STATUS.ELECTRONICALLY_SENT,
|
||||||
'receiving_started': STATUS.RECEIVING_STARTED,
|
'receiving_started': STATUS.RECEIVING_STARTED,
|
||||||
'done': STATUS.DONE
|
'done': STATUS.DONE,
|
||||||
|
// Receiving status mappings
|
||||||
|
'partial_received': STATUS.RECEIVING_PARTIAL,
|
||||||
|
'full_received': STATUS.RECEIVING_FULL,
|
||||||
|
'paid': STATUS.RECEIVING_PAID
|
||||||
};
|
};
|
||||||
|
|
||||||
// Helper for SQL status value comparison with string values in DB
|
// Helper for SQL status value comparison with string values in DB
|
||||||
@@ -41,7 +50,18 @@ function getStatusWhereClause(statusNum) {
|
|||||||
router.get('/', async (req, res) => {
|
router.get('/', async (req, res) => {
|
||||||
try {
|
try {
|
||||||
const pool = req.app.locals.pool;
|
const pool = req.app.locals.pool;
|
||||||
const { search, status, vendor, startDate, endDate, page = 1, limit = 100, sortColumn = 'date', sortDirection = 'desc' } = req.query;
|
const {
|
||||||
|
search,
|
||||||
|
status,
|
||||||
|
vendor,
|
||||||
|
recordType,
|
||||||
|
startDate,
|
||||||
|
endDate,
|
||||||
|
page = 1,
|
||||||
|
limit = 100,
|
||||||
|
sortColumn = 'id',
|
||||||
|
sortDirection = 'desc'
|
||||||
|
} = req.query;
|
||||||
|
|
||||||
let whereClause = '1=1';
|
let whereClause = '1=1';
|
||||||
const params = [];
|
const params = [];
|
||||||
@@ -88,13 +108,11 @@ router.get('/', async (req, res) => {
|
|||||||
),
|
),
|
||||||
receiving_totals AS (
|
receiving_totals AS (
|
||||||
SELECT
|
SELECT
|
||||||
r.receiving_id,
|
r.receiving_id as po_id,
|
||||||
po.po_id,
|
|
||||||
SUM(r.qty_each) as total_received
|
SUM(r.qty_each) as total_received
|
||||||
FROM receivings r
|
FROM receivings r
|
||||||
JOIN purchase_orders po ON r.pid = po.pid
|
WHERE r.receiving_id IN (SELECT po_id FROM po_totals)
|
||||||
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
GROUP BY r.receiving_id
|
||||||
GROUP BY r.receiving_id, po.po_id
|
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
COUNT(DISTINCT po.po_id) as order_count,
|
COUNT(DISTINCT po.po_id) as order_count,
|
||||||
@@ -109,42 +127,120 @@ router.get('/', async (req, res) => {
|
|||||||
LEFT JOIN receiving_totals r ON po.po_id = r.po_id
|
LEFT JOIN receiving_totals r ON po.po_id = r.po_id
|
||||||
`, params);
|
`, params);
|
||||||
|
|
||||||
// Get total count for pagination
|
// Get total count for pagination (including both POs and receivings without POs)
|
||||||
const { rows: [countResult] } = await pool.query(`
|
let countQuery = `
|
||||||
SELECT COUNT(DISTINCT po_id) as total
|
WITH po_count AS (
|
||||||
|
SELECT COUNT(DISTINCT po_id) as po_count
|
||||||
FROM purchase_orders po
|
FROM purchase_orders po
|
||||||
WHERE ${whereClause}
|
WHERE ${whereClause}
|
||||||
`, params);
|
),
|
||||||
|
receiving_count AS (
|
||||||
|
SELECT COUNT(DISTINCT receiving_id) as r_count
|
||||||
|
FROM receivings r
|
||||||
|
WHERE receiving_id NOT IN (
|
||||||
|
SELECT po_id FROM purchase_orders po WHERE ${whereClause}
|
||||||
|
)
|
||||||
|
)`;
|
||||||
|
|
||||||
|
// Adjust count query based on record type filter
|
||||||
|
if (recordType && recordType !== 'all') {
|
||||||
|
if (recordType === 'po_only') {
|
||||||
|
countQuery = `
|
||||||
|
WITH po_count AS (
|
||||||
|
SELECT COUNT(DISTINCT po.po_id) as po_count
|
||||||
|
FROM purchase_orders po
|
||||||
|
LEFT JOIN (
|
||||||
|
SELECT DISTINCT receiving_id
|
||||||
|
FROM receivings
|
||||||
|
) r ON po.po_id = r.receiving_id
|
||||||
|
WHERE ${whereClause} AND r.receiving_id IS NULL
|
||||||
|
),
|
||||||
|
receiving_count AS (
|
||||||
|
SELECT 0 as r_count
|
||||||
|
)`;
|
||||||
|
} else if (recordType === 'po_with_receiving') {
|
||||||
|
countQuery = `
|
||||||
|
WITH po_count AS (
|
||||||
|
SELECT COUNT(DISTINCT po.po_id) as po_count
|
||||||
|
FROM purchase_orders po
|
||||||
|
INNER JOIN (
|
||||||
|
SELECT DISTINCT receiving_id
|
||||||
|
FROM receivings
|
||||||
|
) r ON po.po_id = r.receiving_id
|
||||||
|
WHERE ${whereClause}
|
||||||
|
),
|
||||||
|
receiving_count AS (
|
||||||
|
SELECT 0 as r_count
|
||||||
|
)`;
|
||||||
|
} else if (recordType === 'receiving_only') {
|
||||||
|
countQuery = `
|
||||||
|
WITH po_count AS (
|
||||||
|
SELECT 0 as po_count
|
||||||
|
),
|
||||||
|
receiving_count AS (
|
||||||
|
SELECT COUNT(DISTINCT receiving_id) as r_count
|
||||||
|
FROM receivings r
|
||||||
|
WHERE receiving_id NOT IN (
|
||||||
|
SELECT po_id FROM purchase_orders po WHERE ${whereClause}
|
||||||
|
)
|
||||||
|
)`;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
countQuery += `
|
||||||
|
SELECT (SELECT po_count FROM po_count) + (SELECT r_count FROM receiving_count) as total
|
||||||
|
`;
|
||||||
|
|
||||||
|
const { rows: [countResult] } = await pool.query(countQuery, params);
|
||||||
|
|
||||||
const total = countResult.total;
|
const total = countResult.total;
|
||||||
const offset = (page - 1) * limit;
|
const offset = (page - 1) * limit;
|
||||||
const pages = Math.ceil(total / limit);
|
const pages = Math.ceil(total / limit);
|
||||||
|
|
||||||
// Get recent purchase orders
|
// Set default sorting for id to ensure consistent ordering
|
||||||
let orderByClause;
|
const defaultSortColumn = sortColumn || 'id';
|
||||||
|
const defaultSortDirection = sortDirection || 'desc';
|
||||||
|
|
||||||
if (sortColumn === 'order_date') {
|
// Get recent purchase orders - build the base query
|
||||||
orderByClause = `date ${sortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
let orderByClause = '';
|
||||||
} else if (sortColumn === 'vendor_name') {
|
|
||||||
orderByClause = `vendor ${sortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
// Special sorting that ensures receiving_only records are included with any date sorting
|
||||||
} else if (sortColumn === 'total_cost') {
|
if (defaultSortColumn === 'order_date' || defaultSortColumn === 'date') {
|
||||||
orderByClause = `total_cost ${sortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
// Make sure to include receivings (which have NULL order_date) by using a CASE statement
|
||||||
} else if (sortColumn === 'total_received') {
|
orderByClause = `
|
||||||
orderByClause = `total_received ${sortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
CASE
|
||||||
} else if (sortColumn === 'total_items') {
|
WHEN order_date IS NULL THEN
|
||||||
orderByClause = `total_items ${sortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
CASE WHEN receiving_date IS NOT NULL THEN
|
||||||
} else if (sortColumn === 'total_quantity') {
|
to_date(receiving_date, 'YYYY-MM-DD')
|
||||||
orderByClause = `total_quantity ${sortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
ELSE
|
||||||
} else if (sortColumn === 'fulfillment_rate') {
|
'1900-01-01'::date
|
||||||
orderByClause = `fulfillment_rate ${sortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
END
|
||||||
} else if (sortColumn === 'status') {
|
ELSE
|
||||||
orderByClause = `status ${sortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
to_date(order_date, 'YYYY-MM-DD')
|
||||||
|
END ${defaultSortDirection === 'desc' ? 'DESC' : 'ASC'}
|
||||||
|
`;
|
||||||
|
} else if (defaultSortColumn === 'vendor_name') {
|
||||||
|
orderByClause = `vendor_name ${defaultSortDirection === 'desc' ? 'DESC NULLS LAST' : 'ASC NULLS FIRST'}`;
|
||||||
|
} else if (defaultSortColumn === 'total_cost') {
|
||||||
|
orderByClause = `total_cost ${defaultSortDirection === 'desc' ? 'DESC NULLS LAST' : 'ASC NULLS FIRST'}`;
|
||||||
|
} else if (defaultSortColumn === 'total_received') {
|
||||||
|
orderByClause = `total_received ${defaultSortDirection === 'desc' ? 'DESC NULLS LAST' : 'ASC NULLS FIRST'}`;
|
||||||
|
} else if (defaultSortColumn === 'total_items') {
|
||||||
|
orderByClause = `total_items ${defaultSortDirection === 'desc' ? 'DESC NULLS LAST' : 'ASC NULLS FIRST'}`;
|
||||||
|
} else if (defaultSortColumn === 'total_quantity') {
|
||||||
|
orderByClause = `total_quantity ${defaultSortDirection === 'desc' ? 'DESC NULLS LAST' : 'ASC NULLS FIRST'}`;
|
||||||
|
} else if (defaultSortColumn === 'fulfillment_rate') {
|
||||||
|
orderByClause = `fulfillment_rate ${defaultSortDirection === 'desc' ? 'DESC NULLS LAST' : 'ASC NULLS FIRST'}`;
|
||||||
|
} else if (defaultSortColumn === 'status') {
|
||||||
|
orderByClause = `status ${defaultSortDirection === 'desc' ? 'DESC NULLS LAST' : 'ASC NULLS FIRST'}`;
|
||||||
} else {
|
} else {
|
||||||
orderByClause = `date ${sortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
// Default to ID sorting if no valid column is specified
|
||||||
|
orderByClause = `id::bigint ${defaultSortDirection === 'desc' ? 'DESC' : 'ASC'}`;
|
||||||
}
|
}
|
||||||
|
|
||||||
const { rows: orders } = await pool.query(`
|
// Simplified combined query approach to ensure all record types are included
|
||||||
WITH po_totals AS (
|
let orderQuery = `
|
||||||
|
WITH po_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
po_id,
|
po_id,
|
||||||
vendor,
|
vendor,
|
||||||
@@ -152,37 +248,79 @@ router.get('/', async (req, res) => {
|
|||||||
status,
|
status,
|
||||||
COUNT(DISTINCT pid) as total_items,
|
COUNT(DISTINCT pid) as total_items,
|
||||||
SUM(ordered) as total_quantity,
|
SUM(ordered) as total_quantity,
|
||||||
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost
|
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost,
|
||||||
|
MAX(notes) as short_note
|
||||||
FROM purchase_orders po
|
FROM purchase_orders po
|
||||||
WHERE ${whereClause}
|
WHERE ${whereClause}
|
||||||
GROUP BY po_id, vendor, date, status
|
GROUP BY po_id, vendor, date, status
|
||||||
),
|
),
|
||||||
receiving_totals AS (
|
receiving_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
po.po_id,
|
r.receiving_id,
|
||||||
SUM(r.qty_each) as total_received
|
MAX(r.received_date) as receiving_date,
|
||||||
|
r.vendor as receiving_vendor,
|
||||||
|
COUNT(DISTINCT r.pid) as total_items,
|
||||||
|
SUM(r.qty_each) as total_received,
|
||||||
|
ROUND(SUM(r.qty_each * r.cost_each)::numeric, 3) as total_cost,
|
||||||
|
MAX(r.status) as receiving_status
|
||||||
FROM receivings r
|
FROM receivings r
|
||||||
JOIN purchase_orders po ON r.pid = po.pid
|
GROUP BY r.receiving_id, r.vendor
|
||||||
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
),
|
||||||
GROUP BY po.po_id
|
all_data AS (
|
||||||
)
|
-- Get all unique IDs from both tables
|
||||||
|
SELECT DISTINCT po_id as id FROM po_data
|
||||||
|
UNION
|
||||||
|
SELECT DISTINCT receiving_id as id FROM receiving_data
|
||||||
|
${recordType === 'po_only' ?
|
||||||
|
'EXCEPT SELECT DISTINCT receiving_id as id FROM receiving_data' :
|
||||||
|
recordType === 'po_with_receiving' ?
|
||||||
|
'INTERSECT SELECT DISTINCT receiving_id as id FROM receiving_data' :
|
||||||
|
recordType === 'receiving_only' ?
|
||||||
|
'EXCEPT SELECT DISTINCT po_id as id FROM po_data' :
|
||||||
|
'' // No additional clause for 'all'
|
||||||
|
}
|
||||||
|
),
|
||||||
|
combined_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
pt.po_id as id,
|
a.id,
|
||||||
pt.vendor as vendor_name,
|
COALESCE(po.vendor, r.receiving_vendor) as vendor_name,
|
||||||
to_char(pt.date, 'YYYY-MM-DD') as order_date,
|
to_char(po.date, 'YYYY-MM-DD') as order_date,
|
||||||
pt.status,
|
to_char(r.receiving_date, 'YYYY-MM-DD') as receiving_date,
|
||||||
pt.total_items,
|
CASE
|
||||||
pt.total_quantity,
|
WHEN po.po_id IS NULL THEN r.receiving_status
|
||||||
pt.total_cost,
|
ELSE po.status
|
||||||
COALESCE(rt.total_received, 0) as total_received,
|
END as status,
|
||||||
ROUND(
|
COALESCE(po.total_items, r.total_items, 0) as total_items,
|
||||||
(COALESCE(rt.total_received, 0)::numeric / NULLIF(pt.total_quantity, 0)), 3
|
COALESCE(po.total_quantity, 0) as total_quantity,
|
||||||
) as fulfillment_rate
|
COALESCE(po.total_cost, r.total_cost, 0) as total_cost,
|
||||||
FROM po_totals pt
|
COALESCE(r.total_received, 0) as total_received,
|
||||||
LEFT JOIN receiving_totals rt ON pt.po_id = rt.po_id
|
CASE
|
||||||
ORDER BY ${orderByClause}
|
WHEN po.po_id IS NULL THEN 1
|
||||||
|
WHEN r.receiving_id IS NULL THEN 0
|
||||||
|
ELSE ROUND((r.total_received::numeric / NULLIF(po.total_quantity, 0)), 3)
|
||||||
|
END as fulfillment_rate,
|
||||||
|
po.short_note,
|
||||||
|
CASE
|
||||||
|
WHEN po.po_id IS NULL THEN 'receiving_only'
|
||||||
|
WHEN r.receiving_id IS NULL THEN 'po_only'
|
||||||
|
ELSE 'po_with_receiving'
|
||||||
|
END as record_type
|
||||||
|
FROM all_data a
|
||||||
|
LEFT JOIN po_data po ON a.id = po.po_id
|
||||||
|
LEFT JOIN receiving_data r ON a.id = r.receiving_id
|
||||||
|
${
|
||||||
|
recordType === 'po_only' ? 'WHERE po.po_id IS NOT NULL AND r.receiving_id IS NULL' :
|
||||||
|
recordType === 'po_with_receiving' ? 'WHERE po.po_id IS NOT NULL AND r.receiving_id IS NOT NULL' :
|
||||||
|
recordType === 'receiving_only' ? 'WHERE po.po_id IS NULL AND r.receiving_id IS NOT NULL' :
|
||||||
|
'' // No WHERE clause for 'all'
|
||||||
|
}
|
||||||
|
)
|
||||||
|
SELECT * FROM combined_data
|
||||||
|
ORDER BY ${orderByClause}, id::bigint DESC
|
||||||
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
|
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
|
||||||
`, [...params, Number(limit), offset]);
|
`;
|
||||||
|
|
||||||
|
const { rows: orders } = await pool.query(orderQuery, [...params, Number(limit), offset]);
|
||||||
|
|
||||||
// Get unique vendors for filter options
|
// Get unique vendors for filter options
|
||||||
const { rows: vendors } = await pool.query(`
|
const { rows: vendors } = await pool.query(`
|
||||||
@@ -224,17 +362,32 @@ router.get('/', async (req, res) => {
|
|||||||
}
|
}
|
||||||
|
|
||||||
// Parse numeric values and map status strings to numeric codes
|
// Parse numeric values and map status strings to numeric codes
|
||||||
const parsedOrders = orders.map(order => ({
|
const parsedOrders = orders.map(order => {
|
||||||
|
// Special handling for status mapping
|
||||||
|
let statusCode;
|
||||||
|
if (order.record_type === 'receiving_only') {
|
||||||
|
// For receiving-only records, use receiving status codes
|
||||||
|
statusCode = STATUS_MAPPING[order.status] || 0;
|
||||||
|
} else {
|
||||||
|
// For PO records, use PO status codes
|
||||||
|
statusCode = STATUS_MAPPING[order.status] || 0;
|
||||||
|
}
|
||||||
|
|
||||||
|
return {
|
||||||
id: order.id,
|
id: order.id,
|
||||||
vendor_name: vendorMappings[order.id] || order.vendor_name,
|
vendor_name: vendorMappings[order.id] || order.vendor_name,
|
||||||
order_date: order.order_date,
|
order_date: order.order_date,
|
||||||
status: STATUS_MAPPING[order.status] || 0, // Map string status to numeric code
|
receiving_date: order.receiving_date,
|
||||||
|
status: statusCode,
|
||||||
total_items: Number(order.total_items) || 0,
|
total_items: Number(order.total_items) || 0,
|
||||||
total_quantity: Number(order.total_quantity) || 0,
|
total_quantity: Number(order.total_quantity) || 0,
|
||||||
total_cost: Number(order.total_cost) || 0,
|
total_cost: Number(order.total_cost) || 0,
|
||||||
total_received: Number(order.total_received) || 0,
|
total_received: Number(order.total_received) || 0,
|
||||||
fulfillment_rate: Number(order.fulfillment_rate) || 0
|
fulfillment_rate: Number(order.fulfillment_rate) || 0,
|
||||||
}));
|
short_note: order.short_note,
|
||||||
|
record_type: order.record_type
|
||||||
|
};
|
||||||
|
});
|
||||||
|
|
||||||
// Parse summary metrics
|
// Parse summary metrics
|
||||||
const parsedSummary = {
|
const parsedSummary = {
|
||||||
@@ -276,40 +429,39 @@ router.get('/vendor-metrics', async (req, res) => {
|
|||||||
SELECT
|
SELECT
|
||||||
vendor,
|
vendor,
|
||||||
po_id,
|
po_id,
|
||||||
ordered,
|
SUM(ordered) as total_ordered,
|
||||||
po_cost_price,
|
AVG(po_cost_price) as avg_cost_price,
|
||||||
date
|
MAX(date) as po_date
|
||||||
FROM purchase_orders
|
FROM purchase_orders
|
||||||
WHERE vendor IS NOT NULL AND vendor != ''
|
WHERE vendor IS NOT NULL AND vendor != ''
|
||||||
AND status != 'canceled' -- Exclude canceled orders
|
AND status != 'canceled' -- Exclude canceled orders
|
||||||
|
GROUP BY vendor, po_id
|
||||||
),
|
),
|
||||||
receiving_data AS (
|
receiving_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
po.po_id,
|
r.receiving_id as po_id,
|
||||||
po.vendor,
|
SUM(r.qty_each) as total_received,
|
||||||
r.pid,
|
MIN(r.received_date) as first_received_date
|
||||||
r.qty_each as received,
|
|
||||||
r.received_date
|
|
||||||
FROM receivings r
|
FROM receivings r
|
||||||
JOIN purchase_orders po ON r.pid = po.pid
|
JOIN purchase_orders po ON r.receiving_id = po.po_id
|
||||||
WHERE po.vendor IS NOT NULL AND po.vendor != ''
|
WHERE po.vendor IS NOT NULL AND po.vendor != ''
|
||||||
AND po.status != 'canceled'
|
AND po.status != 'canceled'
|
||||||
|
GROUP BY r.receiving_id
|
||||||
),
|
),
|
||||||
delivery_metrics AS (
|
delivery_metrics AS (
|
||||||
SELECT
|
SELECT
|
||||||
po.vendor,
|
po.vendor,
|
||||||
po.po_id,
|
po.po_id,
|
||||||
po.ordered,
|
po.total_ordered as ordered,
|
||||||
COALESCE(SUM(r.received), 0) as received,
|
COALESCE(r.total_received, 0) as received,
|
||||||
po.po_cost_price,
|
po.avg_cost_price as po_cost_price,
|
||||||
CASE
|
CASE
|
||||||
WHEN MIN(r.received_date) IS NOT NULL AND po.date IS NOT NULL
|
WHEN r.first_received_date IS NOT NULL AND po.po_date IS NOT NULL
|
||||||
THEN (MIN(r.received_date) - po.date)::integer
|
THEN EXTRACT(DAY FROM (r.first_received_date - po.po_date))
|
||||||
ELSE NULL
|
ELSE NULL
|
||||||
END as delivery_days
|
END as delivery_days
|
||||||
FROM po_data po
|
FROM po_data po
|
||||||
LEFT JOIN receiving_data r ON po.po_id = r.po_id
|
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
|
SELECT
|
||||||
vendor as vendor_name,
|
vendor as vendor_name,
|
||||||
@@ -428,6 +580,119 @@ router.get('/cost-analysis', async (req, res) => {
|
|||||||
}
|
}
|
||||||
});
|
});
|
||||||
|
|
||||||
|
// New endpoint for yearly category spending analysis based on receivings
|
||||||
|
router.get('/category-analysis', async (req, res) => {
|
||||||
|
try {
|
||||||
|
const pool = req.app.locals.pool;
|
||||||
|
|
||||||
|
// Allow an optional "since" parameter or default to 1 year ago
|
||||||
|
const since = req.query.since || new Date(Date.now() - 365 * 24 * 60 * 60 * 1000).toISOString().split('T')[0];
|
||||||
|
|
||||||
|
const { rows: analysis } = await pool.query(`
|
||||||
|
WITH receiving_costs AS (
|
||||||
|
SELECT
|
||||||
|
c.name as category,
|
||||||
|
r.pid,
|
||||||
|
r.cost_each as received_cost,
|
||||||
|
r.qty_each as received_qty,
|
||||||
|
r.received_date
|
||||||
|
FROM receivings r
|
||||||
|
JOIN product_categories pc ON r.pid = pc.pid
|
||||||
|
JOIN categories c ON pc.cat_id = c.cat_id
|
||||||
|
WHERE r.received_date >= $1::date
|
||||||
|
AND r.qty_each > 0 -- Only consider actual received quantities
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
category,
|
||||||
|
COUNT(DISTINCT pid) as unique_products,
|
||||||
|
ROUND(AVG(received_cost)::numeric, 3) as avg_cost,
|
||||||
|
ROUND(MIN(received_cost)::numeric, 3) as min_cost,
|
||||||
|
ROUND(MAX(received_cost)::numeric, 3) as max_cost,
|
||||||
|
ROUND(STDDEV(received_cost)::numeric, 3) as cost_variance,
|
||||||
|
ROUND(SUM(received_qty * received_cost)::numeric, 3) as total_spend
|
||||||
|
FROM receiving_costs
|
||||||
|
GROUP BY category
|
||||||
|
ORDER BY total_spend DESC
|
||||||
|
`, [since]);
|
||||||
|
|
||||||
|
// Parse numeric values
|
||||||
|
const parsedAnalysis = analysis.map(cat => ({
|
||||||
|
category: cat.category,
|
||||||
|
unique_products: Number(cat.unique_products) || 0,
|
||||||
|
avg_cost: Number(cat.avg_cost) || 0,
|
||||||
|
min_cost: Number(cat.min_cost) || 0,
|
||||||
|
max_cost: Number(cat.max_cost) || 0,
|
||||||
|
cost_variance: Number(cat.cost_variance) || 0,
|
||||||
|
total_spend: Number(cat.total_spend) || 0
|
||||||
|
}));
|
||||||
|
|
||||||
|
res.json(parsedAnalysis);
|
||||||
|
} catch (error) {
|
||||||
|
console.error('Error fetching category analysis:', error);
|
||||||
|
res.status(500).json({ error: 'Failed to fetch category analysis' });
|
||||||
|
}
|
||||||
|
});
|
||||||
|
|
||||||
|
// New endpoint for yearly vendor spending analysis based on receivings
|
||||||
|
router.get('/vendor-analysis', async (req, res) => {
|
||||||
|
try {
|
||||||
|
const pool = req.app.locals.pool;
|
||||||
|
|
||||||
|
// Allow an optional "since" parameter or default to 1 year ago
|
||||||
|
const since = req.query.since || new Date(Date.now() - 365 * 24 * 60 * 60 * 1000).toISOString().split('T')[0];
|
||||||
|
|
||||||
|
const { rows: metrics } = await pool.query(`
|
||||||
|
WITH receiving_data AS (
|
||||||
|
SELECT
|
||||||
|
r.vendor,
|
||||||
|
r.receiving_id,
|
||||||
|
r.pid,
|
||||||
|
r.qty_each,
|
||||||
|
r.cost_each,
|
||||||
|
r.received_date
|
||||||
|
FROM receivings r
|
||||||
|
WHERE r.received_date >= $1::date
|
||||||
|
AND r.qty_each > 0 -- Only consider actual received quantities
|
||||||
|
),
|
||||||
|
receiving_totals AS (
|
||||||
|
SELECT
|
||||||
|
vendor,
|
||||||
|
receiving_id,
|
||||||
|
COUNT(DISTINCT pid) as unique_products,
|
||||||
|
SUM(qty_each) as total_received,
|
||||||
|
SUM(qty_each * cost_each) as total_spend
|
||||||
|
FROM receiving_data
|
||||||
|
GROUP BY vendor, receiving_id
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
vendor,
|
||||||
|
COUNT(DISTINCT receiving_id) as orders,
|
||||||
|
ROUND(SUM(total_spend)::numeric, 3) as total_spend,
|
||||||
|
SUM(total_received) as total_received,
|
||||||
|
SUM(unique_products) as total_items
|
||||||
|
FROM receiving_totals
|
||||||
|
WHERE vendor IS NOT NULL AND vendor != ''
|
||||||
|
GROUP BY vendor
|
||||||
|
HAVING COUNT(DISTINCT receiving_id) > 0
|
||||||
|
ORDER BY total_spend DESC
|
||||||
|
`, [since]);
|
||||||
|
|
||||||
|
// Parse numeric values
|
||||||
|
const parsedMetrics = metrics.map(vendor => ({
|
||||||
|
vendor: vendor.vendor,
|
||||||
|
orders: Number(vendor.orders) || 0,
|
||||||
|
total_spend: Number(vendor.total_spend) || 0,
|
||||||
|
total_received: Number(vendor.total_received) || 0,
|
||||||
|
total_items: Number(vendor.total_items) || 0
|
||||||
|
}));
|
||||||
|
|
||||||
|
res.json(parsedMetrics);
|
||||||
|
} catch (error) {
|
||||||
|
console.error('Error fetching vendor analysis:', error);
|
||||||
|
res.status(500).json({ error: 'Failed to fetch vendor analysis' });
|
||||||
|
}
|
||||||
|
});
|
||||||
|
|
||||||
// Get order status metrics
|
// Get order status metrics
|
||||||
router.get('/receiving-status', async (req, res) => {
|
router.get('/receiving-status', async (req, res) => {
|
||||||
try {
|
try {
|
||||||
@@ -449,33 +714,42 @@ router.get('/receiving-status', async (req, res) => {
|
|||||||
po.po_id,
|
po.po_id,
|
||||||
SUM(r.qty_each) as total_received
|
SUM(r.qty_each) as total_received
|
||||||
FROM receivings r
|
FROM receivings r
|
||||||
JOIN purchase_orders po ON r.pid = po.pid
|
JOIN purchase_orders po ON r.pid = po.pid AND r.sku = po.sku
|
||||||
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
||||||
GROUP BY po.po_id
|
GROUP BY po.po_id
|
||||||
)
|
),
|
||||||
|
combined_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
COUNT(DISTINCT po.po_id) as order_count,
|
po.po_id,
|
||||||
SUM(po.total_ordered) as total_ordered,
|
po.status,
|
||||||
COALESCE(SUM(r.total_received), 0) as total_received,
|
po.total_ordered,
|
||||||
ROUND(
|
po.total_cost,
|
||||||
COALESCE(SUM(r.total_received), 0) / NULLIF(SUM(po.total_ordered), 0), 3
|
COALESCE(r.total_received, 0) as total_received
|
||||||
) as fulfillment_rate,
|
|
||||||
ROUND(SUM(po.total_cost)::numeric, 3) as total_value,
|
|
||||||
ROUND(AVG(po.total_cost)::numeric, 3) as avg_cost,
|
|
||||||
COUNT(DISTINCT CASE
|
|
||||||
WHEN po.status = 'created' THEN po.po_id
|
|
||||||
END) as pending_count,
|
|
||||||
COUNT(DISTINCT CASE
|
|
||||||
WHEN po.status = 'receiving_started' THEN po.po_id
|
|
||||||
END) as partial_count,
|
|
||||||
COUNT(DISTINCT CASE
|
|
||||||
WHEN po.status = 'done' THEN po.po_id
|
|
||||||
END) as completed_count,
|
|
||||||
COUNT(DISTINCT CASE
|
|
||||||
WHEN po.status = 'canceled' THEN po.po_id
|
|
||||||
END) as canceled_count
|
|
||||||
FROM po_totals po
|
FROM po_totals po
|
||||||
LEFT JOIN receiving_totals r ON po.po_id = r.po_id
|
LEFT JOIN receiving_totals r ON po.po_id = r.po_id
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
COUNT(DISTINCT po_id) as order_count,
|
||||||
|
SUM(total_ordered) as total_ordered,
|
||||||
|
SUM(total_received) as total_received,
|
||||||
|
ROUND(
|
||||||
|
SUM(total_received) / NULLIF(SUM(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,
|
||||||
|
COUNT(DISTINCT CASE
|
||||||
|
WHEN status = 'created' THEN po_id
|
||||||
|
END) as pending_count,
|
||||||
|
COUNT(DISTINCT CASE
|
||||||
|
WHEN status = 'receiving_started' THEN po_id
|
||||||
|
END) as partial_count,
|
||||||
|
COUNT(DISTINCT CASE
|
||||||
|
WHEN status = 'done' THEN po_id
|
||||||
|
END) as completed_count,
|
||||||
|
COUNT(DISTINCT CASE
|
||||||
|
WHEN status = 'canceled' THEN po_id
|
||||||
|
END) as canceled_count
|
||||||
|
FROM combined_data
|
||||||
`);
|
`);
|
||||||
|
|
||||||
// Parse numeric values
|
// Parse numeric values
|
||||||
@@ -524,7 +798,7 @@ router.get('/order-vs-received', async (req, res) => {
|
|||||||
r.pid,
|
r.pid,
|
||||||
SUM(r.qty_each) as received_quantity
|
SUM(r.qty_each) as received_quantity
|
||||||
FROM receivings r
|
FROM receivings r
|
||||||
JOIN products p ON r.pid = p.pid
|
JOIN purchase_orders po ON r.receiving_id = po.po_id
|
||||||
WHERE r.received_date >= (CURRENT_DATE - INTERVAL '90 days')
|
WHERE r.received_date >= (CURRENT_DATE - INTERVAL '90 days')
|
||||||
GROUP BY r.pid
|
GROUP BY r.pid
|
||||||
)
|
)
|
||||||
@@ -540,7 +814,7 @@ router.get('/order-vs-received', async (req, res) => {
|
|||||||
o.order_count
|
o.order_count
|
||||||
FROM order_data o
|
FROM order_data o
|
||||||
LEFT JOIN receiving_data r ON o.pid = r.pid
|
LEFT JOIN receiving_data r ON o.pid = r.pid
|
||||||
HAVING o.order_count > 0
|
WHERE o.order_count > 0
|
||||||
ORDER BY o.ordered_quantity DESC
|
ORDER BY o.ordered_quantity DESC
|
||||||
LIMIT 20
|
LIMIT 20
|
||||||
`);
|
`);
|
||||||
|
|||||||
File diff suppressed because it is too large
Load Diff
@@ -75,7 +75,7 @@ export function getPurchaseOrderStatusVariant(status: number): 'default' | 'seco
|
|||||||
|
|
||||||
export function getReceivingStatusVariant(status: number): 'default' | 'secondary' | 'destructive' | 'outline' {
|
export function getReceivingStatusVariant(status: number): 'default' | 'secondary' | 'destructive' | 'outline' {
|
||||||
if (isReceivingCanceled(status)) return 'destructive';
|
if (isReceivingCanceled(status)) return 'destructive';
|
||||||
if (status === ReceivingStatus.Paid) return 'default';
|
if (status === ReceivingStatus.Paid || status === ReceivingStatus.FullReceived) return 'default';
|
||||||
if (status >= ReceivingStatus.PartialReceived) return 'secondary';
|
if (status >= ReceivingStatus.PartialReceived) return 'secondary';
|
||||||
return 'outline';
|
return 'outline';
|
||||||
}
|
}
|
||||||
Reference in New Issue
Block a user