Update calculate scripts and routes for PO table split
This commit is contained in:
@@ -91,6 +91,287 @@ function cancelCalculation() {
|
||||
process.on('SIGTERM', 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() {
|
||||
let connection;
|
||||
const startTime = Date.now();
|
||||
|
||||
Reference in New Issue
Block a user