Fix up more purchase order stuff
This commit is contained in:
@@ -11,8 +11,8 @@ router.get('/', async (req, res) => {
|
||||
const params = [];
|
||||
|
||||
if (search) {
|
||||
whereClause += ' AND (po.po_id LIKE ? OR po.vendor LIKE ?)';
|
||||
params.push(`%${search}%`, `%${search}%`);
|
||||
whereClause += ' AND (po.po_id LIKE ? OR po.vendor LIKE ? OR po.status LIKE ?)';
|
||||
params.push(`%${search}%`, `%${search}%`, `%${search}%`);
|
||||
}
|
||||
|
||||
if (status && status !== 'all') {
|
||||
@@ -35,6 +35,30 @@ router.get('/', async (req, res) => {
|
||||
params.push(endDate);
|
||||
}
|
||||
|
||||
// Get filtered summary metrics
|
||||
const [summary] = await pool.query(`
|
||||
WITH po_totals AS (
|
||||
SELECT
|
||||
po_id,
|
||||
SUM(ordered) as total_ordered,
|
||||
SUM(received) as total_received,
|
||||
SUM(ordered * cost_price) as total_cost
|
||||
FROM purchase_orders po
|
||||
WHERE ${whereClause}
|
||||
GROUP BY 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,
|
||||
SUM(total_cost) as total_value,
|
||||
ROUND(AVG(total_cost), 2) as avg_cost
|
||||
FROM po_totals
|
||||
`, params);
|
||||
|
||||
// Get total count for pagination
|
||||
const [countResult] = await pool.query(`
|
||||
SELECT COUNT(DISTINCT po_id) as total
|
||||
@@ -48,32 +72,48 @@ router.get('/', async (req, res) => {
|
||||
|
||||
// Get recent purchase orders
|
||||
const [orders] = await pool.query(`
|
||||
WITH po_totals AS (
|
||||
SELECT
|
||||
po_id,
|
||||
vendor,
|
||||
date,
|
||||
status,
|
||||
COUNT(DISTINCT product_id) as total_items,
|
||||
SUM(ordered) as total_quantity,
|
||||
SUM(ordered * cost_price) as total_cost,
|
||||
SUM(received) as total_received,
|
||||
ROUND(
|
||||
SUM(received) / NULLIF(SUM(ordered), 0), 3
|
||||
) as fulfillment_rate
|
||||
FROM purchase_orders po
|
||||
WHERE ${whereClause}
|
||||
GROUP BY po_id, vendor, date, status
|
||||
)
|
||||
SELECT
|
||||
po_id as id,
|
||||
vendor as vendor_name,
|
||||
DATE_FORMAT(date, '%Y-%m-%d') as order_date,
|
||||
status,
|
||||
COUNT(DISTINCT product_id) as total_items,
|
||||
SUM(ordered) as total_quantity,
|
||||
SUM(ordered * cost_price) as total_cost,
|
||||
SUM(received) as total_received,
|
||||
ROUND(
|
||||
SUM(received) / SUM(ordered), 3
|
||||
) as fulfillment_rate
|
||||
FROM purchase_orders po
|
||||
WHERE ${whereClause}
|
||||
GROUP BY po_id, vendor, date, status
|
||||
total_items,
|
||||
total_quantity,
|
||||
total_cost,
|
||||
total_received,
|
||||
fulfillment_rate
|
||||
FROM po_totals
|
||||
ORDER BY
|
||||
CASE
|
||||
WHEN ? = 'order_date' THEN date
|
||||
WHEN ? = 'vendor_name' THEN vendor
|
||||
WHEN ? = 'total_cost' THEN SUM(ordered * cost_price)
|
||||
WHEN ? = 'total_received' THEN SUM(received)
|
||||
WHEN ? = 'fulfillment_rate' THEN SUM(received) / SUM(ordered)
|
||||
WHEN ? = 'total_cost' THEN CAST(total_cost AS DECIMAL(15,2))
|
||||
WHEN ? = 'total_received' THEN CAST(total_received AS DECIMAL(15,2))
|
||||
WHEN ? = 'total_items' THEN CAST(total_items AS SIGNED)
|
||||
WHEN ? = 'total_quantity' THEN CAST(total_quantity AS SIGNED)
|
||||
WHEN ? = 'fulfillment_rate' THEN CAST(fulfillment_rate AS DECIMAL(5,3))
|
||||
WHEN ? = 'status' THEN status
|
||||
ELSE date
|
||||
END ${sortDirection === 'desc' ? 'DESC' : 'ASC'}
|
||||
LIMIT ? OFFSET ?
|
||||
`, [...params, sortColumn, sortColumn, sortColumn, sortColumn, sortColumn, Number(limit), offset]);
|
||||
`, [...params, sortColumn, sortColumn, sortColumn, sortColumn, sortColumn, sortColumn, sortColumn, sortColumn, Number(limit), offset]);
|
||||
|
||||
// Get unique vendors for filter options
|
||||
const [vendors] = await pool.query(`
|
||||
@@ -104,8 +144,19 @@ router.get('/', async (req, res) => {
|
||||
fulfillment_rate: Number(order.fulfillment_rate) || 0
|
||||
}));
|
||||
|
||||
// Parse summary metrics
|
||||
const parsedSummary = {
|
||||
order_count: Number(summary[0].order_count) || 0,
|
||||
total_ordered: Number(summary[0].total_ordered) || 0,
|
||||
total_received: Number(summary[0].total_received) || 0,
|
||||
fulfillment_rate: Number(summary[0].fulfillment_rate) || 0,
|
||||
total_value: Number(summary[0].total_value) || 0,
|
||||
avg_cost: Number(summary[0].avg_cost) || 0
|
||||
};
|
||||
|
||||
res.json({
|
||||
orders: parsedOrders,
|
||||
summary: parsedSummary,
|
||||
pagination: {
|
||||
total,
|
||||
pages,
|
||||
@@ -129,27 +180,37 @@ router.get('/vendor-metrics', async (req, res) => {
|
||||
const pool = req.app.locals.pool;
|
||||
|
||||
const [metrics] = await pool.query(`
|
||||
WITH delivery_metrics AS (
|
||||
SELECT
|
||||
vendor,
|
||||
po_id,
|
||||
ordered,
|
||||
received,
|
||||
cost_price,
|
||||
CASE
|
||||
WHEN status = 'received' AND received_date IS NOT NULL AND date IS NOT NULL
|
||||
THEN DATEDIFF(received_date, date)
|
||||
ELSE NULL
|
||||
END as delivery_days
|
||||
FROM purchase_orders
|
||||
WHERE vendor IS NOT NULL AND vendor != ''
|
||||
)
|
||||
SELECT
|
||||
vendor as vendor_name,
|
||||
COUNT(DISTINCT po_id) as total_orders,
|
||||
SUM(ordered) as total_ordered,
|
||||
SUM(received) as total_received,
|
||||
ROUND(
|
||||
SUM(received) / SUM(ordered), 3
|
||||
SUM(received) / NULLIF(SUM(ordered), 0), 3
|
||||
) as fulfillment_rate,
|
||||
ROUND(
|
||||
SUM(ordered * cost_price) / SUM(ordered), 2
|
||||
SUM(ordered * cost_price) / NULLIF(SUM(ordered), 0), 2
|
||||
) as avg_unit_cost,
|
||||
SUM(ordered * cost_price) as total_spend,
|
||||
ROUND(AVG(
|
||||
CASE
|
||||
WHEN status = 'received' AND received_date IS NOT NULL AND date IS NOT NULL
|
||||
THEN DATEDIFF(received_date, date)
|
||||
ELSE NULL
|
||||
END
|
||||
), 1) as avg_delivery_days
|
||||
FROM purchase_orders
|
||||
WHERE vendor IS NOT NULL AND vendor != ''
|
||||
ROUND(
|
||||
AVG(NULLIF(delivery_days, 0)), 1
|
||||
) as avg_delivery_days
|
||||
FROM delivery_metrics
|
||||
GROUP BY vendor
|
||||
HAVING total_orders > 0
|
||||
ORDER BY total_spend DESC
|
||||
@@ -165,7 +226,7 @@ router.get('/vendor-metrics', async (req, res) => {
|
||||
fulfillment_rate: Number(vendor.fulfillment_rate) || 0,
|
||||
avg_unit_cost: Number(vendor.avg_unit_cost) || 0,
|
||||
total_spend: Number(vendor.total_spend) || 0,
|
||||
avg_delivery_days: Number(vendor.avg_delivery_days) || 0
|
||||
avg_delivery_days: vendor.avg_delivery_days === null ? null : Number(vendor.avg_delivery_days)
|
||||
}));
|
||||
|
||||
res.json(parsedMetrics);
|
||||
|
||||
@@ -65,6 +65,14 @@ interface ReceivingStatus {
|
||||
|
||||
interface PurchaseOrdersResponse {
|
||||
orders: PurchaseOrder[];
|
||||
summary: {
|
||||
order_count: number;
|
||||
total_ordered: number;
|
||||
total_received: number;
|
||||
fulfillment_rate: number;
|
||||
total_value: number;
|
||||
avg_cost: number;
|
||||
};
|
||||
pagination: {
|
||||
total: number;
|
||||
pages: number;
|
||||
@@ -81,7 +89,7 @@ export default function PurchaseOrders() {
|
||||
const [purchaseOrders, setPurchaseOrders] = useState<PurchaseOrder[]>([]);
|
||||
const [vendorMetrics, setVendorMetrics] = useState<VendorMetrics[]>([]);
|
||||
const [costAnalysis, setCostAnalysis] = useState<CostAnalysis | null>(null);
|
||||
const [receivingStatus, setReceivingStatus] = useState<ReceivingStatus | null>(null);
|
||||
const [summary, setSummary] = useState<ReceivingStatus | null>(null);
|
||||
const [loading, setLoading] = useState(true);
|
||||
const [page, setPage] = useState(1);
|
||||
const [sortColumn, setSortColumn] = useState<string>('order_date');
|
||||
@@ -120,33 +128,29 @@ export default function PurchaseOrders() {
|
||||
const [
|
||||
purchaseOrdersRes,
|
||||
vendorMetricsRes,
|
||||
costAnalysisRes,
|
||||
receivingStatusRes
|
||||
costAnalysisRes
|
||||
] = await Promise.all([
|
||||
fetch(`/api/purchase-orders?${searchParams}`),
|
||||
fetch('/api/purchase-orders/vendor-metrics'),
|
||||
fetch('/api/purchase-orders/cost-analysis'),
|
||||
fetch('/api/purchase-orders/receiving-status')
|
||||
fetch('/api/purchase-orders/cost-analysis')
|
||||
]);
|
||||
|
||||
const [
|
||||
purchaseOrdersData,
|
||||
vendorMetricsData,
|
||||
costAnalysisData,
|
||||
receivingStatusData
|
||||
costAnalysisData
|
||||
] = await Promise.all([
|
||||
purchaseOrdersRes.json(),
|
||||
vendorMetricsRes.json(),
|
||||
costAnalysisRes.json(),
|
||||
receivingStatusRes.json()
|
||||
costAnalysisRes.json()
|
||||
]);
|
||||
|
||||
setPurchaseOrders(purchaseOrdersData.orders);
|
||||
setPagination(purchaseOrdersData.pagination);
|
||||
setFilterOptions(purchaseOrdersData.filters);
|
||||
setSummary(purchaseOrdersData.summary);
|
||||
setVendorMetrics(vendorMetricsData);
|
||||
setCostAnalysis(costAnalysisData);
|
||||
setReceivingStatus(receivingStatusData);
|
||||
} catch (error) {
|
||||
console.error('Error fetching data:', error);
|
||||
} finally {
|
||||
@@ -179,6 +183,20 @@ export default function PurchaseOrders() {
|
||||
return <Badge variant={statusConfig.variant}>{statusConfig.label}</Badge>;
|
||||
};
|
||||
|
||||
const formatNumber = (value: number) => {
|
||||
return value.toLocaleString('en-US', {
|
||||
minimumFractionDigits: 2,
|
||||
maximumFractionDigits: 2
|
||||
});
|
||||
};
|
||||
|
||||
const formatPercent = (value: number) => {
|
||||
return (value * 100).toLocaleString('en-US', {
|
||||
minimumFractionDigits: 1,
|
||||
maximumFractionDigits: 1
|
||||
}) + '%';
|
||||
};
|
||||
|
||||
if (loading) {
|
||||
return (
|
||||
<div className="flex h-full items-center justify-center">
|
||||
@@ -198,7 +216,7 @@ export default function PurchaseOrders() {
|
||||
<CardTitle className="text-sm font-medium">Total Orders</CardTitle>
|
||||
</CardHeader>
|
||||
<CardContent>
|
||||
<div className="text-2xl font-bold">{receivingStatus?.order_count || 0}</div>
|
||||
<div className="text-2xl font-bold">{summary?.order_count.toLocaleString() || 0}</div>
|
||||
</CardContent>
|
||||
</Card>
|
||||
<Card>
|
||||
@@ -207,7 +225,7 @@ export default function PurchaseOrders() {
|
||||
</CardHeader>
|
||||
<CardContent>
|
||||
<div className="text-2xl font-bold">
|
||||
${(receivingStatus?.total_value || 0).toFixed(2)}
|
||||
${formatNumber(summary?.total_value || 0)}
|
||||
</div>
|
||||
</CardContent>
|
||||
</Card>
|
||||
@@ -217,7 +235,7 @@ export default function PurchaseOrders() {
|
||||
</CardHeader>
|
||||
<CardContent>
|
||||
<div className="text-2xl font-bold">
|
||||
{((receivingStatus?.fulfillment_rate || 0) * 100).toFixed(1)}%
|
||||
{formatPercent(summary?.fulfillment_rate || 0)}
|
||||
</div>
|
||||
</CardContent>
|
||||
</Card>
|
||||
@@ -227,7 +245,7 @@ export default function PurchaseOrders() {
|
||||
</CardHeader>
|
||||
<CardContent>
|
||||
<div className="text-2xl font-bold">
|
||||
${(receivingStatus?.avg_cost || 0).toFixed(2)}
|
||||
${formatNumber(summary?.avg_cost || 0)}
|
||||
</div>
|
||||
</CardContent>
|
||||
</Card>
|
||||
@@ -326,11 +344,11 @@ export default function PurchaseOrders() {
|
||||
<TableCell>{po.vendor_name}</TableCell>
|
||||
<TableCell>{new Date(po.order_date).toLocaleDateString()}</TableCell>
|
||||
<TableCell>{getStatusBadge(po.status)}</TableCell>
|
||||
<TableCell>{po.total_items}</TableCell>
|
||||
<TableCell>{po.total_quantity}</TableCell>
|
||||
<TableCell>${po.total_cost.toFixed(2)}</TableCell>
|
||||
<TableCell>{po.total_received}</TableCell>
|
||||
<TableCell>{(po.fulfillment_rate * 100).toFixed(1)}%</TableCell>
|
||||
<TableCell>{po.total_items.toLocaleString()}</TableCell>
|
||||
<TableCell>{po.total_quantity.toLocaleString()}</TableCell>
|
||||
<TableCell>${formatNumber(po.total_cost)}</TableCell>
|
||||
<TableCell>{po.total_received.toLocaleString()}</TableCell>
|
||||
<TableCell>{formatPercent(po.fulfillment_rate)}</TableCell>
|
||||
</TableRow>
|
||||
))}
|
||||
{!purchaseOrders.length && (
|
||||
@@ -398,11 +416,11 @@ export default function PurchaseOrders() {
|
||||
{vendorMetrics.map((vendor) => (
|
||||
<TableRow key={vendor.vendor_name}>
|
||||
<TableCell>{vendor.vendor_name}</TableCell>
|
||||
<TableCell>{vendor.total_orders}</TableCell>
|
||||
<TableCell>{vendor.avg_delivery_days.toFixed(1)}</TableCell>
|
||||
<TableCell>{(vendor.fulfillment_rate * 100).toFixed(1)}%</TableCell>
|
||||
<TableCell>${vendor.avg_unit_cost.toFixed(2)}</TableCell>
|
||||
<TableCell>${vendor.total_spend.toFixed(2)}</TableCell>
|
||||
<TableCell>{vendor.total_orders.toLocaleString()}</TableCell>
|
||||
<TableCell>{vendor.avg_delivery_days?.toFixed(1) || 'N/A'}</TableCell>
|
||||
<TableCell>{formatPercent(vendor.fulfillment_rate)}</TableCell>
|
||||
<TableCell>${formatNumber(vendor.avg_unit_cost)}</TableCell>
|
||||
<TableCell>${formatNumber(vendor.total_spend)}</TableCell>
|
||||
</TableRow>
|
||||
))}
|
||||
</TableBody>
|
||||
@@ -427,7 +445,7 @@ export default function PurchaseOrders() {
|
||||
{costAnalysis?.total_spend_by_category?.map((category) => (
|
||||
<TableRow key={category.category}>
|
||||
<TableCell>{category.category}</TableCell>
|
||||
<TableCell>${category.total_spend.toFixed(2)}</TableCell>
|
||||
<TableCell>${formatNumber(category.total_spend)}</TableCell>
|
||||
</TableRow>
|
||||
)) || (
|
||||
<TableRow>
|
||||
|
||||
Reference in New Issue
Block a user