Fix filtering/sorting/pagination for purchase orders

This commit is contained in:
2025-04-13 23:51:09 -04:00
parent eeff5817ea
commit 8dd852dd6a
2 changed files with 511 additions and 283 deletions

View File

@@ -50,60 +50,106 @@ function getStatusWhereClause(statusNum) {
router.get('/', async (req, res) => {
try {
const pool = req.app.locals.pool;
// Parse query parameters with defaults
const {
search,
status,
vendor,
recordType,
startDate,
endDate,
search = '',
status = 'all',
vendor = 'all',
recordType = 'all',
startDate = null,
endDate = null,
page = 1,
limit = 100,
sortColumn = 'id',
sortDirection = 'desc'
} = req.query;
let whereClause = '1=1';
console.log("Received query parameters:", {
search, status, vendor, recordType, page, limit, sortColumn, sortDirection
});
// Base where clause for purchase orders
let poWhereClause = '1=1';
// Base where clause for receivings (used in the receiving_data CTE)
let receivingWhereClause = '1=1';
const params = [];
let paramCounter = 1;
if (search) {
whereClause += ` AND (po.po_id ILIKE $${paramCounter} OR po.vendor ILIKE $${paramCounter})`;
params.push(`%${search}%`);
if (search && search.trim() !== '') {
// Simplified search for purchase orders - improved performance
const searchTerm = `%${search.trim()}%`;
poWhereClause += ` AND (
po.po_id::text ILIKE $${paramCounter}
OR po.vendor ILIKE $${paramCounter}
OR po.notes ILIKE $${paramCounter}
)`;
params.push(searchTerm);
paramCounter++;
// Add search for receivings
receivingWhereClause += ` AND (
r.receiving_id::text ILIKE $${paramCounter}
OR r.vendor ILIKE $${paramCounter}
)`;
params.push(searchTerm);
paramCounter++;
}
if (status && status !== 'all') {
whereClause += ` AND ${getStatusWhereClause(status)}`;
poWhereClause += ` AND ${getStatusWhereClause(status)}`;
// Handle status for receivings
const dbStatuses = Object.keys(STATUS_MAPPING).filter(key =>
STATUS_MAPPING[key] === parseInt(status));
if (dbStatuses.length > 0) {
receivingWhereClause += ` AND r.status = '${dbStatuses[0]}'`;
}
}
if (vendor && vendor !== 'all') {
whereClause += ` AND po.vendor = $${paramCounter}`;
poWhereClause += ` AND po.vendor = $${paramCounter}`;
params.push(vendor);
paramCounter++;
// Add vendor filter for receivings
receivingWhereClause += ` AND r.vendor = $${paramCounter}`;
params.push(vendor);
paramCounter++;
}
if (startDate) {
whereClause += ` AND po.date >= $${paramCounter}`;
poWhereClause += ` AND po.date >= $${paramCounter}::date`;
params.push(startDate);
paramCounter++;
// Add date filter for receivings
receivingWhereClause += ` AND r.received_date >= $${paramCounter}::date`;
params.push(startDate);
paramCounter++;
}
if (endDate) {
whereClause += ` AND po.date <= $${paramCounter}`;
poWhereClause += ` AND po.date <= $${paramCounter}::date`;
params.push(endDate);
paramCounter++;
// Add date filter for receivings
receivingWhereClause += ` AND r.received_date <= $${paramCounter}::date`;
params.push(endDate);
paramCounter++;
}
// Get filtered summary metrics
const { rows: [summary] } = await pool.query(`
const summaryQuery = `
WITH po_totals AS (
SELECT
po_id,
SUM(ordered) as total_ordered,
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost
FROM purchase_orders po
WHERE ${whereClause}
WHERE ${poWhereClause}
GROUP BY po_id
),
receiving_totals AS (
@@ -111,102 +157,143 @@ router.get('/', async (req, res) => {
r.receiving_id as po_id,
SUM(r.qty_each) as total_received
FROM receivings r
WHERE r.receiving_id IN (SELECT po_id FROM po_totals)
WHERE (${receivingWhereClause})
AND r.receiving_id IN (SELECT po_id FROM po_totals)
GROUP BY r.receiving_id
)
SELECT
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(
(COALESCE(SUM(r.total_received), 0)::numeric / NULLIF(SUM(po.total_ordered), 0)), 3
) as fulfillment_rate,
CASE
WHEN SUM(po.total_ordered) > 0
THEN ROUND((COALESCE(SUM(r.total_received), 0)::numeric / SUM(po.total_ordered)), 3)
ELSE 0
END as fulfillment_rate,
ROUND(SUM(po.total_cost)::numeric, 3) as total_value,
ROUND(AVG(po.total_cost)::numeric, 3) as avg_cost
CASE
WHEN COUNT(DISTINCT po.po_id) > 0
THEN ROUND(AVG(po.total_cost)::numeric, 3)
ELSE 0
END 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 (including both POs and receivings without POs)
let countQuery = `
WITH po_count AS (
SELECT COUNT(DISTINCT po_id) as po_count
FROM purchase_orders po
WHERE ${whereClause}
),
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: [summary] } = await pool.query(summaryQuery, params);
// Prepare query based on record type filter to get correct counts
let countQuery = '';
if (recordType === 'po_only') {
countQuery = `
WITH po_data AS (
SELECT po_id
FROM purchase_orders po
WHERE ${poWhereClause}
GROUP BY po_id
),
receiving_data AS (
SELECT receiving_id
FROM receivings r
WHERE ${receivingWhereClause}
GROUP BY receiving_id
),
filtered_data AS (
SELECT DISTINCT po_id as id
FROM po_data
WHERE po_id NOT IN (SELECT receiving_id FROM receiving_data WHERE receiving_id IS NOT NULL)
)
SELECT COUNT(*) as total FROM filtered_data
`;
} else if (recordType === 'po_with_receiving') {
countQuery = `
WITH po_data AS (
SELECT po_id
FROM purchase_orders po
WHERE ${poWhereClause}
GROUP BY po_id
),
receiving_data AS (
SELECT receiving_id
FROM receivings r
WHERE ${receivingWhereClause}
GROUP BY receiving_id
),
filtered_data AS (
SELECT DISTINCT po_id as id
FROM po_data
WHERE po_id IN (SELECT receiving_id FROM receiving_data WHERE receiving_id IS NOT NULL)
)
SELECT COUNT(*) as total FROM filtered_data
`;
} else if (recordType === 'receiving_only') {
countQuery = `
WITH po_data AS (
SELECT po_id
FROM purchase_orders po
WHERE ${poWhereClause}
GROUP BY po_id
),
receiving_data AS (
SELECT receiving_id
FROM receivings r
WHERE ${receivingWhereClause}
GROUP BY receiving_id
),
filtered_data AS (
SELECT DISTINCT receiving_id as id
FROM receiving_data
WHERE receiving_id NOT IN (SELECT po_id FROM po_data WHERE po_id IS NOT NULL)
)
SELECT COUNT(*) as total FROM filtered_data
`;
} else {
// 'all' - count both purchase orders and receiving-only records
countQuery = `
WITH po_data AS (
SELECT po_id
FROM purchase_orders po
WHERE ${poWhereClause}
GROUP BY po_id
),
receiving_data AS (
SELECT receiving_id
FROM receivings r
WHERE ${receivingWhereClause}
GROUP BY receiving_id
),
filtered_data AS (
SELECT DISTINCT po_id as id FROM po_data
UNION
SELECT DISTINCT receiving_id as id FROM receiving_data
WHERE receiving_id NOT IN (SELECT po_id FROM po_data WHERE po_id IS NOT NULL)
)
SELECT COUNT(*) as total FROM filtered_data
`;
}
const { rows: [countResult] } = await pool.query(countQuery, params);
const total = countResult.total;
const offset = (page - 1) * limit;
const pages = Math.ceil(total / limit);
// Parse parameters safely
const parsedPage = parseInt(page) || 1;
const parsedLimit = parseInt(limit) || 100;
const total = parseInt(countResult?.total) || 0;
const offset = (parsedPage - 1) * parsedLimit;
const pages = Math.ceil(total / parsedLimit);
// Set default sorting for id to ensure consistent ordering
const defaultSortColumn = sortColumn || 'id';
const defaultSortDirection = sortDirection || 'desc';
// Validated sort parameters
const validSortColumns = ['id', 'vendor_name', 'order_date', 'receiving_date',
'status', 'total_cost', 'total_items', 'total_quantity', 'total_received', 'fulfillment_rate'];
const finalSortColumn = validSortColumns.includes(sortColumn) ? sortColumn : 'id';
const finalSortDirection = sortDirection === 'asc' ? 'asc' : 'desc';
// Get recent purchase orders - build the base query
// Build the order by clause with improved null handling
let orderByClause = '';
// Special sorting that ensures receiving_only records are included with any date sorting
if (defaultSortColumn === 'order_date' || defaultSortColumn === 'date') {
// Make sure to include receivings (which have NULL order_date) by using a CASE statement
if (finalSortColumn === 'order_date' || finalSortColumn === 'date') {
orderByClause = `
CASE
WHEN order_date IS NULL THEN
@@ -217,28 +304,43 @@ router.get('/', async (req, res) => {
END
ELSE
to_date(order_date, 'YYYY-MM-DD')
END ${defaultSortDirection === 'desc' ? 'DESC' : 'ASC'}
END ${finalSortDirection === 'desc' ? 'DESC' : 'ASC'}
`;
} else if (finalSortColumn === 'receiving_date') {
orderByClause = `
CASE WHEN receiving_date IS NULL THEN
'1900-01-01'::date
ELSE
to_date(receiving_date, 'YYYY-MM-DD')
END ${finalSortDirection === 'desc' ? 'DESC' : 'ASC'}
`;
} else if (finalSortColumn === 'vendor_name') {
orderByClause = `vendor_name ${finalSortDirection === 'desc' ? 'DESC NULLS LAST' : 'ASC NULLS FIRST'}`;
} else if (finalSortColumn === 'total_cost' || finalSortColumn === 'total_received' ||
finalSortColumn === 'total_items' || finalSortColumn === 'total_quantity' || finalSortColumn === 'fulfillment_rate') {
orderByClause = `COALESCE(${finalSortColumn}, 0) ${finalSortDirection === 'desc' ? 'DESC' : 'ASC'}`;
} else if (finalSortColumn === 'status') {
// For status sorting, first convert to numeric values for consistent sorting
orderByClause = `
CASE
WHEN status = 'canceled' THEN 0
WHEN status = 'created' THEN 1
WHEN status = 'electronically_ready_send' THEN 10
WHEN status = 'ordered' THEN 11
WHEN status = 'receiving_started' THEN 15
WHEN status = 'done' THEN 50
WHEN status = 'partial_received' THEN 30
WHEN status = 'full_received' THEN 40
WHEN status = 'paid' THEN 50
ELSE 999
END ${finalSortDirection === '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 {
// Default to ID sorting if no valid column is specified
orderByClause = `id::bigint ${defaultSortDirection === 'desc' ? 'DESC' : 'ASC'}`;
// Default to ID sorting
orderByClause = `id::text::bigint ${finalSortDirection === 'desc' ? 'DESC' : 'ASC'}`;
}
// Simplified combined query approach to ensure all record types are included
// Main query to get purchase orders and receivings
let orderQuery = `
WITH po_data AS (
SELECT
@@ -251,7 +353,7 @@ router.get('/', async (req, res) => {
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost,
MAX(notes) as short_note
FROM purchase_orders po
WHERE ${whereClause}
WHERE ${poWhereClause}
GROUP BY po_id, vendor, date, status
),
receiving_data AS (
@@ -264,23 +366,46 @@ router.get('/', async (req, res) => {
ROUND(SUM(r.qty_each * r.cost_each)::numeric, 3) as total_cost,
MAX(r.status) as receiving_status
FROM receivings r
WHERE ${receivingWhereClause}
GROUP BY r.receiving_id, r.vendor
),
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 (
)`;
// Add appropriate record type filtering based on the filter value
if (recordType === 'po_only') {
orderQuery += `,
all_data AS (
SELECT DISTINCT po_id as id
FROM po_data
WHERE po_id NOT IN (SELECT receiving_id FROM receiving_data WHERE receiving_id IS NOT NULL)
)`;
} else if (recordType === 'po_with_receiving') {
orderQuery += `,
all_data AS (
SELECT DISTINCT po_id as id
FROM po_data
WHERE po_id IN (SELECT receiving_id FROM receiving_data WHERE receiving_id IS NOT NULL)
)`;
} else if (recordType === 'receiving_only') {
orderQuery += `,
all_data AS (
SELECT DISTINCT receiving_id as id
FROM receiving_data
WHERE receiving_id NOT IN (SELECT po_id FROM po_data WHERE po_id IS NOT NULL)
)`;
} else {
// 'all' - include all records
orderQuery += `,
all_data AS (
SELECT DISTINCT po_id as id FROM po_data
UNION
SELECT DISTINCT receiving_id as id FROM receiving_data
WHERE receiving_id NOT IN (SELECT po_id FROM po_data WHERE po_id IS NOT NULL)
)`;
}
// Complete the query with combined data and ordering
orderQuery += `
,combined_data AS (
SELECT
a.id,
COALESCE(po.vendor, r.receiving_vendor) as vendor_name,
@@ -297,7 +422,8 @@ router.get('/', async (req, res) => {
CASE
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)
WHEN po.total_quantity = 0 THEN 0
ELSE ROUND((r.total_received::numeric / po.total_quantity), 3)
END as fulfillment_rate,
po.short_note,
CASE
@@ -308,25 +434,23 @@ router.get('/', async (req, res) => {
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
ORDER BY ${orderByClause}, id::text::bigint DESC
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
`;
const { rows: orders } = await pool.query(orderQuery, [...params, Number(limit), offset]);
const { rows: orders } = await pool.query(orderQuery, [...params, parsedLimit, offset]);
// Get unique vendors for filter options
const { rows: vendors } = await pool.query(`
SELECT DISTINCT vendor
FROM purchase_orders
WHERE vendor IS NOT NULL AND vendor != ''
UNION
SELECT DISTINCT vendor
FROM receivings
WHERE vendor IS NOT NULL AND vendor != ''
ORDER BY vendor
`);
@@ -335,6 +459,10 @@ router.get('/', async (req, res) => {
SELECT DISTINCT status
FROM purchase_orders
WHERE status IS NOT NULL
UNION
SELECT DISTINCT status
FROM receivings
WHERE status IS NOT NULL
ORDER BY status
`);
@@ -389,24 +517,26 @@ router.get('/', async (req, res) => {
};
});
// Parse summary metrics
// Parse summary metrics with fallbacks
const parsedSummary = {
order_count: Number(summary.order_count) || 0,
total_ordered: Number(summary.total_ordered) || 0,
total_received: Number(summary.total_received) || 0,
fulfillment_rate: Number(summary.fulfillment_rate) || 0,
total_value: Number(summary.total_value) || 0,
avg_cost: Number(summary.avg_cost) || 0
order_count: Number(summary?.order_count) || 0,
total_ordered: Number(summary?.total_ordered) || 0,
total_received: Number(summary?.total_received) || 0,
fulfillment_rate: Number(summary?.fulfillment_rate) || 0,
total_value: Number(summary?.total_value) || 0,
avg_cost: Number(summary?.avg_cost) || 0
};
console.log(`Returning ${parsedOrders.length} orders, total=${total}, pages=${pages}, page=${parsedPage}`);
res.json({
orders: parsedOrders,
summary: parsedSummary,
pagination: {
total,
pages,
page: Number(page),
limit: Number(limit)
page: parsedPage,
limit: parsedLimit
},
filters: {
vendors: vendors.map(v => v.vendor),
@@ -415,7 +545,7 @@ router.get('/', async (req, res) => {
});
} catch (error) {
console.error('Error fetching purchase orders:', error);
res.status(500).json({ error: 'Failed to fetch purchase orders' });
res.status(500).json({ error: 'Failed to fetch purchase orders', details: error.message });
}
});