initial work on baselining price

This commit is contained in:
Paul Trowbridge 2021-04-07 09:53:32 -04:00
parent 5dc43123c9
commit 94f925f1d8

View File

@ -1,120 +1,316 @@
BEGIN;
with p AS (
SELECT
part
,bill_cust
,ship_cust
,round(fb_val_loc/fb_qty,10) AS price
,orderdate
,row_number() OVER (PARTITION BY part,bill_cust, ship_cust ORDER BY orderdate DESC) rn
FROM
rlarp.osm
WHERE
fs_line = '41010'
AND calc_status <> 'CANCELED'
AND COALESCE(part,'') <> ''
AND fb_qty <> 0
AND orderdate IS NOT NULL
ORDER BY
part
,bill_cust
,ship_cust
,orderdate
--BEGIN;
WITH
incr AS (
SELECT * FROM (VALUES
('110','PP','B',0.25),
('110','PP','T',0.25),
('110','PP','L',0.4),
('110','PP','M',0.4),
('110','PP','P',0.4),
('110','PP','C',0.4),
('210','PE','B',0.25),
('210','PE','T',0.25),
('210','PE','L',0.25),
('210','PE','M',0.25),
('210','PE','P',0.25),
('210','PE','C',0.25),
('310','PE','B',0.15),
('310','PE','T',0.25),
('310','PE','L',0.25),
('310','PE','M',0.25),
('310','PE','P',0.25),
('310','PE','C',0.25),
('310','PP','B',0.13),
('310','PP','T',0.16),
('310','PP','L',0.16),
('310','PP','M',0.16),
('310','PP','P',0.16),
('310','PP','C',0.16),
('310','PS','B',0.13),
('310','PS','T',0.16),
('310','PS','L',0.16),
('310','PS','M',0.16),
('310','PS','P',0.16),
('310','PS','C',0.16),
('320','PE','B',0.25),
('320','PE','T',0.25),
('320','PE','L',0.25),
('320','PE','M',0.25),
('320','PE','P',0.25),
('320','PE','C',0.25),
('320','PP','B',0.25),
('320','PP','T',0.25),
('320','PP','L',0.25),
('320','PP','M',0.25),
('320','PP','P',0.25),
('320','PP','C',0.25),
('910','PE','B',0.15),
('910','PE','D',0.25),
('910','PE','F',0.25),
('910','PP','B',0.15),
('910','PP','D',0.25),
('910','PP','F',0.25),
('910','PS','B',0.15),
('910','','B',0.15),
('910','','D',0.25),
('910','','F',0.25),
('910','','T',0.25),
('910','','L',0.25),
('910','','M',0.25),
('910','','P',0.25),
('910','','C',0.25),
('910','PS','D',0.25),
('910','PS','F',0.25),
('610','','B',0.02),
('610','','S',0.02),
('610','','W',0.02)
) x(MAJG,ASSC,COLTIER,RATE)
)
--SELECT * FROM p WHERE rn = 1
,incr AS (
,p AS (
SELECT
b.plnt
,b."ddord#"
,b."dditm#"
,b."fgbol#"
,b."fgent#"
,b."diinv#"
,b."dilin#"
,b.promo
,b.return_reas
,b.terms
,b.custpo
,b.dhincr
,b.diext
,b.ditdis
,b.dcodat
,b.ddqdat
,b.dcmdat
,b.dhidat
,b.fspr
,b.remit_to
,b.bill_class
,b.bill_cust
,b.bill_rep
,b.bill_terr
,b.ship_class
,b.ship_cust
,b.ship_rep
,b.ship_terr
,b.quota_rep
,b.account
,b.shipgrp
,b.geo
,b.chan
,b.orig_ctry
,b.orig_prov
,b.orig_post
,b.dest_ctry
,b.dest_prov
,b.dest_post
,b.part
,b.ord_gldc
,b.majg
,b.ming
,b.majs
,b.mins
,b.gldc
,b.glec
,b.harm
,b.clss
,b.brand
,b.assc
,b.fs_line
,b.r_currency
,b.r_rate
,b.c_currency
,b.c_rate
,b.ddqtoi
,b.ddqtsi
,b.fgqshp
,b.diqtsh
,0 fb_qty
,0 fb_cst_loc
,0 fb_cst_loc_cur
,0 fb_cst_loc_fut
,b.fb_qty * p.price - b.fb_val_loc fb_val_loc
,0 fb_val_loc_pl
,b.calc_status
,b.flag
,b.orderdate
,b.requestdate
,b.shipdate
,b.adj_orderdate
,b.adj_requestdate
,b.adj_shipdate
,b."version"
,'last price paid' iter
o.part
,o.styc||'.'||o.colgrp||substring(o.sizc,2,3) product
,o.glec
,o.styc
,o.majg
,i.assc
,o.coltier
,o.sizc
,i.suffix
,substring(o.chan,1,1) chgrp
,o.account
,o.shipgrp
,o.fb_qty units
,o.fb_val_loc*r_rate val_usd
,round(o.fb_val_loc/o.fb_qty,10) AS price
,o.odate
,o.oseas
,row_number() OVER (PARTITION BY o.part,o.bill_cust, o.ship_cust ORDER BY o.odate DESC) rn
FROM
rlarp.osmfs b
INNER JOIN p ON
p.part = b.part
AND p.bill_cust = b.bill_cust
AND p.ship_cust = b.ship_cust
AND p.rn = 1
rlarp.osm_dev o
INNER JOIN rlarp.itemmv i ON
i.item = o.part
WHERE
b.orderdate BETWEEN '2019-03-25' AND '2019-05-31'
OR b.orderdate BETWEEN '2020-03-25' AND '2020-05-31'
---exclude R&A's
o.fs_line = '41010'
---exclude canceled orders
AND o.calc_status <> 'CANCELED'
---exclude quotes
AND o.version = 'ACTUALS'
---only finished goods
AND substring(o.glec,1,1) <= '2'
---exclude blank parts
AND COALESCE(o.part,'') <> ''
---must have a quantity
AND o.fb_qty <> 0
---must have a price
AND o.fb_val_loc <> 0
---must come from and order
AND o.odate IS NOT NULL
---exclude samples
AND o.bill_class <> 'SALE'
---only use recent history
AND o.oseas >= 2020
ORDER BY
o.part
,o.styc
,o.coltier
,o.sizc
,i.suffix
,o.account
,o.shipgrp
,o.odate DESC
)
,baseline AS (
SELECT
product
,majg
,assc
,chgrp
,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_gasp
FROM
p
GROUP BY
product
,majg
,assc
,chgrp
)
,pivot AS (
SELECT
p.product
,p.styc
,p.glec
,p.majg
,p.assc
,p.coltier
,p.sizc
,p.suffix
,p.account
,p.shipgrp
,bl.py_gasp
,sum(units) FILTER (WHERE oseas = 2021) cy_units
,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_asp
,round(avg(price) FILTER (WHERE rn = 1),5) last_price
,max(odate) FILTER (WHERE rn = 1) last_order
,i.rate
,CASE WHEN sum(val_usd) FILTER (WHERE oseas = 2020) IS NULL
THEN CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL
THEN 'unknown'
ELSE 'new'
END
ELSE CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL
THEN 'lost'
ELSE 'repeat'
END
END flag
FROM
p
LEFT OUTER JOIN baseline bl ON
bl.product = p.product
AND bl.majg = p.majg
AND bl.assc = p.assc
AND bl.chgrp = p.chgrp
LEFT OUTER JOIN incr i ON
i.majg = p.majg
AND i.assc = p.assc
AND i.coltier = p.coltier
AND p.glec <> '1RE'
GROUP BY
p.product
,p.styc
,p.glec
,p.majg
,p.assc
,p.coltier
,p.sizc
,p.suffix
,p.account
,p.shipgrp
,bl.py_gasp
,i.rate
)
,adj AS (
SELECT
p.product
,p.styc
,p.glec
,p.majg
,p.assc
,p.coltier
,p.sizc
,p.suffix
,p.account
,p.shipgrp
,p.py_gasp
,p.cy_units
,p.py_asp
,p.last_price
,p.last_order
,p.rate
,p.flag
,CASE p.flag
----------------------if repeat business then get to prior year + target %--------------------------------------------------------------
WHEN 'repeat' THEN greatest(py_asp * COALESCE(1+rate,1) - last_price,0)
WHEN 'lost' THEN greatest(py_asp * COALESCE(1+rate,1) - last_price,0)
----------------------if new business, move towards py_gasp + target % : lesser of py gloabl + target or last + target------------------
WHEN 'new' THEN least(last_price * COALESCE(1+rate,1) - last_price,greatest(py_gasp * COALESCE(1+rate,1) - last_price,0))
END price_increment
FROM
pivot p
)
,log AS (
--INSERT INTO
-- rlarp.osm_log(doc)
SELECT
$${
"message":"application of last price and target increases to all forecast orders",
"tag":"last price",
"type":"build"
}$$::jsonb doc
--RETURNING *
)
,ins AS (
INSERT INTO rlarp.osmfs SELECT * FROM incr RETURNING *
SELECT
o.fspr
,o.plnt ---master data
,o.promo --history date mix
,o.terms
,o.bill_cust_descr --history cust mix
,o.ship_cust_descr --history cust mix
,o.dsm
,o.quota_rep_descr --master data
,o.director
,o.billto_group --master data
,o.shipto_group
,o.chan --master data
,o.chansub
,o.chan_retail
,o.part
,o.part_descr
,o.part_group
,o.branding
,o.majg_descr
,o.ming_descr
,o.majs_descr
,o.mins_descr
,o.segm
,o.substance
,o.fs_line --master data
,o.r_currency --history cust mix
,o.r_rate --master data
,o.c_currency --master data
,o.c_rate --master data
,0::numeric units
,ROUND(o.units * (a.price_increment/o.r_rate),2) value_loc
,ROUND(o.units * a.price_increment,2) value_usd
,0::numeric cost_loc
,0::numeric cost_usd
,o.calc_status --0
,o.flag --0
,o.order_date --history date mix
,o.order_month
,o.order_season
,o.request_date --history date mix
,o.request_month
,o.request_season
,o.ship_date --history date mix
,o.ship_month
,o.ship_season
,o.version
---this iteration has to be listed in the master template file in order to be effectively included---
,'upload price' iter
,COALESCE(log.doc->>'tag','') "tag"
,log.doc->>'message' "comment"
,log.doc->>'type' module
-------------------------------------
--,value_usd/units price
--,a.py_gasp
--,a.rate
--,a.last_price
--,a.price_increment
FROM
rlarp.osm_pool o
,rlarp.itemmv i
,adj a
,log
WHERE
i.item = o.part
AND a.product = i.stlc||'.'||i.colgrp||substring(i.sizc,2,3)
AND a.account = o.billto_group
AND a.shipgrp = o.shipto_group
AND a.price_increment <> 0
AND o.units <> 0
---only apply to 2022 orders----
AND o.order_date >= '2021-06-01'
)
SELECT fspr, sum(fb_val_loc *r_rate) FROM ins GROUP BY fspr;
SELECT
order_season
,sum(value_usd) val_usd
FROM
ins
GROUP BY
order_season;
COMMIT;
--COMMIT;