Update calculate scripts and routes for PO table split
This commit is contained in:
@@ -11,10 +11,10 @@ const importHistoricalData = require('./import/historical-data');
|
|||||||
dotenv.config({ path: path.join(__dirname, "../.env") });
|
dotenv.config({ path: path.join(__dirname, "../.env") });
|
||||||
|
|
||||||
// Constants to control which imports run
|
// Constants to control which imports run
|
||||||
const IMPORT_CATEGORIES = false;
|
const IMPORT_CATEGORIES = true;
|
||||||
const IMPORT_PRODUCTS = true;
|
const IMPORT_PRODUCTS = true;
|
||||||
const IMPORT_ORDERS = false;
|
const IMPORT_ORDERS = true;
|
||||||
const IMPORT_PURCHASE_ORDERS = false;
|
const IMPORT_PURCHASE_ORDERS = true;
|
||||||
const IMPORT_HISTORICAL_DATA = false;
|
const IMPORT_HISTORICAL_DATA = false;
|
||||||
|
|
||||||
// Add flag for incremental updates
|
// Add flag for incremental updates
|
||||||
|
|||||||
@@ -91,6 +91,287 @@ function cancelCalculation() {
|
|||||||
process.on('SIGTERM', cancelCalculation);
|
process.on('SIGTERM', cancelCalculation);
|
||||||
process.on('SIGINT', cancelCalculation);
|
process.on('SIGINT', cancelCalculation);
|
||||||
|
|
||||||
|
const calculateInitialMetrics = (client, onProgress) => {
|
||||||
|
return client.query(`
|
||||||
|
-- Truncate the existing metrics tables to ensure clean data
|
||||||
|
TRUNCATE TABLE public.daily_product_snapshots;
|
||||||
|
TRUNCATE TABLE public.product_metrics;
|
||||||
|
|
||||||
|
-- First let's create daily snapshots for all products with order activity
|
||||||
|
WITH SalesData AS (
|
||||||
|
SELECT
|
||||||
|
p.pid,
|
||||||
|
p.sku,
|
||||||
|
o.date::date AS order_date,
|
||||||
|
-- Count orders to ensure we only include products with real activity
|
||||||
|
COUNT(o.id) as order_count,
|
||||||
|
-- Aggregate Sales (Quantity > 0, Status not Canceled/Returned)
|
||||||
|
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN o.quantity ELSE 0 END), 0) AS units_sold,
|
||||||
|
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN o.price * o.quantity ELSE 0 END), 0.00) AS gross_revenue_unadjusted,
|
||||||
|
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN o.discount ELSE 0 END), 0.00) AS discounts,
|
||||||
|
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN COALESCE(o.costeach, p.landing_cost_price, p.cost_price) * o.quantity ELSE 0 END), 0.00) AS cogs,
|
||||||
|
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN p.regular_price * o.quantity ELSE 0 END), 0.00) AS gross_regular_revenue,
|
||||||
|
|
||||||
|
-- Aggregate Returns (Quantity < 0 or Status = Returned)
|
||||||
|
COALESCE(SUM(CASE WHEN o.quantity < 0 OR COALESCE(o.status, 'pending') = 'returned' THEN ABS(o.quantity) ELSE 0 END), 0) AS units_returned,
|
||||||
|
COALESCE(SUM(CASE WHEN o.quantity < 0 OR COALESCE(o.status, 'pending') = 'returned' THEN o.price * ABS(o.quantity) ELSE 0 END), 0.00) AS returns_revenue
|
||||||
|
FROM public.products p
|
||||||
|
LEFT JOIN public.orders o ON p.pid = o.pid
|
||||||
|
GROUP BY p.pid, p.sku, o.date::date
|
||||||
|
HAVING COUNT(o.id) > 0 -- Only include products with actual orders
|
||||||
|
),
|
||||||
|
ReceivingData AS (
|
||||||
|
SELECT
|
||||||
|
r.pid,
|
||||||
|
r.received_date::date AS receiving_date,
|
||||||
|
-- Count receiving documents to ensure we only include products with real activity
|
||||||
|
COUNT(DISTINCT r.receiving_id) as receiving_count,
|
||||||
|
-- Calculate received quantity for this day
|
||||||
|
SUM(r.received_quantity) AS units_received,
|
||||||
|
-- Calculate received cost for this day
|
||||||
|
SUM(r.received_quantity * r.unit_cost) AS cost_received
|
||||||
|
FROM public.receivings r
|
||||||
|
GROUP BY r.pid, r.received_date::date
|
||||||
|
HAVING COUNT(DISTINCT r.receiving_id) > 0 OR SUM(r.received_quantity) > 0
|
||||||
|
),
|
||||||
|
-- Get current stock quantities
|
||||||
|
StockData AS (
|
||||||
|
SELECT
|
||||||
|
p.pid,
|
||||||
|
p.stock_quantity,
|
||||||
|
COALESCE(p.landing_cost_price, p.cost_price, 0.00) as effective_cost_price,
|
||||||
|
COALESCE(p.price, 0.00) as current_price,
|
||||||
|
COALESCE(p.regular_price, 0.00) as current_regular_price
|
||||||
|
FROM public.products p
|
||||||
|
),
|
||||||
|
-- Combine sales and receiving dates to get all activity dates
|
||||||
|
DatePidCombos AS (
|
||||||
|
SELECT DISTINCT pid, order_date AS activity_date FROM SalesData
|
||||||
|
UNION
|
||||||
|
SELECT DISTINCT pid, receiving_date FROM ReceivingData
|
||||||
|
),
|
||||||
|
-- Insert daily snapshots for all product-date combinations
|
||||||
|
SnapshotInsert AS (
|
||||||
|
INSERT INTO public.daily_product_snapshots (
|
||||||
|
snapshot_date,
|
||||||
|
pid,
|
||||||
|
sku,
|
||||||
|
eod_stock_quantity,
|
||||||
|
eod_stock_cost,
|
||||||
|
eod_stock_retail,
|
||||||
|
eod_stock_gross,
|
||||||
|
stockout_flag,
|
||||||
|
units_sold,
|
||||||
|
units_returned,
|
||||||
|
gross_revenue,
|
||||||
|
discounts,
|
||||||
|
returns_revenue,
|
||||||
|
net_revenue,
|
||||||
|
cogs,
|
||||||
|
gross_regular_revenue,
|
||||||
|
profit,
|
||||||
|
units_received,
|
||||||
|
cost_received,
|
||||||
|
calculation_timestamp
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
d.activity_date AS snapshot_date,
|
||||||
|
d.pid,
|
||||||
|
p.sku,
|
||||||
|
-- Use current stock as approximation, since historical stock data is not available
|
||||||
|
s.stock_quantity AS eod_stock_quantity,
|
||||||
|
s.stock_quantity * s.effective_cost_price AS eod_stock_cost,
|
||||||
|
s.stock_quantity * s.current_price AS eod_stock_retail,
|
||||||
|
s.stock_quantity * s.current_regular_price AS eod_stock_gross,
|
||||||
|
(s.stock_quantity <= 0) AS stockout_flag,
|
||||||
|
-- Sales metrics
|
||||||
|
COALESCE(sd.units_sold, 0),
|
||||||
|
COALESCE(sd.units_returned, 0),
|
||||||
|
COALESCE(sd.gross_revenue_unadjusted, 0.00),
|
||||||
|
COALESCE(sd.discounts, 0.00),
|
||||||
|
COALESCE(sd.returns_revenue, 0.00),
|
||||||
|
COALESCE(sd.gross_revenue_unadjusted, 0.00) - COALESCE(sd.discounts, 0.00) AS net_revenue,
|
||||||
|
COALESCE(sd.cogs, 0.00),
|
||||||
|
COALESCE(sd.gross_regular_revenue, 0.00),
|
||||||
|
(COALESCE(sd.gross_revenue_unadjusted, 0.00) - COALESCE(sd.discounts, 0.00)) - COALESCE(sd.cogs, 0.00) AS profit,
|
||||||
|
-- Receiving metrics
|
||||||
|
COALESCE(rd.units_received, 0),
|
||||||
|
COALESCE(rd.cost_received, 0.00),
|
||||||
|
now() -- calculation timestamp
|
||||||
|
FROM DatePidCombos d
|
||||||
|
JOIN public.products p ON d.pid = p.pid
|
||||||
|
LEFT JOIN SalesData sd ON d.pid = sd.pid AND d.activity_date = sd.order_date
|
||||||
|
LEFT JOIN ReceivingData rd ON d.pid = rd.pid AND d.activity_date = rd.receiving_date
|
||||||
|
LEFT JOIN StockData s ON d.pid = s.pid
|
||||||
|
RETURNING pid, snapshot_date
|
||||||
|
),
|
||||||
|
-- Now build the aggregated product metrics from the daily snapshots
|
||||||
|
MetricsInsert AS (
|
||||||
|
INSERT INTO public.product_metrics (
|
||||||
|
pid,
|
||||||
|
sku,
|
||||||
|
current_stock_quantity,
|
||||||
|
current_stock_cost,
|
||||||
|
current_stock_retail,
|
||||||
|
current_stock_msrp,
|
||||||
|
is_out_of_stock,
|
||||||
|
total_units_sold,
|
||||||
|
total_units_returned,
|
||||||
|
return_rate,
|
||||||
|
gross_revenue,
|
||||||
|
total_discounts,
|
||||||
|
total_returns,
|
||||||
|
net_revenue,
|
||||||
|
total_cogs,
|
||||||
|
total_gross_revenue,
|
||||||
|
total_profit,
|
||||||
|
profit_margin,
|
||||||
|
avg_daily_units,
|
||||||
|
reorder_point,
|
||||||
|
reorder_alert,
|
||||||
|
days_of_supply,
|
||||||
|
sales_velocity,
|
||||||
|
sales_velocity_score,
|
||||||
|
rank_by_revenue,
|
||||||
|
rank_by_quantity,
|
||||||
|
rank_by_profit,
|
||||||
|
total_received_quantity,
|
||||||
|
total_received_cost,
|
||||||
|
last_sold_date,
|
||||||
|
last_received_date,
|
||||||
|
days_since_last_sale,
|
||||||
|
days_since_last_received,
|
||||||
|
calculation_timestamp
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
p.pid,
|
||||||
|
p.sku,
|
||||||
|
p.stock_quantity AS current_stock_quantity,
|
||||||
|
p.stock_quantity * COALESCE(p.landing_cost_price, p.cost_price, 0) AS current_stock_cost,
|
||||||
|
p.stock_quantity * COALESCE(p.price, 0) AS current_stock_retail,
|
||||||
|
p.stock_quantity * COALESCE(p.regular_price, 0) AS current_stock_msrp,
|
||||||
|
(p.stock_quantity <= 0) AS is_out_of_stock,
|
||||||
|
-- Aggregate metrics
|
||||||
|
COALESCE(SUM(ds.units_sold), 0) AS total_units_sold,
|
||||||
|
COALESCE(SUM(ds.units_returned), 0) AS total_units_returned,
|
||||||
|
CASE
|
||||||
|
WHEN COALESCE(SUM(ds.units_sold), 0) > 0
|
||||||
|
THEN COALESCE(SUM(ds.units_returned), 0)::float / NULLIF(COALESCE(SUM(ds.units_sold), 0), 0)
|
||||||
|
ELSE 0
|
||||||
|
END AS return_rate,
|
||||||
|
COALESCE(SUM(ds.gross_revenue), 0) AS gross_revenue,
|
||||||
|
COALESCE(SUM(ds.discounts), 0) AS total_discounts,
|
||||||
|
COALESCE(SUM(ds.returns_revenue), 0) AS total_returns,
|
||||||
|
COALESCE(SUM(ds.net_revenue), 0) AS net_revenue,
|
||||||
|
COALESCE(SUM(ds.cogs), 0) AS total_cogs,
|
||||||
|
COALESCE(SUM(ds.gross_regular_revenue), 0) AS total_gross_revenue,
|
||||||
|
COALESCE(SUM(ds.profit), 0) AS total_profit,
|
||||||
|
CASE
|
||||||
|
WHEN COALESCE(SUM(ds.net_revenue), 0) > 0
|
||||||
|
THEN COALESCE(SUM(ds.profit), 0) / NULLIF(COALESCE(SUM(ds.net_revenue), 0), 0)
|
||||||
|
ELSE 0
|
||||||
|
END AS profit_margin,
|
||||||
|
-- Calculate average daily units
|
||||||
|
COALESCE(AVG(ds.units_sold), 0) AS avg_daily_units,
|
||||||
|
-- Calculate reorder point (simplified, can be enhanced with lead time and safety stock)
|
||||||
|
CEILING(COALESCE(AVG(ds.units_sold) * 14, 0)) AS reorder_point,
|
||||||
|
(p.stock_quantity <= CEILING(COALESCE(AVG(ds.units_sold) * 14, 0))) AS reorder_alert,
|
||||||
|
-- Days of supply based on average daily sales
|
||||||
|
CASE
|
||||||
|
WHEN COALESCE(AVG(ds.units_sold), 0) > 0
|
||||||
|
THEN p.stock_quantity / NULLIF(COALESCE(AVG(ds.units_sold), 0), 0)
|
||||||
|
ELSE NULL
|
||||||
|
END AS days_of_supply,
|
||||||
|
-- Sales velocity (average units sold per day over last 30 days)
|
||||||
|
(SELECT COALESCE(AVG(recent.units_sold), 0)
|
||||||
|
FROM public.daily_product_snapshots recent
|
||||||
|
WHERE recent.pid = p.pid
|
||||||
|
AND recent.snapshot_date >= CURRENT_DATE - INTERVAL '30 days'
|
||||||
|
) AS sales_velocity,
|
||||||
|
-- Placeholder for sales velocity score (can be calculated based on velocity)
|
||||||
|
0 AS sales_velocity_score,
|
||||||
|
-- Will be updated later by ranking procedure
|
||||||
|
0 AS rank_by_revenue,
|
||||||
|
0 AS rank_by_quantity,
|
||||||
|
0 AS rank_by_profit,
|
||||||
|
-- Receiving data
|
||||||
|
COALESCE(SUM(ds.units_received), 0) AS total_received_quantity,
|
||||||
|
COALESCE(SUM(ds.cost_received), 0) AS total_received_cost,
|
||||||
|
-- Date metrics
|
||||||
|
(SELECT MAX(sd.snapshot_date)
|
||||||
|
FROM public.daily_product_snapshots sd
|
||||||
|
WHERE sd.pid = p.pid AND sd.units_sold > 0
|
||||||
|
) AS last_sold_date,
|
||||||
|
(SELECT MAX(rd.snapshot_date)
|
||||||
|
FROM public.daily_product_snapshots rd
|
||||||
|
WHERE rd.pid = p.pid AND rd.units_received > 0
|
||||||
|
) AS last_received_date,
|
||||||
|
-- Calculate days since last sale/received
|
||||||
|
CASE
|
||||||
|
WHEN (SELECT MAX(sd.snapshot_date)
|
||||||
|
FROM public.daily_product_snapshots sd
|
||||||
|
WHERE sd.pid = p.pid AND sd.units_sold > 0) IS NOT NULL
|
||||||
|
THEN (CURRENT_DATE - (SELECT MAX(sd.snapshot_date)
|
||||||
|
FROM public.daily_product_snapshots sd
|
||||||
|
WHERE sd.pid = p.pid AND sd.units_sold > 0))::integer
|
||||||
|
ELSE NULL
|
||||||
|
END AS days_since_last_sale,
|
||||||
|
CASE
|
||||||
|
WHEN (SELECT MAX(rd.snapshot_date)
|
||||||
|
FROM public.daily_product_snapshots rd
|
||||||
|
WHERE rd.pid = p.pid AND rd.units_received > 0) IS NOT NULL
|
||||||
|
THEN (CURRENT_DATE - (SELECT MAX(rd.snapshot_date)
|
||||||
|
FROM public.daily_product_snapshots rd
|
||||||
|
WHERE rd.pid = p.pid AND rd.units_received > 0))::integer
|
||||||
|
ELSE NULL
|
||||||
|
END AS days_since_last_received,
|
||||||
|
now() -- calculation timestamp
|
||||||
|
FROM public.products p
|
||||||
|
LEFT JOIN public.daily_product_snapshots ds ON p.pid = ds.pid
|
||||||
|
GROUP BY p.pid, p.sku, p.stock_quantity, p.landing_cost_price, p.cost_price, p.price, p.regular_price
|
||||||
|
)
|
||||||
|
|
||||||
|
-- Update the calculate_status table
|
||||||
|
INSERT INTO public.calculate_status (module_name, last_calculation_timestamp)
|
||||||
|
VALUES
|
||||||
|
('daily_snapshots', now()),
|
||||||
|
('product_metrics', now())
|
||||||
|
ON CONFLICT (module_name) DO UPDATE
|
||||||
|
SET last_calculation_timestamp = now();
|
||||||
|
|
||||||
|
-- Finally, update the ranks for products
|
||||||
|
UPDATE public.product_metrics pm SET
|
||||||
|
rank_by_revenue = rev_ranks.rank
|
||||||
|
FROM (
|
||||||
|
SELECT pid, RANK() OVER (ORDER BY net_revenue DESC) AS rank
|
||||||
|
FROM public.product_metrics
|
||||||
|
WHERE net_revenue > 0
|
||||||
|
) rev_ranks
|
||||||
|
WHERE pm.pid = rev_ranks.pid;
|
||||||
|
|
||||||
|
UPDATE public.product_metrics pm SET
|
||||||
|
rank_by_quantity = qty_ranks.rank
|
||||||
|
FROM (
|
||||||
|
SELECT pid, RANK() OVER (ORDER BY total_units_sold DESC) AS rank
|
||||||
|
FROM public.product_metrics
|
||||||
|
WHERE total_units_sold > 0
|
||||||
|
) qty_ranks
|
||||||
|
WHERE pm.pid = qty_ranks.pid;
|
||||||
|
|
||||||
|
UPDATE public.product_metrics pm SET
|
||||||
|
rank_by_profit = profit_ranks.rank
|
||||||
|
FROM (
|
||||||
|
SELECT pid, RANK() OVER (ORDER BY total_profit DESC) AS rank
|
||||||
|
FROM public.product_metrics
|
||||||
|
WHERE total_profit > 0
|
||||||
|
) profit_ranks
|
||||||
|
WHERE pm.pid = profit_ranks.pid;
|
||||||
|
|
||||||
|
-- Return count of products with metrics
|
||||||
|
SELECT COUNT(*) AS product_count FROM public.product_metrics
|
||||||
|
`);
|
||||||
|
};
|
||||||
|
|
||||||
async function populateInitialMetrics() {
|
async function populateInitialMetrics() {
|
||||||
let connection;
|
let connection;
|
||||||
const startTime = Date.now();
|
const startTime = Date.now();
|
||||||
|
|||||||
@@ -2,7 +2,7 @@
|
|||||||
-- historically backfilled daily_product_snapshots and current product/PO data.
|
-- historically backfilled daily_product_snapshots and current product/PO data.
|
||||||
-- Calculates all metrics considering the full available history up to 'yesterday'.
|
-- Calculates all metrics considering the full available history up to 'yesterday'.
|
||||||
-- Run ONCE after backfill_historical_snapshots_final.sql completes successfully.
|
-- Run ONCE after backfill_historical_snapshots_final.sql completes successfully.
|
||||||
-- Dependencies: Core import tables (products, purchase_orders), daily_product_snapshots (historically populated),
|
-- Dependencies: Core import tables (products, purchase_orders, receivings), daily_product_snapshots (historically populated),
|
||||||
-- configuration tables (settings_*), product_metrics table must exist.
|
-- configuration tables (settings_*), product_metrics table must exist.
|
||||||
-- Frequency: Run ONCE.
|
-- Frequency: Run ONCE.
|
||||||
DO $$
|
DO $$
|
||||||
@@ -39,35 +39,26 @@ BEGIN
|
|||||||
-- Calculates current on-order quantities and costs
|
-- Calculates current on-order quantities and costs
|
||||||
SELECT
|
SELECT
|
||||||
pid,
|
pid,
|
||||||
COALESCE(SUM(ordered - received), 0) AS on_order_qty,
|
SUM(ordered) AS on_order_qty,
|
||||||
COALESCE(SUM((ordered - received) * cost_price), 0.00) AS on_order_cost,
|
SUM(ordered * po_cost_price) AS on_order_cost,
|
||||||
MIN(expected_date) AS earliest_expected_date
|
MIN(expected_date) AS earliest_expected_date
|
||||||
FROM public.purchase_orders
|
FROM public.purchase_orders
|
||||||
-- Use the most common statuses representing active, unfulfilled POs
|
-- Use the most common statuses representing active, unfulfilled POs
|
||||||
WHERE status IN ('open', 'partially_received', 'ordered', 'preordered', 'receiving_started', 'electronically_sent', 'electronically_ready_send')
|
WHERE status IN ('created', 'ordered', 'preordered', 'electronically_sent', 'electronically_ready_send', 'receiving_started')
|
||||||
AND (ordered - received) > 0
|
AND status NOT IN ('canceled', 'done')
|
||||||
GROUP BY pid
|
GROUP BY pid
|
||||||
),
|
),
|
||||||
HistoricalDates AS (
|
HistoricalDates AS (
|
||||||
-- Determines key historical dates from orders and PO history (receiving_history)
|
-- Determines key historical dates from orders and receivings
|
||||||
SELECT
|
SELECT
|
||||||
p.pid,
|
p.pid,
|
||||||
MIN(o.date)::date AS date_first_sold,
|
MIN(o.date)::date AS date_first_sold,
|
||||||
MAX(o.date)::date AS max_order_date, -- Used as fallback for date_last_sold
|
MAX(o.date)::date AS max_order_date, -- Used as fallback for date_last_sold
|
||||||
MIN(rh.first_receipt_date) AS date_first_received_calc,
|
MIN(r.received_date)::date AS date_first_received_calc,
|
||||||
MAX(rh.last_receipt_date) AS date_last_received_calc
|
MAX(r.received_date)::date AS date_last_received_calc
|
||||||
FROM public.products p
|
FROM public.products p
|
||||||
LEFT JOIN public.orders o ON p.pid = o.pid AND o.quantity > 0 AND o.status NOT IN ('canceled', 'returned')
|
LEFT JOIN public.orders o ON p.pid = o.pid AND o.quantity > 0 AND o.status NOT IN ('canceled', 'returned')
|
||||||
LEFT JOIN (
|
LEFT JOIN public.receivings r ON p.pid = r.pid
|
||||||
SELECT
|
|
||||||
po.pid,
|
|
||||||
MIN((rh.item->>'received_at')::date) as first_receipt_date,
|
|
||||||
MAX((rh.item->>'received_at')::date) as last_receipt_date
|
|
||||||
FROM public.purchase_orders po
|
|
||||||
CROSS JOIN LATERAL jsonb_array_elements(po.receiving_history) AS rh(item)
|
|
||||||
WHERE jsonb_typeof(po.receiving_history) = 'array' AND jsonb_array_length(po.receiving_history) > 0
|
|
||||||
GROUP BY po.pid
|
|
||||||
) rh ON p.pid = rh.pid
|
|
||||||
GROUP BY p.pid
|
GROUP BY p.pid
|
||||||
),
|
),
|
||||||
SnapshotAggregates AS (
|
SnapshotAggregates AS (
|
||||||
@@ -165,22 +156,23 @@ BEGIN
|
|||||||
LEFT JOIN public.settings_vendor sv ON p.vendor = sv.vendor
|
LEFT JOIN public.settings_vendor sv ON p.vendor = sv.vendor
|
||||||
),
|
),
|
||||||
AvgLeadTime AS (
|
AvgLeadTime AS (
|
||||||
-- Calculate Average Lead Time from historical POs
|
-- Calculate Average Lead Time by joining purchase_orders with receivings
|
||||||
SELECT
|
SELECT
|
||||||
pid,
|
po.pid,
|
||||||
AVG(GREATEST(1,
|
AVG(GREATEST(1,
|
||||||
CASE
|
CASE
|
||||||
WHEN last_received_date IS NOT NULL AND date IS NOT NULL
|
WHEN r.received_date IS NOT NULL AND po.date IS NOT NULL
|
||||||
THEN (last_received_date::date - date::date)
|
THEN (r.received_date::date - po.date::date)
|
||||||
ELSE 1
|
ELSE 1
|
||||||
END
|
END
|
||||||
))::int AS avg_lead_time_days_calc
|
))::int AS avg_lead_time_days_calc
|
||||||
FROM public.purchase_orders
|
FROM public.purchase_orders po
|
||||||
WHERE status = 'received' -- Assumes 'received' marks full receipt
|
JOIN public.receivings r ON r.pid = po.pid
|
||||||
AND last_received_date IS NOT NULL
|
WHERE po.status = 'done' -- Completed POs
|
||||||
AND date IS NOT NULL
|
AND r.received_date IS NOT NULL
|
||||||
AND last_received_date >= date
|
AND po.date IS NOT NULL
|
||||||
GROUP BY pid
|
AND r.received_date >= po.date
|
||||||
|
GROUP BY po.pid
|
||||||
),
|
),
|
||||||
RankedForABC AS (
|
RankedForABC AS (
|
||||||
-- Ranks products based on the configured ABC metric (using historical data)
|
-- Ranks products based on the configured ABC metric (using historical data)
|
||||||
@@ -198,7 +190,7 @@ BEGIN
|
|||||||
WHEN 'sales_30d' THEN COALESCE(sa.sales_30d, 0)
|
WHEN 'sales_30d' THEN COALESCE(sa.sales_30d, 0)
|
||||||
WHEN 'lifetime_revenue' THEN COALESCE(sa.lifetime_revenue, 0)::numeric
|
WHEN 'lifetime_revenue' THEN COALESCE(sa.lifetime_revenue, 0)::numeric
|
||||||
ELSE COALESCE(sa.revenue_30d, 0)
|
ELSE COALESCE(sa.revenue_30d, 0)
|
||||||
END) > 0 -- Exclude zero-value products from ranking
|
END) > 0 -- Only include products with non-zero contribution
|
||||||
),
|
),
|
||||||
CumulativeABC AS (
|
CumulativeABC AS (
|
||||||
-- Calculates cumulative metric values for ABC ranking
|
-- Calculates cumulative metric values for ABC ranking
|
||||||
|
|||||||
@@ -1,6 +1,6 @@
|
|||||||
-- Description: Rebuilds daily product snapshots from scratch using real orders data.
|
-- Description: Rebuilds daily product snapshots from scratch using real orders data.
|
||||||
-- Fixes issues with duplicated/inflated metrics.
|
-- Fixes issues with duplicated/inflated metrics.
|
||||||
-- Dependencies: Core import tables (products, orders, purchase_orders).
|
-- Dependencies: Core import tables (products, orders, receivings).
|
||||||
-- Frequency: One-time run to clear out problematic data.
|
-- Frequency: One-time run to clear out problematic data.
|
||||||
|
|
||||||
DO $$
|
DO $$
|
||||||
@@ -51,65 +51,17 @@ BEGIN
|
|||||||
),
|
),
|
||||||
ReceivingData AS (
|
ReceivingData AS (
|
||||||
SELECT
|
SELECT
|
||||||
po.pid,
|
r.pid,
|
||||||
-- Count POs to ensure we only include products with real activity
|
-- Count receiving documents to ensure we only include products with real activity
|
||||||
COUNT(po.po_id) as po_count,
|
COUNT(DISTINCT r.receiving_id) as receiving_count,
|
||||||
-- Calculate received quantity for this day
|
-- Calculate received quantity for this day
|
||||||
COALESCE(
|
SUM(r.qty_each) AS units_received,
|
||||||
-- First try the received field from purchase_orders table (if received on this date)
|
-- Calculate received cost for this day
|
||||||
SUM(CASE WHEN po.date::date = _date THEN po.received ELSE 0 END),
|
SUM(r.qty_each * r.cost_each) AS cost_received
|
||||||
|
FROM public.receivings r
|
||||||
-- Otherwise try receiving_history JSON
|
WHERE r.received_date::date = _date
|
||||||
SUM(
|
GROUP BY r.pid
|
||||||
CASE
|
HAVING COUNT(DISTINCT r.receiving_id) > 0 OR SUM(r.qty_each) > 0
|
||||||
WHEN (rh.item->>'date')::date = _date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'received_at')::date = _date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'receipt_date')::date = _date THEN (rh.item->>'qty')::numeric
|
|
||||||
ELSE 0
|
|
||||||
END
|
|
||||||
),
|
|
||||||
0
|
|
||||||
) AS units_received,
|
|
||||||
|
|
||||||
COALESCE(
|
|
||||||
-- First try the actual cost_price from purchase_orders
|
|
||||||
SUM(CASE WHEN po.date::date = _date THEN po.received * po.cost_price ELSE 0 END),
|
|
||||||
|
|
||||||
-- Otherwise try receiving_history JSON
|
|
||||||
SUM(
|
|
||||||
CASE
|
|
||||||
WHEN (rh.item->>'date')::date = _date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'received_at')::date = _date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'receipt_date')::date = _date THEN (rh.item->>'qty')::numeric
|
|
||||||
ELSE 0
|
|
||||||
END
|
|
||||||
* COALESCE((rh.item->>'cost')::numeric, po.cost_price)
|
|
||||||
),
|
|
||||||
0.00
|
|
||||||
) AS cost_received
|
|
||||||
FROM public.purchase_orders po
|
|
||||||
LEFT JOIN LATERAL jsonb_array_elements(po.receiving_history) AS rh(item) ON
|
|
||||||
jsonb_typeof(po.receiving_history) = 'array' AND
|
|
||||||
jsonb_array_length(po.receiving_history) > 0 AND
|
|
||||||
(
|
|
||||||
(rh.item->>'date')::date = _date OR
|
|
||||||
(rh.item->>'received_at')::date = _date OR
|
|
||||||
(rh.item->>'receipt_date')::date = _date
|
|
||||||
)
|
|
||||||
-- Include POs with the current date or relevant receiving_history
|
|
||||||
WHERE
|
|
||||||
po.date::date = _date OR
|
|
||||||
jsonb_typeof(po.receiving_history) = 'array' AND
|
|
||||||
jsonb_array_length(po.receiving_history) > 0
|
|
||||||
GROUP BY po.pid
|
|
||||||
HAVING COUNT(po.po_id) > 0 OR SUM(
|
|
||||||
CASE
|
|
||||||
WHEN (rh.item->>'date')::date = _date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'received_at')::date = _date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'receipt_date')::date = _date THEN (rh.item->>'qty')::numeric
|
|
||||||
ELSE 0
|
|
||||||
END
|
|
||||||
) > 0
|
|
||||||
),
|
),
|
||||||
-- Get stock quantities for the day - note this is approximate since we're using current products data
|
-- Get stock quantities for the day - note this is approximate since we're using current products data
|
||||||
StockData AS (
|
StockData AS (
|
||||||
@@ -170,7 +122,7 @@ BEGIN
|
|||||||
FROM SalesData sd
|
FROM SalesData sd
|
||||||
FULL OUTER JOIN ReceivingData rd ON sd.pid = rd.pid
|
FULL OUTER JOIN ReceivingData rd ON sd.pid = rd.pid
|
||||||
LEFT JOIN StockData s ON COALESCE(sd.pid, rd.pid) = s.pid
|
LEFT JOIN StockData s ON COALESCE(sd.pid, rd.pid) = s.pid
|
||||||
WHERE (COALESCE(sd.order_count, 0) > 0 OR COALESCE(rd.po_count, 0) > 0);
|
WHERE (COALESCE(sd.order_count, 0) > 0 OR COALESCE(rd.receiving_count, 0) > 0);
|
||||||
|
|
||||||
-- Get record count for this day
|
-- Get record count for this day
|
||||||
GET DIAGNOSTICS _count = ROW_COUNT;
|
GET DIAGNOSTICS _count = ROW_COUNT;
|
||||||
|
|||||||
@@ -45,19 +45,26 @@ BEGIN
|
|||||||
GROUP BY p.vendor
|
GROUP BY p.vendor
|
||||||
),
|
),
|
||||||
VendorPOAggregates AS (
|
VendorPOAggregates AS (
|
||||||
-- Aggregate PO related stats
|
-- Aggregate PO related stats including lead time calculated from POs to receivings
|
||||||
SELECT
|
SELECT
|
||||||
vendor,
|
po.vendor,
|
||||||
COUNT(DISTINCT po_id) AS po_count_365d,
|
COUNT(DISTINCT po.po_id) AS po_count_365d,
|
||||||
AVG(GREATEST(1, CASE WHEN last_received_date IS NOT NULL AND date IS NOT NULL THEN (last_received_date::date - date::date) ELSE NULL END))::int AS avg_lead_time_days_hist -- Avg lead time from HISTORICAL received POs
|
-- Calculate lead time by averaging the days between PO date and receiving date
|
||||||
FROM public.purchase_orders
|
AVG(GREATEST(1, CASE
|
||||||
WHERE vendor IS NOT NULL AND vendor <> ''
|
WHEN r.received_date IS NOT NULL AND po.date IS NOT NULL
|
||||||
AND date >= CURRENT_DATE - INTERVAL '1 year' -- Look at POs created in the last year
|
THEN (r.received_date::date - po.date::date)
|
||||||
AND status = 'received' -- Only calculate lead time on fully received POs
|
ELSE NULL
|
||||||
AND last_received_date IS NOT NULL
|
END))::int AS avg_lead_time_days_hist -- Avg lead time from HISTORICAL received POs
|
||||||
AND date IS NOT NULL
|
FROM public.purchase_orders po
|
||||||
AND last_received_date >= date
|
-- Join to receivings table to find when items were received
|
||||||
GROUP BY vendor
|
LEFT JOIN public.receivings r ON r.pid = po.pid
|
||||||
|
WHERE po.vendor IS NOT NULL AND po.vendor <> ''
|
||||||
|
AND po.date >= CURRENT_DATE - INTERVAL '1 year' -- Look at POs created in the last year
|
||||||
|
AND po.status = 'done' -- Only calculate lead time on completed POs
|
||||||
|
AND r.received_date IS NOT NULL
|
||||||
|
AND po.date IS NOT NULL
|
||||||
|
AND r.received_date >= po.date
|
||||||
|
GROUP BY po.vendor
|
||||||
),
|
),
|
||||||
AllVendors AS (
|
AllVendors AS (
|
||||||
-- Ensure all vendors from products table are included
|
-- Ensure all vendors from products table are included
|
||||||
|
|||||||
@@ -101,66 +101,20 @@ BEGIN
|
|||||||
),
|
),
|
||||||
ReceivingData AS (
|
ReceivingData AS (
|
||||||
SELECT
|
SELECT
|
||||||
po.pid,
|
r.pid,
|
||||||
-- Track number of POs to ensure we have real data
|
-- Track number of receiving docs to ensure we have real data
|
||||||
COUNT(po.po_id) as po_count,
|
COUNT(DISTINCT r.receiving_id) as receiving_doc_count,
|
||||||
-- Prioritize the actual table fields over the JSON data
|
-- Sum the quantities received on this date
|
||||||
COALESCE(
|
SUM(r.qty_each) AS units_received,
|
||||||
-- First try the received field from purchase_orders table
|
-- Calculate the cost received (qty * cost)
|
||||||
SUM(CASE WHEN po.date::date = _target_date THEN po.received ELSE 0 END),
|
SUM(r.qty_each * r.cost_each) AS cost_received
|
||||||
|
FROM public.receivings r
|
||||||
-- Otherwise fall back to the receiving_history JSON as secondary source
|
WHERE r.received_date::date = _target_date
|
||||||
SUM(
|
-- Optional: Filter out canceled receivings if needed
|
||||||
CASE
|
-- AND r.status <> 'canceled'
|
||||||
WHEN (rh.item->>'date')::date = _target_date THEN (rh.item->>'qty')::numeric
|
GROUP BY r.pid
|
||||||
WHEN (rh.item->>'received_at')::date = _target_date THEN (rh.item->>'qty')::numeric
|
-- Only include products with actual receiving activity
|
||||||
WHEN (rh.item->>'receipt_date')::date = _target_date THEN (rh.item->>'qty')::numeric
|
HAVING COUNT(DISTINCT r.receiving_id) > 0 OR SUM(r.qty_each) > 0
|
||||||
ELSE 0
|
|
||||||
END
|
|
||||||
),
|
|
||||||
0
|
|
||||||
) AS units_received,
|
|
||||||
|
|
||||||
COALESCE(
|
|
||||||
-- First try the actual cost_price from purchase_orders
|
|
||||||
SUM(CASE WHEN po.date::date = _target_date THEN po.received * po.cost_price ELSE 0 END),
|
|
||||||
|
|
||||||
-- Otherwise fall back to receiving_history JSON
|
|
||||||
SUM(
|
|
||||||
CASE
|
|
||||||
WHEN (rh.item->>'date')::date = _target_date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'received_at')::date = _target_date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'receipt_date')::date = _target_date THEN (rh.item->>'qty')::numeric
|
|
||||||
ELSE 0
|
|
||||||
END
|
|
||||||
* COALESCE((rh.item->>'cost')::numeric, po.cost_price)
|
|
||||||
),
|
|
||||||
0.00
|
|
||||||
) AS cost_received
|
|
||||||
FROM public.purchase_orders po
|
|
||||||
LEFT JOIN LATERAL jsonb_array_elements(po.receiving_history) AS rh(item) ON
|
|
||||||
jsonb_typeof(po.receiving_history) = 'array' AND
|
|
||||||
jsonb_array_length(po.receiving_history) > 0 AND
|
|
||||||
(
|
|
||||||
(rh.item->>'date')::date = _target_date OR
|
|
||||||
(rh.item->>'received_at')::date = _target_date OR
|
|
||||||
(rh.item->>'receipt_date')::date = _target_date
|
|
||||||
)
|
|
||||||
-- Include POs with the current date or relevant receiving_history
|
|
||||||
WHERE
|
|
||||||
po.date::date = _target_date OR
|
|
||||||
jsonb_typeof(po.receiving_history) = 'array' AND
|
|
||||||
jsonb_array_length(po.receiving_history) > 0
|
|
||||||
GROUP BY po.pid
|
|
||||||
-- CRITICAL: Only include products with actual receiving activity
|
|
||||||
HAVING COUNT(po.po_id) > 0 OR SUM(
|
|
||||||
CASE
|
|
||||||
WHEN (rh.item->>'date')::date = _target_date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'received_at')::date = _target_date THEN (rh.item->>'qty')::numeric
|
|
||||||
WHEN (rh.item->>'receipt_date')::date = _target_date THEN (rh.item->>'qty')::numeric
|
|
||||||
ELSE 0
|
|
||||||
END
|
|
||||||
) > 0
|
|
||||||
),
|
),
|
||||||
CurrentStock AS (
|
CurrentStock AS (
|
||||||
-- Select current stock values directly from products table
|
-- Select current stock values directly from products table
|
||||||
|
|||||||
@@ -24,14 +24,17 @@ BEGIN
|
|||||||
RAISE NOTICE 'Calculating Average Lead Time...';
|
RAISE NOTICE 'Calculating Average Lead Time...';
|
||||||
WITH LeadTimes AS (
|
WITH LeadTimes AS (
|
||||||
SELECT
|
SELECT
|
||||||
pid,
|
po.pid,
|
||||||
AVG(GREATEST(1, (last_received_date::date - date::date))) AS avg_days -- Use GREATEST(1,...) to avoid 0 or negative days
|
-- Calculate lead time by looking at when items ordered on POs were received
|
||||||
FROM public.purchase_orders
|
AVG(GREATEST(1, (r.received_date::date - po.date::date))) AS avg_days -- Use GREATEST(1,...) to avoid 0 or negative days
|
||||||
WHERE status = 'received' -- Or potentially 'full_received' if using that status
|
FROM public.purchase_orders po
|
||||||
AND last_received_date IS NOT NULL
|
-- Join to receivings table to find actual receipts
|
||||||
AND date IS NOT NULL
|
JOIN public.receivings r ON r.pid = po.pid
|
||||||
AND last_received_date >= date -- Ensure received date is not before order date
|
WHERE po.status = 'done' -- Only include completed POs
|
||||||
GROUP BY pid
|
AND r.received_date >= po.date -- Ensure received date is not before order date
|
||||||
|
-- Optional: add check to make sure receiving is related to PO if you have source_po_id
|
||||||
|
-- AND (r.source_po_id = po.po_id OR r.source_po_id IS NULL)
|
||||||
|
GROUP BY po.pid
|
||||||
)
|
)
|
||||||
UPDATE public.product_metrics pm
|
UPDATE public.product_metrics pm
|
||||||
SET avg_lead_time_days = lt.avg_days::int
|
SET avg_lead_time_days = lt.avg_days::int
|
||||||
|
|||||||
@@ -64,12 +64,12 @@ BEGIN
|
|||||||
OnOrderInfo AS (
|
OnOrderInfo AS (
|
||||||
SELECT
|
SELECT
|
||||||
pid,
|
pid,
|
||||||
COALESCE(SUM(ordered - received), 0) AS on_order_qty,
|
SUM(ordered) AS on_order_qty,
|
||||||
COALESCE(SUM((ordered - received) * cost_price), 0.00) AS on_order_cost,
|
SUM(ordered * po_cost_price) AS on_order_cost,
|
||||||
MIN(expected_date) AS earliest_expected_date
|
MIN(expected_date) AS earliest_expected_date
|
||||||
FROM public.purchase_orders
|
FROM public.purchase_orders
|
||||||
WHERE status IN ('open', 'partially_received', 'ordered', 'preordered', 'receiving_started', 'electronically_sent', 'electronically_ready_send') -- Adjust based on your status workflow representing active POs not fully received
|
WHERE status IN ('created', 'ordered', 'preordered', 'electronically_sent', 'electronically_ready_send', 'receiving_started')
|
||||||
AND (ordered - received) > 0
|
AND status NOT IN ('canceled', 'done')
|
||||||
GROUP BY pid
|
GROUP BY pid
|
||||||
),
|
),
|
||||||
HistoricalDates AS (
|
HistoricalDates AS (
|
||||||
@@ -80,45 +80,14 @@ BEGIN
|
|||||||
MIN(o.date)::date AS date_first_sold,
|
MIN(o.date)::date AS date_first_sold,
|
||||||
MAX(o.date)::date AS max_order_date, -- Use MAX for potential recalc of date_last_sold
|
MAX(o.date)::date AS max_order_date, -- Use MAX for potential recalc of date_last_sold
|
||||||
|
|
||||||
-- For first received date, try table data first then fall back to JSON
|
-- For first received, use the new receivings table
|
||||||
COALESCE(
|
MIN(r.received_date)::date AS date_first_received_calc,
|
||||||
MIN(po.date)::date, -- Try purchase_order date first
|
|
||||||
MIN(rh.first_receipt_date) -- Fall back to JSON data if needed
|
|
||||||
) AS date_first_received_calc,
|
|
||||||
|
|
||||||
-- If we only have one receipt date (first = last), use that for last_received too
|
-- For last received, use the new receivings table
|
||||||
COALESCE(
|
MAX(r.received_date)::date AS date_last_received_calc
|
||||||
MAX(po.date)::date, -- Try purchase_order date first
|
|
||||||
NULLIF(MAX(rh.last_receipt_date), NULL),
|
|
||||||
MIN(rh.first_receipt_date)
|
|
||||||
) AS date_last_received_calc
|
|
||||||
FROM public.products p
|
FROM public.products p
|
||||||
LEFT JOIN public.orders o ON p.pid = o.pid AND o.quantity > 0 AND o.status NOT IN ('canceled', 'returned')
|
LEFT JOIN public.orders o ON p.pid = o.pid AND o.quantity > 0 AND o.status NOT IN ('canceled', 'returned')
|
||||||
LEFT JOIN public.purchase_orders po ON p.pid = po.pid AND po.received > 0
|
LEFT JOIN public.receivings r ON p.pid = r.pid
|
||||||
LEFT JOIN (
|
|
||||||
SELECT
|
|
||||||
po.pid,
|
|
||||||
MIN(
|
|
||||||
CASE
|
|
||||||
WHEN rh.item->>'date' IS NOT NULL THEN (rh.item->>'date')::date
|
|
||||||
WHEN rh.item->>'received_at' IS NOT NULL THEN (rh.item->>'received_at')::date
|
|
||||||
WHEN rh.item->>'receipt_date' IS NOT NULL THEN (rh.item->>'receipt_date')::date
|
|
||||||
ELSE NULL
|
|
||||||
END
|
|
||||||
) as first_receipt_date,
|
|
||||||
MAX(
|
|
||||||
CASE
|
|
||||||
WHEN rh.item->>'date' IS NOT NULL THEN (rh.item->>'date')::date
|
|
||||||
WHEN rh.item->>'received_at' IS NOT NULL THEN (rh.item->>'received_at')::date
|
|
||||||
WHEN rh.item->>'receipt_date' IS NOT NULL THEN (rh.item->>'receipt_date')::date
|
|
||||||
ELSE NULL
|
|
||||||
END
|
|
||||||
) as last_receipt_date
|
|
||||||
FROM public.purchase_orders po
|
|
||||||
CROSS JOIN LATERAL jsonb_array_elements(po.receiving_history) AS rh(item)
|
|
||||||
WHERE jsonb_typeof(po.receiving_history) = 'array' AND jsonb_array_length(po.receiving_history) > 0
|
|
||||||
GROUP BY po.pid
|
|
||||||
) rh ON p.pid = rh.pid
|
|
||||||
GROUP BY p.pid
|
GROUP BY p.pid
|
||||||
),
|
),
|
||||||
SnapshotAggregates AS (
|
SnapshotAggregates AS (
|
||||||
|
|||||||
@@ -110,36 +110,31 @@ router.get('/purchase/metrics', async (req, res) => {
|
|||||||
const { rows: [poMetrics] } = await executeQuery(`
|
const { rows: [poMetrics] } = await executeQuery(`
|
||||||
SELECT
|
SELECT
|
||||||
COALESCE(COUNT(DISTINCT CASE
|
COALESCE(COUNT(DISTINCT CASE
|
||||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
WHEN po.status NOT IN ('canceled', 'done')
|
||||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
|
||||||
THEN po.po_id
|
THEN po.po_id
|
||||||
END), 0)::integer as active_pos,
|
END), 0)::integer as active_pos,
|
||||||
COALESCE(COUNT(DISTINCT CASE
|
COALESCE(COUNT(DISTINCT CASE
|
||||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
WHEN po.status NOT IN ('canceled', 'done')
|
||||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
|
||||||
AND po.expected_date < CURRENT_DATE
|
AND po.expected_date < CURRENT_DATE
|
||||||
THEN po.po_id
|
THEN po.po_id
|
||||||
END), 0)::integer as overdue_pos,
|
END), 0)::integer as overdue_pos,
|
||||||
COALESCE(SUM(CASE
|
COALESCE(SUM(CASE
|
||||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
WHEN po.status NOT IN ('canceled', 'done')
|
||||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
|
||||||
THEN po.ordered
|
THEN po.ordered
|
||||||
ELSE 0
|
ELSE 0
|
||||||
END), 0)::integer as total_units,
|
END), 0)::integer as total_units,
|
||||||
ROUND(COALESCE(SUM(CASE
|
ROUND(COALESCE(SUM(CASE
|
||||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
WHEN po.status NOT IN ('canceled', 'done')
|
||||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
THEN po.ordered * po.po_cost_price
|
||||||
THEN po.ordered * po.cost_price
|
|
||||||
ELSE 0
|
ELSE 0
|
||||||
END), 0)::numeric, 3) as total_cost,
|
END), 0)::numeric, 3) as total_cost,
|
||||||
ROUND(COALESCE(SUM(CASE
|
ROUND(COALESCE(SUM(CASE
|
||||||
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
WHEN po.status NOT IN ('canceled', 'done')
|
||||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
|
||||||
THEN po.ordered * pm.current_price
|
THEN po.ordered * pm.current_price
|
||||||
ELSE 0
|
ELSE 0
|
||||||
END), 0)::numeric, 3) as total_retail
|
END), 0)::numeric, 3) as total_retail
|
||||||
@@ -152,15 +147,14 @@ router.get('/purchase/metrics', async (req, res) => {
|
|||||||
po.vendor,
|
po.vendor,
|
||||||
COUNT(DISTINCT po.po_id)::integer as orders,
|
COUNT(DISTINCT po.po_id)::integer as orders,
|
||||||
COALESCE(SUM(po.ordered), 0)::integer as units,
|
COALESCE(SUM(po.ordered), 0)::integer as units,
|
||||||
ROUND(COALESCE(SUM(po.ordered * po.cost_price), 0)::numeric, 3) as cost,
|
ROUND(COALESCE(SUM(po.ordered * po.po_cost_price), 0)::numeric, 3) as cost,
|
||||||
ROUND(COALESCE(SUM(po.ordered * pm.current_price), 0)::numeric, 3) as retail
|
ROUND(COALESCE(SUM(po.ordered * pm.current_price), 0)::numeric, 3) as retail
|
||||||
FROM purchase_orders po
|
FROM purchase_orders po
|
||||||
JOIN product_metrics pm ON po.pid = pm.pid
|
JOIN product_metrics pm ON po.pid = pm.pid
|
||||||
WHERE po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
|
WHERE po.status NOT IN ('canceled', 'done')
|
||||||
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
AND po.date >= CURRENT_DATE - INTERVAL '6 months'
|
||||||
AND NOT (po.date < CURRENT_DATE - INTERVAL '1 month' AND po.received >= po.ordered * 0.9)
|
|
||||||
GROUP BY po.vendor
|
GROUP BY po.vendor
|
||||||
HAVING ROUND(COALESCE(SUM(po.ordered * po.cost_price), 0)::numeric, 3) > 0
|
HAVING ROUND(COALESCE(SUM(po.ordered * po.po_cost_price), 0)::numeric, 3) > 0
|
||||||
ORDER BY cost DESC
|
ORDER BY cost DESC
|
||||||
`);
|
`);
|
||||||
|
|
||||||
|
|||||||
@@ -26,23 +26,6 @@ const STATUS_MAPPING = {
|
|||||||
'done': STATUS.DONE
|
'done': STATUS.DONE
|
||||||
};
|
};
|
||||||
|
|
||||||
const RECEIVING_STATUS = {
|
|
||||||
CANCELED: 0,
|
|
||||||
CREATED: 1,
|
|
||||||
PARTIAL_RECEIVED: 30,
|
|
||||||
FULL_RECEIVED: 40,
|
|
||||||
PAID: 50
|
|
||||||
};
|
|
||||||
|
|
||||||
// Receiving status mapping from database string values to frontend numeric codes
|
|
||||||
const RECEIVING_STATUS_MAPPING = {
|
|
||||||
'canceled': RECEIVING_STATUS.CANCELED,
|
|
||||||
'created': RECEIVING_STATUS.CREATED,
|
|
||||||
'partial_received': RECEIVING_STATUS.PARTIAL_RECEIVED,
|
|
||||||
'full_received': RECEIVING_STATUS.FULL_RECEIVED,
|
|
||||||
'paid': RECEIVING_STATUS.PAID
|
|
||||||
};
|
|
||||||
|
|
||||||
// Helper for SQL status value comparison with string values in DB
|
// Helper for SQL status value comparison with string values in DB
|
||||||
function getStatusWhereClause(statusNum) {
|
function getStatusWhereClause(statusNum) {
|
||||||
const dbStatuses = Object.keys(STATUS_MAPPING).filter(key =>
|
const dbStatuses = Object.keys(STATUS_MAPPING).filter(key =>
|
||||||
@@ -98,22 +81,32 @@ router.get('/', async (req, res) => {
|
|||||||
SELECT
|
SELECT
|
||||||
po_id,
|
po_id,
|
||||||
SUM(ordered) as total_ordered,
|
SUM(ordered) as total_ordered,
|
||||||
SUM(received) as total_received,
|
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost
|
||||||
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_cost
|
|
||||||
FROM purchase_orders po
|
FROM purchase_orders po
|
||||||
WHERE ${whereClause}
|
WHERE ${whereClause}
|
||||||
GROUP BY po_id
|
GROUP BY po_id
|
||||||
|
),
|
||||||
|
receiving_totals AS (
|
||||||
|
SELECT
|
||||||
|
r.receiving_id,
|
||||||
|
po.po_id,
|
||||||
|
SUM(r.qty_each) as total_received
|
||||||
|
FROM receivings r
|
||||||
|
JOIN purchase_orders po ON r.pid = po.pid
|
||||||
|
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
||||||
|
GROUP BY r.receiving_id, po.po_id
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
COUNT(DISTINCT po_id) as order_count,
|
COUNT(DISTINCT po.po_id) as order_count,
|
||||||
SUM(total_ordered) as total_ordered,
|
SUM(po.total_ordered) as total_ordered,
|
||||||
SUM(total_received) as total_received,
|
COALESCE(SUM(r.total_received), 0) as total_received,
|
||||||
ROUND(
|
ROUND(
|
||||||
(SUM(total_received)::numeric / NULLIF(SUM(total_ordered), 0)), 3
|
(COALESCE(SUM(r.total_received), 0)::numeric / NULLIF(SUM(po.total_ordered), 0)), 3
|
||||||
) as fulfillment_rate,
|
) as fulfillment_rate,
|
||||||
ROUND(SUM(total_cost)::numeric, 3) as total_value,
|
ROUND(SUM(po.total_cost)::numeric, 3) as total_value,
|
||||||
ROUND(AVG(total_cost)::numeric, 3) as avg_cost
|
ROUND(AVG(po.total_cost)::numeric, 3) as avg_cost
|
||||||
FROM po_totals
|
FROM po_totals po
|
||||||
|
LEFT JOIN receiving_totals r ON po.po_id = r.po_id
|
||||||
`, params);
|
`, params);
|
||||||
|
|
||||||
// Get total count for pagination
|
// Get total count for pagination
|
||||||
@@ -157,30 +150,36 @@ router.get('/', async (req, res) => {
|
|||||||
vendor,
|
vendor,
|
||||||
date,
|
date,
|
||||||
status,
|
status,
|
||||||
receiving_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 * cost_price)::numeric, 3) as total_cost,
|
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost
|
||||||
SUM(received) as total_received,
|
|
||||||
ROUND(
|
|
||||||
(SUM(received)::numeric / NULLIF(SUM(ordered), 0)), 3
|
|
||||||
) as fulfillment_rate
|
|
||||||
FROM purchase_orders po
|
FROM purchase_orders po
|
||||||
WHERE ${whereClause}
|
WHERE ${whereClause}
|
||||||
GROUP BY po_id, vendor, date, status, receiving_status
|
GROUP BY po_id, vendor, date, status
|
||||||
|
),
|
||||||
|
receiving_totals AS (
|
||||||
|
SELECT
|
||||||
|
po.po_id,
|
||||||
|
SUM(r.qty_each) as total_received
|
||||||
|
FROM receivings r
|
||||||
|
JOIN purchase_orders po ON r.pid = po.pid
|
||||||
|
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
||||||
|
GROUP BY po.po_id
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
pt.po_id as id,
|
pt.po_id as id,
|
||||||
pt.vendor as vendor_name,
|
pt.vendor as vendor_name,
|
||||||
to_char(pt.date, 'YYYY-MM-DD') as order_date,
|
to_char(pt.date, 'YYYY-MM-DD') as order_date,
|
||||||
pt.status,
|
pt.status,
|
||||||
pt.receiving_status,
|
|
||||||
pt.total_items,
|
pt.total_items,
|
||||||
pt.total_quantity,
|
pt.total_quantity,
|
||||||
pt.total_cost,
|
pt.total_cost,
|
||||||
pt.total_received,
|
COALESCE(rt.total_received, 0) as total_received,
|
||||||
pt.fulfillment_rate
|
ROUND(
|
||||||
|
(COALESCE(rt.total_received, 0)::numeric / NULLIF(pt.total_quantity, 0)), 3
|
||||||
|
) as fulfillment_rate
|
||||||
FROM po_totals pt
|
FROM po_totals pt
|
||||||
|
LEFT JOIN receiving_totals rt ON pt.po_id = rt.po_id
|
||||||
ORDER BY ${orderByClause}
|
ORDER BY ${orderByClause}
|
||||||
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
|
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
|
||||||
`, [...params, Number(limit), offset]);
|
`, [...params, Number(limit), offset]);
|
||||||
@@ -230,7 +229,6 @@ router.get('/', async (req, res) => {
|
|||||||
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
|
status: STATUS_MAPPING[order.status] || 0, // Map string status to numeric code
|
||||||
receiving_status: RECEIVING_STATUS_MAPPING[order.receiving_status] || 0, // Map string receiving status to numeric code
|
|
||||||
total_items: Number(order.total_items) || 0,
|
total_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,
|
||||||
@@ -274,23 +272,44 @@ router.get('/vendor-metrics', async (req, res) => {
|
|||||||
const pool = req.app.locals.pool;
|
const pool = req.app.locals.pool;
|
||||||
|
|
||||||
const { rows: metrics } = await pool.query(`
|
const { rows: metrics } = await pool.query(`
|
||||||
WITH delivery_metrics AS (
|
WITH po_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
vendor,
|
vendor,
|
||||||
po_id,
|
po_id,
|
||||||
ordered,
|
ordered,
|
||||||
received,
|
po_cost_price,
|
||||||
cost_price,
|
date
|
||||||
CASE
|
|
||||||
WHEN status IN ('receiving_started', 'done')
|
|
||||||
AND receiving_status IN ('partial_received', 'full_received', 'paid')
|
|
||||||
AND received_date IS NOT NULL AND date IS NOT NULL
|
|
||||||
THEN (received_date - date)::integer
|
|
||||||
ELSE NULL
|
|
||||||
END as delivery_days
|
|
||||||
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
|
||||||
|
),
|
||||||
|
receiving_data AS (
|
||||||
|
SELECT
|
||||||
|
po.po_id,
|
||||||
|
po.vendor,
|
||||||
|
r.pid,
|
||||||
|
r.qty_each as received,
|
||||||
|
r.received_date
|
||||||
|
FROM receivings r
|
||||||
|
JOIN purchase_orders po ON r.pid = po.pid
|
||||||
|
WHERE po.vendor IS NOT NULL AND po.vendor != ''
|
||||||
|
AND po.status != 'canceled'
|
||||||
|
),
|
||||||
|
delivery_metrics AS (
|
||||||
|
SELECT
|
||||||
|
po.vendor,
|
||||||
|
po.po_id,
|
||||||
|
po.ordered,
|
||||||
|
COALESCE(SUM(r.received), 0) as received,
|
||||||
|
po.po_cost_price,
|
||||||
|
CASE
|
||||||
|
WHEN MIN(r.received_date) IS NOT NULL AND po.date IS NOT NULL
|
||||||
|
THEN (MIN(r.received_date) - po.date)::integer
|
||||||
|
ELSE NULL
|
||||||
|
END as delivery_days
|
||||||
|
FROM po_data po
|
||||||
|
LEFT JOIN receiving_data r ON po.po_id = r.po_id
|
||||||
|
GROUP BY po.vendor, po.po_id, po.ordered, po.po_cost_price, po.date
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
vendor as vendor_name,
|
vendor as vendor_name,
|
||||||
@@ -301,9 +320,9 @@ router.get('/vendor-metrics', async (req, res) => {
|
|||||||
(SUM(received)::numeric / NULLIF(SUM(ordered), 0)), 3
|
(SUM(received)::numeric / NULLIF(SUM(ordered), 0)), 3
|
||||||
) as fulfillment_rate,
|
) as fulfillment_rate,
|
||||||
ROUND(
|
ROUND(
|
||||||
(SUM(ordered * cost_price)::numeric / NULLIF(SUM(ordered), 0)), 2
|
(SUM(ordered * po_cost_price)::numeric / NULLIF(SUM(ordered), 0)), 2
|
||||||
) as avg_unit_cost,
|
) as avg_unit_cost,
|
||||||
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_spend,
|
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_spend,
|
||||||
ROUND(
|
ROUND(
|
||||||
AVG(NULLIF(delivery_days, 0))::numeric, 1
|
AVG(NULLIF(delivery_days, 0))::numeric, 1
|
||||||
) as avg_delivery_days
|
) as avg_delivery_days
|
||||||
@@ -343,11 +362,9 @@ router.get('/cost-analysis', async (req, res) => {
|
|||||||
SELECT
|
SELECT
|
||||||
c.name as category,
|
c.name as category,
|
||||||
po.pid,
|
po.pid,
|
||||||
po.cost_price,
|
po.po_cost_price as cost_price,
|
||||||
po.ordered,
|
po.ordered,
|
||||||
po.received,
|
po.status
|
||||||
po.status,
|
|
||||||
po.receiving_status
|
|
||||||
FROM purchase_orders po
|
FROM purchase_orders po
|
||||||
JOIN product_categories pc ON po.pid = pc.pid
|
JOIN product_categories pc ON po.pid = pc.pid
|
||||||
JOIN categories c ON pc.cat_id = c.cat_id
|
JOIN categories c ON pc.cat_id = c.cat_id
|
||||||
@@ -411,7 +428,7 @@ router.get('/cost-analysis', async (req, res) => {
|
|||||||
}
|
}
|
||||||
});
|
});
|
||||||
|
|
||||||
// Get receiving status metrics
|
// Get order status metrics
|
||||||
router.get('/receiving-status', async (req, res) => {
|
router.get('/receiving-status', async (req, res) => {
|
||||||
try {
|
try {
|
||||||
const pool = req.app.locals.pool;
|
const pool = req.app.locals.pool;
|
||||||
@@ -421,36 +438,44 @@ router.get('/receiving-status', async (req, res) => {
|
|||||||
SELECT
|
SELECT
|
||||||
po_id,
|
po_id,
|
||||||
status,
|
status,
|
||||||
receiving_status,
|
|
||||||
SUM(ordered) as total_ordered,
|
SUM(ordered) as total_ordered,
|
||||||
SUM(received) as total_received,
|
ROUND(SUM(ordered * po_cost_price)::numeric, 3) as total_cost
|
||||||
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_cost
|
|
||||||
FROM purchase_orders
|
FROM purchase_orders
|
||||||
WHERE status != 'canceled'
|
WHERE status != 'canceled'
|
||||||
GROUP BY po_id, status, receiving_status
|
GROUP BY po_id, status
|
||||||
|
),
|
||||||
|
receiving_totals AS (
|
||||||
|
SELECT
|
||||||
|
po.po_id,
|
||||||
|
SUM(r.qty_each) as total_received
|
||||||
|
FROM receivings r
|
||||||
|
JOIN purchase_orders po ON r.pid = po.pid
|
||||||
|
WHERE po.po_id IN (SELECT po_id FROM po_totals)
|
||||||
|
GROUP BY po.po_id
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
COUNT(DISTINCT po_id) as order_count,
|
COUNT(DISTINCT po.po_id) as order_count,
|
||||||
SUM(total_ordered) as total_ordered,
|
SUM(po.total_ordered) as total_ordered,
|
||||||
SUM(total_received) as total_received,
|
COALESCE(SUM(r.total_received), 0) as total_received,
|
||||||
ROUND(
|
ROUND(
|
||||||
SUM(total_received) / NULLIF(SUM(total_ordered), 0), 3
|
COALESCE(SUM(r.total_received), 0) / NULLIF(SUM(po.total_ordered), 0), 3
|
||||||
) as fulfillment_rate,
|
) as fulfillment_rate,
|
||||||
ROUND(SUM(total_cost)::numeric, 3) as total_value,
|
ROUND(SUM(po.total_cost)::numeric, 3) as total_value,
|
||||||
ROUND(AVG(total_cost)::numeric, 3) as avg_cost,
|
ROUND(AVG(po.total_cost)::numeric, 3) as avg_cost,
|
||||||
COUNT(DISTINCT CASE
|
COUNT(DISTINCT CASE
|
||||||
WHEN receiving_status = 'created' THEN po_id
|
WHEN po.status = 'created' THEN po.po_id
|
||||||
END) as pending_count,
|
END) as pending_count,
|
||||||
COUNT(DISTINCT CASE
|
COUNT(DISTINCT CASE
|
||||||
WHEN receiving_status = 'partial_received' THEN po_id
|
WHEN po.status = 'receiving_started' THEN po.po_id
|
||||||
END) as partial_count,
|
END) as partial_count,
|
||||||
COUNT(DISTINCT CASE
|
COUNT(DISTINCT CASE
|
||||||
WHEN receiving_status IN ('full_received', 'paid') THEN po_id
|
WHEN po.status = 'done' THEN po.po_id
|
||||||
END) as completed_count,
|
END) as completed_count,
|
||||||
COUNT(DISTINCT CASE
|
COUNT(DISTINCT CASE
|
||||||
WHEN receiving_status = 'canceled' THEN po_id
|
WHEN po.status = 'canceled' THEN po.po_id
|
||||||
END) as canceled_count
|
END) as canceled_count
|
||||||
FROM po_totals
|
FROM po_totals po
|
||||||
|
LEFT JOIN receiving_totals r ON po.po_id = r.po_id
|
||||||
`);
|
`);
|
||||||
|
|
||||||
// Parse numeric values
|
// Parse numeric values
|
||||||
@@ -482,22 +507,41 @@ router.get('/order-vs-received', async (req, res) => {
|
|||||||
const pool = req.app.locals.pool;
|
const pool = req.app.locals.pool;
|
||||||
|
|
||||||
const { rows: quantities } = await pool.query(`
|
const { rows: quantities } = await pool.query(`
|
||||||
|
WITH order_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
p.pid as product_id,
|
p.pid,
|
||||||
p.title as product,
|
p.title,
|
||||||
p.SKU as sku,
|
p.SKU,
|
||||||
SUM(po.ordered) as ordered_quantity,
|
SUM(po.ordered) as ordered_quantity,
|
||||||
SUM(po.received) as received_quantity,
|
|
||||||
ROUND(
|
|
||||||
SUM(po.received) / NULLIF(SUM(po.ordered), 0) * 100, 1
|
|
||||||
) as fulfillment_rate,
|
|
||||||
COUNT(DISTINCT po.po_id) as order_count
|
COUNT(DISTINCT po.po_id) as order_count
|
||||||
FROM products p
|
FROM products p
|
||||||
JOIN purchase_orders po ON p.pid = po.pid
|
JOIN purchase_orders po ON p.pid = po.pid
|
||||||
WHERE po.date >= (CURRENT_DATE - INTERVAL '90 days')
|
WHERE po.date >= (CURRENT_DATE - INTERVAL '90 days')
|
||||||
GROUP BY p.pid, p.title, p.SKU
|
GROUP BY p.pid, p.title, p.SKU
|
||||||
HAVING COUNT(DISTINCT po.po_id) > 0
|
),
|
||||||
ORDER BY SUM(po.ordered) DESC
|
receiving_data AS (
|
||||||
|
SELECT
|
||||||
|
r.pid,
|
||||||
|
SUM(r.qty_each) as received_quantity
|
||||||
|
FROM receivings r
|
||||||
|
JOIN products p ON r.pid = p.pid
|
||||||
|
WHERE r.received_date >= (CURRENT_DATE - INTERVAL '90 days')
|
||||||
|
GROUP BY r.pid
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
o.pid as product_id,
|
||||||
|
o.title as product,
|
||||||
|
o.SKU as sku,
|
||||||
|
o.ordered_quantity,
|
||||||
|
COALESCE(r.received_quantity, 0) as received_quantity,
|
||||||
|
ROUND(
|
||||||
|
COALESCE(r.received_quantity, 0) / NULLIF(o.ordered_quantity, 0) * 100, 1
|
||||||
|
) as fulfillment_rate,
|
||||||
|
o.order_count
|
||||||
|
FROM order_data o
|
||||||
|
LEFT JOIN receiving_data r ON o.pid = r.pid
|
||||||
|
HAVING o.order_count > 0
|
||||||
|
ORDER BY o.ordered_quantity DESC
|
||||||
LIMIT 20
|
LIMIT 20
|
||||||
`);
|
`);
|
||||||
|
|
||||||
|
|||||||
@@ -49,7 +49,6 @@ interface PurchaseOrder {
|
|||||||
vendor_name: string;
|
vendor_name: string;
|
||||||
order_date: string;
|
order_date: string;
|
||||||
status: number;
|
status: number;
|
||||||
receiving_status: number;
|
|
||||||
total_items: number;
|
total_items: number;
|
||||||
total_quantity: number;
|
total_quantity: number;
|
||||||
total_cost: number;
|
total_cost: number;
|
||||||
@@ -231,7 +230,6 @@ export default function PurchaseOrders() {
|
|||||||
let processedOrder = {
|
let processedOrder = {
|
||||||
...order,
|
...order,
|
||||||
status: Number(order.status),
|
status: Number(order.status),
|
||||||
receiving_status: Number(order.receiving_status),
|
|
||||||
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,
|
||||||
@@ -289,22 +287,7 @@ export default function PurchaseOrders() {
|
|||||||
}
|
}
|
||||||
};
|
};
|
||||||
|
|
||||||
const getStatusBadge = (status: number, receivingStatus: number) => {
|
const getStatusBadge = (status: number) => {
|
||||||
// If the PO is canceled, show that status
|
|
||||||
if (status === PurchaseOrderStatus.Canceled) {
|
|
||||||
return <Badge variant={getPurchaseOrderStatusVariant(status)}>
|
|
||||||
{getPurchaseOrderStatusLabel(status)}
|
|
||||||
</Badge>;
|
|
||||||
}
|
|
||||||
|
|
||||||
// If receiving has started, show receiving status
|
|
||||||
if (status >= PurchaseOrderStatus.ReceivingStarted) {
|
|
||||||
return <Badge variant={getReceivingStatusVariant(receivingStatus)}>
|
|
||||||
{getReceivingStatusLabel(receivingStatus)}
|
|
||||||
</Badge>;
|
|
||||||
}
|
|
||||||
|
|
||||||
// Otherwise show PO status
|
|
||||||
return <Badge variant={getPurchaseOrderStatusVariant(status)}>
|
return <Badge variant={getPurchaseOrderStatusVariant(status)}>
|
||||||
{getPurchaseOrderStatusLabel(status)}
|
{getPurchaseOrderStatusLabel(status)}
|
||||||
</Badge>;
|
</Badge>;
|
||||||
@@ -640,7 +623,7 @@ export default function PurchaseOrders() {
|
|||||||
<TableCell>{po.id}</TableCell>
|
<TableCell>{po.id}</TableCell>
|
||||||
<TableCell>{po.vendor_name}</TableCell>
|
<TableCell>{po.vendor_name}</TableCell>
|
||||||
<TableCell>{new Date(po.order_date).toLocaleDateString()}</TableCell>
|
<TableCell>{new Date(po.order_date).toLocaleDateString()}</TableCell>
|
||||||
<TableCell>{getStatusBadge(po.status, po.receiving_status)}</TableCell>
|
<TableCell>{getStatusBadge(po.status)}</TableCell>
|
||||||
<TableCell>{po.total_items.toLocaleString()}</TableCell>
|
<TableCell>{po.total_items.toLocaleString()}</TableCell>
|
||||||
<TableCell>{po.total_quantity.toLocaleString()}</TableCell>
|
<TableCell>{po.total_quantity.toLocaleString()}</TableCell>
|
||||||
<TableCell>{formatCurrency(po.total_cost)}</TableCell>
|
<TableCell>{formatCurrency(po.total_cost)}</TableCell>
|
||||||
|
|||||||
Reference in New Issue
Block a user