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}
)
)`;
const { rows: [summary] } = await pool.query(summaryQuery, params);
// Prepare query based on record type filter to get correct counts
let countQuery = '';
// 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
WITH po_data AS (
SELECT po_id
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
WHERE ${poWhereClause}
GROUP BY po_id
),
receiving_count AS (
SELECT 0 as r_count
)`;
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_count AS (
SELECT COUNT(DISTINCT po.po_id) as po_count
WITH po_data AS (
SELECT po_id
FROM purchase_orders po
INNER JOIN (
SELECT DISTINCT receiving_id
FROM receivings
) r ON po.po_id = r.receiving_id
WHERE ${whereClause}
WHERE ${poWhereClause}
GROUP BY po_id
),
receiving_count AS (
SELECT 0 as r_count
)`;
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_count AS (
SELECT 0 as po_count
WITH po_data AS (
SELECT po_id
FROM purchase_orders po
WHERE ${poWhereClause}
GROUP BY po_id
),
receiving_count AS (
SELECT COUNT(DISTINCT receiving_id) as r_count
receiving_data AS (
SELECT receiving_id
FROM receivings r
WHERE receiving_id NOT IN (
SELECT po_id FROM purchase_orders po WHERE ${whereClause}
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)
)
)`;
}
}
countQuery += `
SELECT (SELECT po_count FROM po_count) + (SELECT r_count FROM receiving_count) as total
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'];
// Get recent purchase orders - build the base query
const finalSortColumn = validSortColumns.includes(sortColumn) ? sortColumn : 'id';
const finalSortDirection = sortDirection === 'asc' ? 'asc' : 'desc';
// 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
),
)`;
// 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 (
-- 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'
WHERE receiving_id NOT IN (SELECT po_id FROM po_data WHERE po_id IS NOT NULL)
)`;
}
),
combined_data AS (
// 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 });
}
});

View File

@@ -229,6 +229,7 @@ export default function PurchaseOrders() {
const [page, setPage] = useState(1);
const [sortColumn, setSortColumn] = useState<string>("order_date");
const [sortDirection, setSortDirection] = useState<"asc" | "desc">("desc");
const [searchInput, setSearchInput] = useState("");
const [filterValues, setFilterValues] = useState({
search: "",
status: "all",
@@ -315,63 +316,74 @@ export default function PurchaseOrders() {
{ value: "receiving_only", label: "Receiving Only" },
];
// Use useMemo to compute filters only when filterValues change
const filters = useMemo(() => filterValues, [filterValues]);
const fetchData = async () => {
if (
hasInitialFetchRef.current &&
import.meta.hot &&
purchaseOrders.length > 0
) {
return;
}
try {
setLoading(true);
const searchParams = new URLSearchParams({
page: page.toString(),
limit: "100",
sortColumn,
sortDirection,
...(filters.search && { search: filters.search }),
...(filters.status !== "all" && { status: filters.status }),
...(filters.vendor !== "all" && { vendor: filters.vendor }),
...(filters.recordType !== "all" && { recordType: filters.recordType }),
});
const [purchaseOrdersRes, vendorMetricsRes, costAnalysisRes, deliveryMetricsRes] =
await Promise.all([
fetch(`/api/purchase-orders?${searchParams}`),
// Build search params with proper encoding
const searchParams = new URLSearchParams();
searchParams.append('page', page.toString());
searchParams.append('limit', '100');
searchParams.append('sortColumn', sortColumn);
searchParams.append('sortDirection', sortDirection);
if (filters.search) {
searchParams.append('search', filters.search);
}
if (filters.status !== 'all') {
searchParams.append('status', filters.status);
}
if (filters.vendor !== 'all') {
searchParams.append('vendor', filters.vendor);
}
if (filters.recordType !== 'all') {
searchParams.append('recordType', filters.recordType);
}
console.log("Fetching data with params:", searchParams.toString());
// Fetch orders first separately to handle errors better
const purchaseOrdersRes = await fetch(`/api/purchase-orders?${searchParams.toString()}`);
if (!purchaseOrdersRes.ok) {
const errorText = await purchaseOrdersRes.text();
console.error("Failed to fetch purchase orders:", errorText);
throw new Error(`Failed to fetch purchase orders: ${errorText}`);
}
const purchaseOrdersData = await purchaseOrdersRes.json();
// Process orders data immediately
const processedOrders = purchaseOrdersData.orders.map((order: any) => ({
...order,
status: Number(order.status),
total_items: Number(order.total_items) || 0,
total_quantity: Number(order.total_quantity) || 0,
total_cost: Number(order.total_cost) || 0,
total_received: Number(order.total_received) || 0,
fulfillment_rate: Number(order.fulfillment_rate) || 0,
}));
// Update the main data state
setPurchaseOrders(processedOrders);
setPagination(purchaseOrdersData.pagination);
setFilterOptions(purchaseOrdersData.filters);
// Now fetch the additional data in parallel
const [vendorMetricsRes, costAnalysisRes, deliveryMetricsRes] = await Promise.all([
fetch("/api/purchase-orders/vendor-metrics"),
fetch("/api/purchase-orders/cost-analysis"),
fetch("/api/purchase-orders/delivery-metrics"),
]);
// Initialize default data
let purchaseOrdersData: PurchaseOrdersResponse = {
orders: [],
summary: {
order_count: 0,
total_ordered: 0,
total_received: 0,
fulfillment_rate: 0,
total_value: 0,
avg_cost: 0,
},
pagination: {
total: 0,
pages: 0,
page: 1,
limit: 100,
},
filters: {
vendors: [],
statuses: [],
},
};
let vendorMetricsData: VendorMetrics[] = [];
let costAnalysisData: CostAnalysis = {
let vendorMetricsData = [];
let costAnalysisData = {
unique_products: 0,
avg_cost: 0,
min_cost: 0,
@@ -385,57 +397,37 @@ export default function PurchaseOrders() {
max_delivery_days: 0
};
// Only try to parse responses if they were successful
if (purchaseOrdersRes.ok) {
purchaseOrdersData = await purchaseOrdersRes.json();
} else {
console.error(
"Failed to fetch purchase orders:",
await purchaseOrdersRes.text()
);
}
if (vendorMetricsRes.ok) {
vendorMetricsData = await vendorMetricsRes.json();
setVendorMetrics(vendorMetricsData);
} else {
console.error(
"Failed to fetch vendor metrics:",
await vendorMetricsRes.text()
);
setVendorMetrics([]);
}
if (costAnalysisRes.ok) {
costAnalysisData = await costAnalysisRes.json();
setCostAnalysis(costAnalysisData);
} else {
console.error(
"Failed to fetch cost analysis:",
await costAnalysisRes.text()
);
setCostAnalysis({
unique_products: 0,
avg_cost: 0,
min_cost: 0,
max_cost: 0,
cost_variance: 0,
total_spend_by_category: [],
});
}
if (deliveryMetricsRes.ok) {
deliveryMetricsData = await deliveryMetricsRes.json();
} else {
console.error(
"Failed to fetch delivery metrics:",
await deliveryMetricsRes.text()
);
}
// Process orders data
const processedOrders = purchaseOrdersData.orders.map((order) => {
let processedOrder = {
...order,
status: Number(order.status),
total_items: Number(order.total_items) || 0,
total_quantity: Number(order.total_quantity) || 0,
total_cost: Number(order.total_cost) || 0,
total_received: Number(order.total_received) || 0,
fulfillment_rate: Number(order.fulfillment_rate) || 0,
};
return processedOrder;
});
// Merge delivery metrics into summary
const summaryWithDelivery = {
@@ -444,12 +436,18 @@ export default function PurchaseOrders() {
max_delivery_days: deliveryMetricsData.max_delivery_days
};
setPurchaseOrders(processedOrders);
setPagination(purchaseOrdersData.pagination);
setFilterOptions(purchaseOrdersData.filters);
setSummary(summaryWithDelivery);
setVendorMetrics(vendorMetricsData);
setCostAnalysis(costAnalysisData);
} else {
console.error(
"Failed to fetch delivery metrics:",
await deliveryMetricsRes.text()
);
setSummary({
...purchaseOrdersData.summary,
avg_delivery_days: 0,
max_delivery_days: 0
});
}
// Mark that we've completed an initial fetch
hasInitialFetchRef.current = true;
@@ -481,18 +479,73 @@ export default function PurchaseOrders() {
}
};
// Setup debounced search
useEffect(() => {
fetchData();
// eslint-disable-next-line react-hooks/exhaustive-deps
}, [page, sortColumn, sortDirection, filters]);
const timer = setTimeout(() => {
if (searchInput !== filterValues.search) {
setFilterValues(prev => ({ ...prev, search: searchInput }));
}
}, 300); // Use 300ms for better response time
return () => clearTimeout(timer);
}, [searchInput, filterValues.search]);
// Reset page to 1 when filters change
useEffect(() => {
// Reset to page 1 when filters change to ensure proper pagination
setPage(1);
}, [filterValues]); // Use filterValues directly to avoid unnecessary renders
// Fetch data when page, sort or filters change
useEffect(() => {
// Log the current filter state for debugging
console.log("Fetching with filters:", filterValues);
console.log("Page:", page, "Sort:", sortColumn, sortDirection);
// Always fetch data - don't use conditional checks that might prevent it
fetchData();
}, [page, sortColumn, sortDirection, filterValues]);
// Handle column sorting more consistently
const handleSort = (column: string) => {
// Reset to page 1 when changing sort to ensure we see the first page of results
setPage(1);
if (sortColumn === column) {
setSortDirection((prev) => (prev === "asc" ? "desc" : "asc"));
} else {
setSortColumn(column);
// For most columns, start with descending to show highest values first
if (column === 'id' || column === 'vendor_name') {
setSortDirection("asc");
} else {
setSortDirection("desc");
}
}
};
// Update filter handlers
const handleStatusChange = (value: string) => {
setFilterValues(prev => ({ ...prev, status: value }));
};
const handleVendorChange = (value: string) => {
setFilterValues(prev => ({ ...prev, vendor: value }));
};
const handleRecordTypeChange = (value: string) => {
setFilterValues(prev => ({ ...prev, recordType: value }));
};
// Clear all filters handler
const clearFilters = () => {
setSearchInput("");
setFilterValues({
search: "",
status: "all",
vendor: "all",
recordType: "all",
});
};
const getStatusBadge = (status: number, recordType: string) => {
@@ -541,14 +594,15 @@ export default function PurchaseOrders() {
const getPaginationItems = () => {
const items = [];
const totalPages = pagination.pages;
const currentPage = page; // Use the local state to ensure sync
// Always show first page
if (totalPages > 0) {
items.push(
<PaginationItem key="first">
<PaginationLink
isActive={page === 1}
onClick={() => page !== 1 && setPage(1)}
isActive={currentPage === 1}
onClick={() => currentPage !== 1 && setPage(1)}
>
1
</PaginationLink>
@@ -557,7 +611,7 @@ export default function PurchaseOrders() {
}
// Add ellipsis if needed
if (page > 3) {
if (currentPage > 3) {
items.push(
<PaginationItem key="ellipsis-1">
<PaginationEllipsis />
@@ -566,16 +620,16 @@ export default function PurchaseOrders() {
}
// Add pages around current page
const startPage = Math.max(2, page - 1);
const endPage = Math.min(totalPages - 1, page + 1);
const startPage = Math.max(2, currentPage - 1);
const endPage = Math.min(totalPages - 1, currentPage + 1);
for (let i = startPage; i <= endPage; i++) {
if (i <= 1 || i >= totalPages) continue; // Skip first and last page as they're handled separately
items.push(
<PaginationItem key={i}>
<PaginationLink
isActive={page === i}
onClick={() => page !== i && setPage(i)}
isActive={currentPage === i}
onClick={() => currentPage !== i && setPage(i)}
>
{i}
</PaginationLink>
@@ -584,7 +638,7 @@ export default function PurchaseOrders() {
}
// Add ellipsis if needed
if (page < totalPages - 2) {
if (currentPage < totalPages - 2) {
items.push(
<PaginationItem key="ellipsis-2">
<PaginationEllipsis />
@@ -597,8 +651,8 @@ export default function PurchaseOrders() {
items.push(
<PaginationItem key="last">
<PaginationLink
isActive={page === totalPages}
onClick={() => page !== totalPages && setPage(totalPages)}
isActive={currentPage === totalPages}
onClick={() => currentPage !== totalPages && setPage(totalPages)}
>
{totalPages}
</PaginationLink>
@@ -609,6 +663,12 @@ export default function PurchaseOrders() {
return items;
};
// Update sort indicators in table headers
const getSortIndicator = (column: string) => {
if (sortColumn !== column) return null;
return sortDirection === "asc" ? " ↑" : " ↓";
};
// Update this function to fetch yearly data
const fetchYearlyData = async () => {
if (
@@ -938,7 +998,7 @@ export default function PurchaseOrders() {
</div>
) : (
<div className="text-center p-4 text-muted-foreground">
No vendor data available for the past 12 months
No supplier data available for the past 12 months
</div>
);
}
@@ -953,14 +1013,14 @@ export default function PurchaseOrders() {
<>
<div className="text-sm font-medium mb-2 flex justify-between items-center px-4">
<span>
Showing received inventory by vendor for the past 12 months
Showing received inventory by supplier for the past 12 months
</span>
<span>{vendorData.length} vendors found</span>
<span>{vendorData.length} suppliers found</span>
</div>
<Table>
<TableHeader>
<TableRow>
<TableHead>Vendor</TableHead>
<TableHead>Supplier</TableHead>
<TableHead>Orders</TableHead>
<TableHead>Total Spend</TableHead>
<TableHead>% of Total</TableHead>
@@ -1063,7 +1123,7 @@ export default function PurchaseOrders() {
<Card>
<CardHeader className="flex flex-row items-center justify-between space-y-0 pb-2">
<CardTitle className="text-sm font-medium">
Received by Vendor
Received by Supplier
</CardTitle>
<Dialog
open={vendorAnalysisOpen}
@@ -1078,7 +1138,7 @@ export default function PurchaseOrders() {
<DialogHeader>
<DialogTitle className="flex items-center gap-2">
<BarChart3 className="h-5 w-5" />
<span>Received Inventory by Vendor</span>
<span>Received Inventory by Supplier</span>
</DialogTitle>
</DialogHeader>
<div className="overflow-auto max-h-[70vh]">
@@ -1201,18 +1261,14 @@ export default function PurchaseOrders() {
<div className="mb-4 flex flex-wrap items-center gap-4">
<Input
placeholder="Search orders..."
value={filterValues.search}
onChange={(e) =>
setFilterValues((prev) => ({ ...prev, search: e.target.value }))
}
value={searchInput}
onChange={(e) => setSearchInput(e.target.value)}
className="max-w-xs"
disabled={loading}
/>
<Select
value={filterValues.status}
onValueChange={(value) =>
setFilterValues((prev) => ({ ...prev, status: value }))
}
onValueChange={handleStatusChange}
disabled={loading}
>
<SelectTrigger className="w-[180px]">
@@ -1228,16 +1284,14 @@ export default function PurchaseOrders() {
</Select>
<Select
value={filterValues.vendor}
onValueChange={(value) =>
setFilterValues((prev) => ({ ...prev, vendor: value }))
}
onValueChange={handleVendorChange}
disabled={loading}
>
<SelectTrigger className="w-[180px]">
<SelectValue placeholder="Select vendor" />
<SelectValue placeholder="Select supplier" />
</SelectTrigger>
<SelectContent>
<SelectItem value="all">All Vendors</SelectItem>
<SelectItem value="all">All Suppliers</SelectItem>
{filterOptions?.vendors?.map((vendor) => (
<SelectItem key={vendor} value={vendor}>
{vendor}
@@ -1247,9 +1301,7 @@ export default function PurchaseOrders() {
</Select>
<Select
value={filterValues.recordType}
onValueChange={(value) =>
setFilterValues((prev) => ({ ...prev, recordType: value }))
}
onValueChange={handleRecordTypeChange}
disabled={loading}
>
<SelectTrigger className="w-[180px]">
@@ -1263,6 +1315,18 @@ export default function PurchaseOrders() {
))}
</SelectContent>
</Select>
{(filterValues.search || filterValues.status !== "all" || filterValues.vendor !== "all" || filterValues.recordType !== "all") && (
<Button
variant="outline"
size="sm"
onClick={clearFilters}
disabled={loading}
title="Clear filters"
className="gap-1"
>
<span>Clear</span>
</Button>
)}
</div>
{/* Purchase Orders Table */}
@@ -1292,7 +1356,7 @@ export default function PurchaseOrders() {
onClick={() => !loading && handleSort("id")}
disabled={loading}
>
ID
ID{getSortIndicator("id")}
</Button>
</TableHead>
<TableHead className="w-[140px] text-center">
@@ -1302,7 +1366,7 @@ export default function PurchaseOrders() {
onClick={() => !loading && handleSort("vendor_name")}
disabled={loading}
>
Supplier
Supplier{getSortIndicator("vendor_name")}
</Button>
</TableHead>
<TableHead className="w-[115px] text-center">
@@ -1312,7 +1376,7 @@ export default function PurchaseOrders() {
onClick={() => !loading && handleSort("status")}
disabled={loading}
>
Status
Status{getSortIndicator("status")}
</Button>
</TableHead>
<TableHead className="w-[150px] text-center">Note</TableHead>
@@ -1323,10 +1387,19 @@ export default function PurchaseOrders() {
onClick={() => !loading && handleSort("total_cost")}
disabled={loading}
>
Total Cost
Total Cost{getSortIndicator("total_cost")}
</Button>
</TableHead>
<TableHead className="w-[70px] text-center">
<Button
className="w-full"
variant="ghost"
onClick={() => !loading && handleSort("total_items")}
disabled={loading}
>
Products{getSortIndicator("total_items")}
</Button>
</TableHead>
<TableHead className="w-[70px] text-center">Products</TableHead>
<TableHead className="w-[90px] text-center">
<Button
className="w-full"
@@ -1334,14 +1407,39 @@ export default function PurchaseOrders() {
onClick={() => !loading && handleSort("order_date")}
disabled={loading}
>
Order Date
Order Date{getSortIndicator("order_date")}
</Button>
</TableHead>
<TableHead className="w-[90px] text-center">
<Button
className="w-full"
variant="ghost"
onClick={() => !loading && handleSort("receiving_date")}
disabled={loading}
>
Rec'd Date{getSortIndicator("receiving_date")}
</Button>
</TableHead>
<TableHead className="w-[70px] text-center">
<Button
className="w-full"
variant="ghost"
onClick={() => !loading && handleSort("total_quantity")}
disabled={loading}
>
Ordered{getSortIndicator("total_quantity")}
</Button>
</TableHead>
<TableHead className="w-[80px] text-center">
<Button
className="w-full"
variant="ghost"
onClick={() => !loading && handleSort("total_received")}
disabled={loading}
>
Received{getSortIndicator("total_received")}
</Button>
</TableHead>
<TableHead className="w-[90px] text-center">Rec'd Date</TableHead>
<TableHead className="w-[70px] text-center">Ordered</TableHead>
<TableHead className="w-[80px] text-center">Received</TableHead>
<TableHead className="w-[80px] text-center">
<Button
className="w-full"
@@ -1349,7 +1447,7 @@ export default function PurchaseOrders() {
onClick={() => !loading && handleSort("fulfillment_rate")}
disabled={loading}
>
% Fulfilled
% Fulfilled{getSortIndicator("fulfillment_rate")}
</Button>
</TableHead>
</TableRow>