forecast_api/offline/last_price.sql

732 lines
20 KiB
MySQL
Raw Normal View History

2021-05-07 14:32:18 -04:00
BEGIN;
2021-04-07 09:53:32 -04:00
WITH
2021-04-08 12:43:46 -04:00
------------------goal price increases---------------------
2021-04-07 09:53:32 -04:00
incr AS (
SELECT * FROM (VALUES
2021-04-20 16:11:34 -04:00
('110','PP','B',0.3),
('110','PP','T',0.3),
2021-04-07 09:53:32 -04:00
('110','PP','L',0.4),
('110','PP','M',0.4),
('110','PP','P',0.4),
('110','PP','C',0.4),
2021-04-20 16:11:34 -04:00
('210','PE','B',0.3),
('210','PE','T',0.3),
('210','PE','L',0.3),
('210','PE','M',0.3),
('210','PE','P',0.3),
('210','PE','C',0.3),
('310','PE','B',0.25),
('310','PE','T',0.3),
('310','PE','L',0.3),
('310','PE','M',0.3),
('310','PE','P',0.3),
('310','PE','C',0.3),
('310','PP','B',0.25),
('310','PP','T',0.25),
('310','PP','L',0.25),
('310','PP','M',0.25),
('310','PP','P',0.25),
('310','PP','C',0.25),
('310','PS','B',0.25),
('310','PS','T',0.25),
('310','PS','L',0.25),
('310','PS','M',0.25),
('310','PS','P',0.25),
('310','PS','C',0.25),
2021-04-07 09:53:32 -04:00
('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),
2021-04-20 16:11:34 -04:00
('910','PE','B',0.25),
2021-04-07 09:53:32 -04:00
('910','PE','D',0.25),
('910','PE','F',0.25),
2021-04-20 16:11:34 -04:00
('910','PP','B',0.25),
2021-04-07 09:53:32 -04:00
('910','PP','D',0.25),
('910','PP','F',0.25),
2021-04-20 16:11:34 -04:00
('910','PS','B',0.25),
2021-04-07 09:53:32 -04:00
('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)
)
,chx AS (
SELECT * FROM ( VALUES
('DIRECT','DIR','Direct'),
('DISTRIB DROP SHIP','DRP','Drop'),
('DISTRIBUTOR','WHS','Warehouse')
) x(xchan, chan, tchan)
)
,ds AS (
SELECT * FROM ( VALUES
('B','X','BASE','Base',''),
('B','L','BASE LABELED','Base','L'),
('B','P','BASE PRINTED','Base','P'),
('C','X','COLOR','Color',''),
('C','L','COLOR LABELED','Color','L'),
('C','P','COLOR PRINTED','Color','P')
) x(colgrp, brand, dataseg, tcol, tbrand)
)
2021-05-07 10:12:33 -04:00
---customer dba assigned price levels---------
,dbap AS (
SELECT
dba
,jsonb_agg(DISTINCT plevel) plev
,jsonb_agg(DISTINCT plcd) plist
FROM
rlarp.cust c
INNER JOIN rlarp.sachdef sd ON
sd.plev = c.plevel
AND '2020-05-31' between sd.fdate AND sd.tdate
WHERE
pricing <> ''
AND dba <> ''
GROUP BY
dba
)
----customer dba price list pricing------
,plist AS (
SELECT
dbap.dba
,dbap.plev
,dbap.plist
,jcplcd
,jcpart
,jcunit
--,jcvoll
-----just use the lowest volume price for the part-----
,min(jcpric) jcpric
FROM
dbap
INNER JOIN lgdat.iprcc cc ON
dbap.plist ? cc.jcplcd
WHERE
jcunit = 'M'
GROUP BY
dbap.dba
,dbap.plev
,dbap.plist
,jcplcd
,jcpart
,jcunit
)
2021-04-08 12:43:46 -04:00
------------carve out pricing baseline data--------------------
2021-04-07 09:53:32 -04:00
,p AS (
2020-02-19 17:05:27 -05:00
SELECT
2021-04-07 09:53:32 -04:00
o.part
,o.styc||'.'||o.coltier||substring(o.sizc,1,3) productt
,o.styc||'.'||o.colgrp||substring(o.sizc,1,3) product
2021-04-07 09:53:32 -04:00
,o.glec
,o.styc
,o.majg
,i.assc
,o.coltier
,o.colgrp
2021-04-07 09:53:32 -04:00
,o.sizc
,i.suffix
,substring(o.chan,1,1) chgrp
,o.chan
2021-04-07 09:53:32 -04:00
,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.styc||'.'||o.colgrp||substring(o.sizc,1,3),o.account, o.shipgrp ORDER BY o.odate DESC) rn
2020-02-19 17:05:27 -05:00
FROM
2021-04-07 09:53:32 -04:00
rlarp.osm_dev o
INNER JOIN rlarp.itemmv i ON
i.item = o.part
2020-02-19 17:05:27 -05:00
WHERE
2021-04-07 09:53:32 -04:00
---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
---only for direct and drop
--AND o.chan IN ('DIR','DRP')
2020-02-19 17:05:27 -05:00
ORDER BY
2021-04-07 09:53:32 -04:00
o.part
,o.styc
,o.coltier
,o.sizc
,i.suffix
,o.account
,o.shipgrp
,o.odate DESC
2020-02-19 17:05:27 -05:00
)
2021-05-07 10:12:33 -04:00
--SELECT * FROM p WHERE account ~ 'AMA P' and product = 'AMK06000.CBXX' order by rn ASC
2021-04-08 12:43:46 -04:00
------------build global py asp------------------
2021-04-07 09:53:32 -04:00
,baseline AS (
2020-02-19 17:05:27 -05:00
SELECT
2021-04-07 09:53:32 -04:00
product
,majg
,assc
,chgrp
,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_gasp
2021-05-07 10:12:33 -04:00
,round(sum(val_usd) FILTER (WHERE oseas = 2021)/sum(units) FILTER (WHERE oseas = 2021),5) cy_gasp
2020-02-19 17:05:27 -05:00
FROM
2021-04-07 09:53:32 -04:00
p
GROUP BY
product
,majg
,assc
,chgrp
)
2021-05-07 10:12:33 -04:00
--SELECT * FROM baseline WHERE product = 'AMK06000.CBXX'
--SELECT
-- p.product
-- --,p.styc
-- --,p.glec
-- ,p.majg
-- ,p.assc
-- ,p.colgrp
-- --,p.coltier
-- --,p.sizc
-- --,p.suffix
-- ,p.chgrp
-- ,p.account
-- ,p.shipgrp
-- --,bl.py_gasp
-- ,sum(units) FILTER (WHERE oseas = 2020) py_units
-- ,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 incr_rate
-- ,CASE p.chgrp
-- WHEN 'D' THEN .5
-- ELSE CASE p.majg
-- WHEN '610' THEN .02
-- ElSE CASE p.colgrp
-- WHEN 'B' THEN .15
-- WHEN 'C' THEN .20
-- ELSE 1
-- END
-- END
-- END 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'
--WHERE
-- p.account ~ 'AMERICAN HORT' and p.product = 'AZA06000.CBXX' and p.chgrp = 'W'
--GROUP BY
-- p.product
-- --,p.styc
-- --,p.glec
-- ,p.majg
-- ,p.assc
-- --,p.coltier
-- ,p.colgrp
-- --,p.sizc
-- --,p.suffix
-- ,p.chgrp
-- ,p.account
-- ,p.shipgrp
-- --,bl.py_gasp
-- ,i.rate
2021-04-20 16:11:34 -04:00
----------calculate pricing as it sits in the forecast--------------
,poolprice AS (
2021-04-07 09:53:32 -04:00
SELECT
i.stlc||'.'||i.coltier||substring(i.sizc,1,3) productt
,i.stlc||'.'||i.colgrp||substring(i.sizc,1,3) product
,o.quota_rep_descr
2021-04-20 16:11:34 -04:00
,substring(majg,1,3) majg
,substring(chan,1,1) chgrp
,o.billto_group
2021-04-07 09:53:32 -04:00
,o.shipto_group
,order_season
2021-04-20 16:11:34 -04:00
,round(sum(units) ,2) fc_units
--,round(sum(value_loc) ,2) valloc
--,round(sum(value_usd) ,2) valusd
,round(sum(o.value_loc)/sum(o.units),5) fc_price
,jsonb_agg(DISTINCT iter) iters
2021-04-07 09:53:32 -04:00
FROM
rlarp.osm_pool o
,rlarp.itemmv i
WHERE
i.item = o.part
--AND o.units <> 0
2021-04-07 09:53:32 -04:00
---only apply to 2022 orders----
AND o.order_date >= '2021-06-01'
--only include baseline stuff---
AND segm <> 'Retail'
GROUP BY
i.stlc||'.'||i.coltier||substring(i.sizc,1,3)
,i.stlc||'.'||i.colgrp||substring(i.sizc,1,3)
,o.quota_rep_descr
2021-04-20 16:11:34 -04:00
,substring(majg,1,3)
,substring(chan,1,1)
,o.billto_group
,o.shipto_group
,order_season
--AND iter <> 'upload price'
2021-04-20 16:11:34 -04:00
HAVING
sum(o.units) <> 0
2020-02-19 17:05:27 -05:00
)
2021-04-20 16:11:34 -04:00
----------pivot the pricing out into columns per customer/product--------
,pivot AS (
SELECT
p.productt
,p.product
2021-04-20 16:11:34 -04:00
--,p.styc
--,p.glec
,p.majg
,p.assc
,p.colgrp
--,p.coltier
--,p.sizc
--,p.suffix
,p.chgrp
,p.account
,p.shipgrp
,bl.py_gasp
2021-05-07 10:12:33 -04:00
,jsonb_agg(DISTINCT part) item
2021-04-20 16:11:34 -04:00
,sum(units) FILTER (WHERE oseas = 2020) py_units
,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(sum(val_usd) FILTER (WHERE oseas = 2021)/sum(units) FILTER (WHERE oseas = 2021),5) cy_asp
2021-04-20 16:11:34 -04:00
,round(avg(price) FILTER (WHERE rn = 1),5) last_price
,max(odate) FILTER (WHERE rn = 1) last_order
,CASE p.chgrp
WHEN 'D' THEN i.rate
ELSE CASE p.majg
WHEN '610' THEN .02
ElSE CASE p.colgrp
WHEN 'B' THEN .15
WHEN 'C' THEN .20
ELSE 1
END
END
END rate
,ms.avg_price target
2021-05-07 14:32:18 -04:00
,JSONB_AGG(DISTINCT plist.jcpric/1000) jcprice
2021-04-20 16:11:34 -04:00
--,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'
-----convert to target price channels---------
LEFT OUTER JOIN chx ON
chx.chan = p.chan
-----convert to target price product level----
LEFT OUTER JOIN ds ON
ds.colgrp = p.colgrp
AND ds.brand = substring(p.sizc,3,1)
LEFT OUTER JOIN pricequote.market_setavgprice ms ON
ms.mold = substring(p.product,1,8)
AND ms.chan = chx.xchan
AND ms.data_segment = ds.dataseg
AND ms.season = '2021'
AND ms.region = 'ALL'
2021-05-07 10:12:33 -04:00
LEFT OUTER JOIN plist ON
plist.dba = p.account
AND plist.jcpart = p.part
2021-04-20 16:11:34 -04:00
GROUP BY
p.productt
,p.product
2021-04-20 16:11:34 -04:00
--,p.styc
--,p.glec
,p.majg
,p.assc
--,p.coltier
,p.colgrp
--,p.sizc
--,p.suffix
,p.chgrp
,p.account
,p.shipgrp
,bl.py_gasp
,ms.avg_price
2021-04-20 16:11:34 -04:00
,i.rate
)
--,test_unique AS (
--SELECT
-- p.*
-- ,count(*) OVER (partition by productt, majg, chgrp, account, shipgrp) cnt
--FROM
-- pivot p
2021-04-20 16:11:34 -04:00
--)
--SELECT * FROM test_unique where cnt > 1
--SELECT * FROM pivot LIMIT 1000
--------------join forecast price-------------------
2021-05-07 14:32:18 -04:00
--,fcp AS (
-- SELECT
-- pp.productt
-- ,pp.product
-- ,pp.majg
-- ,pp.quota_rep_descr
-- ,pp.order_season
-- ,pp.billto_group
-- ,pp.shipto_group
-- ,pp.chgrp
-- ,pp.fc_units
-- ,pp.fc_price
-- ,pp.iters
-- --,p.item
-- ,p.py_gasp
-- ,p.cy_units
-- ,p.py_asp
-- ,p.last_price
-- ,p.last_order
-- ,p.target
-- ,p.rate
-- ,p.jcprice
-- --need to link in targets pricing and price list for cap purposes---------
-- --also need to link regional price lists so we don't blow past those------
-- ,least(
-- least(
-- COALESCE(p.py_asp,p.last_price),
-- COALESCE(py_gasp,target)
-- ) * (1 + p.rate),
-- (jcprice->>0)::numeric
-- ) rev_price
-- ,greatest(
-- least(
-- least(
-- COALESCE(p.py_asp,p.last_price),
-- COALESCE(py_gasp,target)
-- ) * (1 + p.rate),
-- (jcprice->>0)::numeric
-- ) - fc_price
-- ,0
-- ) fc_adj
-- --last season price + % capped at list or py_gasp + %
-- --last price + % capped at list or pg_gasp + %
-- FROM
-- poolprice pp
-- LEFT OUTER JOIN pivot p ON
-- pp.productt = p.productt
-- AND pp.majg = p.majg
-- AND pp.chgrp = p.chgrp
-- AND pp.billto_group = p.account
-- AND pp.shipto_group = p.shipgrp
-- WHERE
-- greatest(
-- least(
-- least(
-- COALESCE(p.py_asp,p.last_price),
-- COALESCE(py_gasp,target)
-- ) * (1 + p.rate),
-- (jcprice->>0)::numeric
-- ) - fc_price
-- ,0
-- ) <> 0
--)
--SELECT * FROM fcp LIMIT 1000
----------------create a log entry--------------------
,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 *
)
---------collapse iterations-----------------------
,collapse AS (
SELECT
2021-05-07 14:32:18 -04:00
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
,i.stlc||'.'||i.coltier||substring(i.sizc,1,3) productt
,o.part_group
,o.branding
,o.majg_descr
,o.ming_descr
,o.majs_descr
,o.mins_descr
,o.segm
,o.substance
,o.fs_line
,o.r_currency
,o.r_rate
,o.c_currency
,o.c_rate
,SUM(o.units) units
,SUM(o.value_loc) value_loc
,SUM(o.value_usd) value_usd
,SUM(o.value_loc)/SUM(o.units) price_loc
,SUM(o.cost_loc) cost_loc
,SUM(o.cost_usd) 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
FROM
rlarp.osm_pool o
--need to join to itemm to get the product from osm_pool
,rlarp.itemmv i
WHERE
i.item = o.part
GROUP BY
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
,i.stlc||'.'||i.coltier||substring(i.sizc,1,3)
,o.part_group
,o.branding
,o.majg_descr
,o.ming_descr
,o.majs_descr
,o.mins_descr
,o.segm
,o.substance
,o.fs_line
,o.r_currency
,o.r_rate
,o.c_currency
,o.c_rate
,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
HAVING
sum(o.units) <> 0
)
2021-05-07 14:32:18 -04:00
-------------build the iteration rows----------------
,ins AS (
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
--,o.units
,0::numeric units
,greatest(
round(least(
least(
COALESCE(a.py_asp,o.price_loc),
COALESCE(a.py_gasp,a.target)
) * (1 + a.rate),
(a.jcprice->>0)::numeric
)*o.units - o.value_loc,2)
,0) AS value_loc
,greatest(
round((least(
least(
COALESCE(a.py_asp,o.price_loc),
COALESCE(a.py_gasp,a.target)
) * (1 + a.rate),
(a.jcprice->>0)::numeric
)*o.units - o.value_loc) * r_rate,2)
,0) AS value_usd
----debug---
--,least(
-- least(
-- COALESCE(a.py_asp,o.price_loc),
-- COALESCE(a.py_gasp,a.target)
-- ) * (1 + a.rate),
-- (a.jcprice->>0)::numeric
--) AS rev_price
--,o.units
--,o.value_loc
--,o.value_usd
--,o.price_loc
--,a.last_price
--,a.target
--,a.jcprice
--,a.rate
--,a.py_asp
--,a.py_gasp
-----------
,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---
,'b22' AS version
,'upload price' iter
,log.id
,COALESCE(log.doc->>'tag','') "tag"
,log.doc->>'message' "comment"
,log.doc->>'type' module
-----------debug columns---------
--,value_usd/units price
--,a.py_gasp
--,a.rate
--,a.last_price
--,a.price_increment
FROM
collapse o
--need to join to itemm to get the product from osm_pool
--,fcp a
,pivot a
,log
WHERE
-- a.productt = o.productt
--AND a.quota_rep_descr = o.quota_rep_descr
--AND a.majg = SUBSTRING(o.majg_descr,1,3)
--AND a.billto_group = o.billto_group
--AND a.shipto_group = o.shipto_group
--AND a.chgrp = substring(o.chan,1,1)
---only apply to 2022 orders----
---join p
a.productt = o.productt
AND a.majg = SUBSTRING(o.majg_descr,1,3)
AND a.chgrp = substring(o.chan,1,1)
AND a.account = o.billto_group
AND a.shipgrp = o.shipto_group
AND o.order_date >= '2021-06-01'
)
--SELECT order_season, order_month, sum(value_usd) from ins group by order_season, order_month;
INSERT INTO rlarp.osm_pool SELECT * FROM ins;
-----------aggregate the impact------------
--SELECT * FROM ins limit 10000
--SELECT
2021-05-07 14:32:18 -04:00
-- order_season
-- ,sum(value_loc) val_loc
-- ,sum(value_usd) val_usd
--FROM
2021-05-07 14:32:18 -04:00
-- ins
--GROUP BY
-- order_season;
2021-05-07 10:12:33 -04:00
--,del AS (
-- DELETE FROM rlarp.osm_pool WHERE iter = 'upload price' RETURNING *
--)
--INSERT INTO
-- rlarp.osm_pool
--SELECT * FROM ins;
--
2021-05-07 14:32:18 -04:00
COMMIT;