589 lines
17 KiB
PL/PgSQL
589 lines
17 KiB
PL/PgSQL
--BEGIN;
|
|
|
|
WITH
|
|
------------------goal price increases---------------------
|
|
incr AS (
|
|
SELECT * FROM (VALUES
|
|
('110','PP','B',0.35),
|
|
('110','PP','T',0.35),
|
|
('110','PP','L',0.45),
|
|
('110','PP','M',0.45),
|
|
('110','PP','P',0.45),
|
|
('110','PP','C',0.45),
|
|
('210','PE','B',0.4),
|
|
('210','PE','T',0.4),
|
|
('210','PE','L',0.4),
|
|
('210','PE','M',0.4),
|
|
('210','PE','P',0.4),
|
|
('210','PE','C',0.4),
|
|
('310','PE','B',0.3),
|
|
('310','PE','T',0.35),
|
|
('310','PE','L',0.35),
|
|
('310','PE','M',0.35),
|
|
('310','PE','P',0.35),
|
|
('310','PE','C',0.35),
|
|
('310','PP','B',0.3),
|
|
('310','PP','T',0.3),
|
|
('310','PP','L',0.3),
|
|
('310','PP','M',0.3),
|
|
('310','PP','P',0.3),
|
|
('310','PP','C',0.3),
|
|
('310','PS','B',0.3),
|
|
('310','PS','T',0.3),
|
|
('310','PS','L',0.3),
|
|
('310','PS','M',0.3),
|
|
('310','PS','P',0.3),
|
|
('310','PS','C',0.3),
|
|
('320','PE','B',0.3),
|
|
('320','PE','T',0.3),
|
|
('320','PE','L',0.3),
|
|
('320','PE','M',0.3),
|
|
('320','PE','P',0.3),
|
|
('320','PE','C',0.3),
|
|
('320','PP','B',0.3),
|
|
('320','PP','T',0.3),
|
|
('320','PP','L',0.3),
|
|
('320','PP','M',0.3),
|
|
('320','PP','P',0.3),
|
|
('320','PP','C',0.3),
|
|
('910','PE','B',0.25),
|
|
('910','PE','D',0.25),
|
|
('910','PE','F',0.25),
|
|
('910','PP','B',0.25),
|
|
('910','PP','D',0.25),
|
|
('910','PP','F',0.25),
|
|
('910','PS','B',0.25),
|
|
('910','PS','D',0.25),
|
|
('910','PS','F',0.25),
|
|
('910','','B',0.25),
|
|
('910','','T',0.25),
|
|
('910','','L',0.25),
|
|
('910','','M',0.25),
|
|
('910','','P',0.25),
|
|
('910','','D',0.25),
|
|
('910','','F',0.25),
|
|
('910','','C',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)
|
|
)
|
|
---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
|
|
)
|
|
------------carve out pricing baseline data--------------------
|
|
,p AS (
|
|
SELECT
|
|
o.part
|
|
,o.styc||'.'||o.coltier||substring(o.sizc,1,3) productt
|
|
,o.styc||'.'||o.colgrp||substring(o.sizc,1,3) product
|
|
,o.glec
|
|
,o.styc
|
|
,o.majg
|
|
,i.assc
|
|
,o.coltier
|
|
,o.colgrp
|
|
,o.sizc
|
|
,i.suffix
|
|
,substring(o.chan,1,1) chgrp
|
|
,o.chan
|
|
,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
|
|
FROM
|
|
rlarp.osm_dev o
|
|
INNER JOIN rlarp.itemmv i ON
|
|
i.item = o.part
|
|
WHERE
|
|
---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')
|
|
ORDER BY
|
|
o.part
|
|
,o.styc
|
|
,o.coltier
|
|
,o.sizc
|
|
,i.suffix
|
|
,o.account
|
|
,o.shipgrp
|
|
,o.odate DESC
|
|
)
|
|
--SELECT * FROM p WHERE account ~ 'AMA P' and product = 'AMK06000.CBXX' order by rn ASC
|
|
------------build global py asp------------------
|
|
,baseline AS (
|
|
SELECT
|
|
product
|
|
,majg
|
|
,assc
|
|
,chgrp
|
|
,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_gasp
|
|
,round(sum(val_usd) FILTER (WHERE oseas = 2021)/sum(units) FILTER (WHERE oseas = 2021),5) cy_gasp
|
|
FROM
|
|
p
|
|
GROUP BY
|
|
product
|
|
,majg
|
|
,assc
|
|
,chgrp
|
|
)
|
|
--SELECT * FROM baseline WHERE product = 'AMK06000.CBXX'
|
|
----------calculate pricing as it sits in the forecast--------------
|
|
,poolprice AS (
|
|
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
|
|
,substring(majg,1,3) majg
|
|
,substring(chan,1,1) chgrp
|
|
,o.billto_group
|
|
,o.shipto_group
|
|
,order_season
|
|
,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
|
|
FROM
|
|
rlarp.osm_pool o
|
|
,rlarp.itemmv i
|
|
WHERE
|
|
i.item = o.part
|
|
--AND o.units <> 0
|
|
---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
|
|
,substring(majg,1,3)
|
|
,substring(chan,1,1)
|
|
,o.billto_group
|
|
,o.shipto_group
|
|
,order_season
|
|
--AND iter <> 'upload price'
|
|
HAVING
|
|
sum(o.units) <> 0
|
|
)
|
|
----------pivot the pricing out into columns per customer/product--------
|
|
,pivot AS (
|
|
SELECT
|
|
p.productt
|
|
,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
|
|
,jsonb_agg(DISTINCT part) item
|
|
,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
|
|
,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 .20
|
|
WHEN 'C' THEN .25
|
|
ELSE 1
|
|
END
|
|
END
|
|
END rate
|
|
,ms.avg_price target
|
|
----------------potential price list increase of 5% across board-----
|
|
,JSONB_AGG(DISTINCT (plist.jcpric*1.05)/1000) jcprice
|
|
--,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'
|
|
LEFT OUTER JOIN plist ON
|
|
plist.dba = p.account
|
|
AND plist.jcpart = p.part
|
|
GROUP BY
|
|
p.productt
|
|
,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
|
|
,ms.avg_price
|
|
,i.rate
|
|
)
|
|
--,test_unique AS (
|
|
--SELECT
|
|
-- p.*
|
|
-- ,count(*) OVER (partition by productt, majg, chgrp, account, shipgrp) cnt
|
|
--FROM
|
|
-- pivot p
|
|
--)
|
|
--SELECT * FROM test_unique where cnt > 1
|
|
----------------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 r1",
|
|
"type":"build"
|
|
}$$::jsonb doc
|
|
RETURNING *
|
|
)
|
|
---------collapse iterations-----------------------
|
|
,collapse 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
|
|
,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
|
|
-----exclude any prior pricing adjustments from the "current" price in the forecast------
|
|
,SUM(o.value_loc) FILTER (WHERE iter <> 'upload price')/SUM(o.units) FILTER (WHERE iter <> 'upload price') 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
|
|
)
|
|
-------------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(
|
|
----cap pricing at global ASP or target---
|
|
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(
|
|
-----price loc needs to be prior to any other pricing adjustments-----
|
|
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
|
|
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'
|
|
AND o.segm <> 'Retail'
|
|
)
|
|
--SELECT order_season, order_month, sum(value_usd) from ins group by order_season, order_month;
|
|
INSERT INTO rlarp.osm_pool SELECT * FROM ins;
|
|
--SELECT * FROM ins WHERE shipto_group = 'A&W ANNUALS' and part = 'TWA10200G18B027';
|
|
-----------aggregate the impact------------
|
|
|
|
--COMMIT;
|