92 lines
2.9 KiB
PL/PgSQL
92 lines
2.9 KiB
PL/PgSQL
/*
|
|
you have to be able to isolate the original plan in order for this to work
|
|
if you start with a clean 1+11 its not going to work
|
|
this script targets the 'plan' iteration and the 'diff' iteration
|
|
if plan orders have already been 'diffed' no need to build an additional diff
|
|
will have to be side-by-side roll-up of these two iterations
|
|
*/
|
|
|
|
|
|
--BEGIN;
|
|
--\timing
|
|
--CREATE TABLE IF NOT EXISTS rlarp.osmf_stage AS (SELECT * FROM rlarp.osmf_dev) WITH no data;
|
|
--will not match actuals exactly due to short-ships
|
|
|
|
|
|
WITH
|
|
---these dates will have to be syncronized with the forecast build-----------
|
|
tdr AS (
|
|
SELECT
|
|
-----------actuals into baseline-------------------------------------
|
|
DATERANGE('2020-06-01','2021-07-12','[]') arange
|
|
-----------plan into baseline----------------------------------------
|
|
,DATERANGE('2021-06-01','2022-06-01','[)') prange
|
|
)
|
|
,booked AS materialized(
|
|
SELECT
|
|
billto_group
|
|
,shipto_group
|
|
,part_group
|
|
,sum(units) units
|
|
FROM
|
|
rlarp.osm_pool
|
|
WHERE
|
|
--find actual orders in the overlap range (where orders fall in both target ranges)
|
|
order_date <@ (SELECT arange FROM tdr)
|
|
AND order_date <@ (SELECT prange FROM tdr)
|
|
--anything that falls in this range is supposed to already match actuals, so no need to filter for actuals
|
|
GROUP BY
|
|
billto_group
|
|
,shipto_group
|
|
,part_group
|
|
)
|
|
,planned AS (
|
|
SELECT
|
|
p.billto_group
|
|
,p.shipto_group
|
|
,p.part_group
|
|
,p.order_date
|
|
,p.ship_date
|
|
,sum(p.units) FILTER (WHERE iter = 'plan') plan_units
|
|
,sum(p.units) FILTER (WHERE iter = 'diff') diff_units
|
|
,b.units booked
|
|
FROM
|
|
rlarp.osm_pool p
|
|
INNER JOIN booked b ON
|
|
b.billto_group = p.billto_group AND
|
|
b.shipto_group = p.shipto_group AND
|
|
b.part_group = p.part_group
|
|
WHERE
|
|
--need to be able to isolate the original budget
|
|
--budget orders have already been trued up to match actual, so should not be included in the this isolation
|
|
--find actual orders in the overlap range (where orders fall in both target ranges)
|
|
p.order_date <@ (SELECT prange FROM tdr)
|
|
AND p.iter IN ('plan','diff')
|
|
GROUP BY
|
|
p.billto_group
|
|
,p.shipto_group
|
|
,p.part_group
|
|
,p.order_date
|
|
,p.ship_date
|
|
,b.units
|
|
)
|
|
,plan_ranked AS (
|
|
SELECT
|
|
p.billto_group
|
|
,p.shipto_group
|
|
,p.part_group
|
|
,p.order_date
|
|
,p.ship_date
|
|
,p.plan_units
|
|
,SUM(p.plan_units) OVER (PARTITION BY p.billto_group, p.shipto_group, p.part_group ORDER BY p.order_date, p.ship_date) plan_units_agg
|
|
,p.diff_units
|
|
,SUM(p.diff_units) OVER (PARTITION BY p.billto_group, p.shipto_group, p.part_group ORDER BY p.order_date, p.ship_date) diff_units_agg
|
|
,p.booked
|
|
FROM
|
|
planned p
|
|
|
|
)
|
|
SELECT * FROM plan_ranked LIMIT 1000;
|
|
|
|
--ROLLBACK;
|