Add metrics historical backfill scripts, fix up all new metrics calc queries and add combined script to run
This commit is contained in:
@@ -35,18 +35,59 @@ BEGIN
|
||||
FROM public.products p -- Start from products to include those with no orders today
|
||||
LEFT JOIN public.orders o
|
||||
ON p.pid = o.pid
|
||||
AND o.date >= _target_date -- Filter orders for the target date
|
||||
AND o.date < _target_date + INTERVAL '1 day'
|
||||
AND o.date::date = _target_date -- Cast to date to ensure compatibility regardless of original type
|
||||
GROUP BY p.pid, p.sku
|
||||
),
|
||||
ReceivingData AS (
|
||||
SELECT
|
||||
po.pid,
|
||||
COALESCE(SUM((rh.item->>'qty')::numeric), 0) AS units_received,
|
||||
COALESCE(SUM((rh.item->>'qty')::numeric * COALESCE((rh.item->>'cost')::numeric, po.cost_price)), 0.00) AS cost_received
|
||||
-- Prioritize the actual table fields over the JSON data
|
||||
COALESCE(
|
||||
-- First try the received field from purchase_orders table
|
||||
SUM(CASE WHEN po.date::date = _target_date THEN po.received ELSE 0 END),
|
||||
|
||||
-- Otherwise fall back to the receiving_history JSON as secondary source
|
||||
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
|
||||
) 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
|
||||
CROSS JOIN LATERAL jsonb_array_elements(po.receiving_history) AS rh(item)
|
||||
WHERE (rh.item->>'received_at')::date = _target_date -- Filter receipts for the target date
|
||||
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
|
||||
),
|
||||
CurrentStock AS (
|
||||
|
||||
Reference in New Issue
Block a user