differentiate on bulk/case, and create different rates for warehouse

This commit is contained in:
Paul Trowbridge 2021-04-08 15:45:14 -04:00
parent 4c43a79f15
commit 7dab34e949

View File

@ -1,4 +1,5 @@
--BEGIN; BEGIN;
WITH WITH
------------------goal price increases--------------------- ------------------goal price increases---------------------
incr AS ( incr AS (
@ -71,12 +72,13 @@ incr AS (
,p AS ( ,p AS (
SELECT SELECT
o.part o.part
,o.styc||'.'||o.colgrp||substring(o.sizc,2,3) product ,o.styc||'.'||o.colgrp||substring(o.sizc,1,3) product
,o.glec ,o.glec
,o.styc ,o.styc
,o.majg ,o.majg
,i.assc ,i.assc
,o.coltier ,o.coltier
,o.colgrp
,o.sizc ,o.sizc
,i.suffix ,i.suffix
,substring(o.chan,1,1) chgrp ,substring(o.chan,1,1) chgrp
@ -87,7 +89,7 @@ incr AS (
,round(o.fb_val_loc/o.fb_qty,10) AS price ,round(o.fb_val_loc/o.fb_qty,10) AS price
,o.odate ,o.odate
,o.oseas ,o.oseas
,row_number() OVER (PARTITION BY o.part,o.bill_cust, o.ship_cust ORDER BY o.odate DESC) rn ,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 FROM
rlarp.osm_dev o rlarp.osm_dev o
INNER JOIN rlarp.itemmv i ON INNER JOIN rlarp.itemmv i ON
@ -113,6 +115,8 @@ incr AS (
AND o.bill_class <> 'SALE' AND o.bill_class <> 'SALE'
---only use recent history ---only use recent history
AND o.oseas >= 2020 AND o.oseas >= 2020
---only for direct and drop
--AND o.chan IN ('DIR','DRP')
ORDER BY ORDER BY
o.part o.part
,o.styc ,o.styc
@ -123,6 +127,7 @@ incr AS (
,o.shipgrp ,o.shipgrp
,o.odate DESC ,o.odate DESC
) )
--SELECT * FROM p WHERE account ~ 'ACOSTA'
------------build global py asp------------------ ------------build global py asp------------------
,baseline AS ( ,baseline AS (
SELECT SELECT
@ -147,9 +152,11 @@ SELECT
,p.glec ,p.glec
,p.majg ,p.majg
,p.assc ,p.assc
,p.colgrp
,p.coltier ,p.coltier
,p.sizc ,p.sizc
,p.suffix ,p.suffix
,p.chgrp
,p.account ,p.account
,p.shipgrp ,p.shipgrp
,bl.py_gasp ,bl.py_gasp
@ -157,7 +164,17 @@ SELECT
,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_asp ,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 ,round(avg(price) FILTER (WHERE rn = 1),5) last_price
,max(odate) FILTER (WHERE rn = 1) last_order ,max(odate) FILTER (WHERE rn = 1) last_order
,i.rate ,CASE p.chgrp
WHEN 'D' THEN i.rate
ELSE CASE p.majg
WHEN '610' THEN .02
ElSE CASE p.colgrp
WHEN 'B' THEN .1
WHEN 'C' THEN .15
ELSE 1
END
END
END rate
,CASE WHEN sum(val_usd) FILTER (WHERE oseas = 2020) IS NULL ,CASE WHEN sum(val_usd) FILTER (WHERE oseas = 2020) IS NULL
THEN CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL THEN CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL
THEN 'unknown' THEN 'unknown'
@ -188,8 +205,10 @@ GROUP BY
,p.majg ,p.majg
,p.assc ,p.assc
,p.coltier ,p.coltier
,p.colgrp
,p.sizc ,p.sizc
,p.suffix ,p.suffix
,p.chgrp
,p.account ,p.account
,p.shipgrp ,p.shipgrp
,bl.py_gasp ,bl.py_gasp
@ -225,17 +244,18 @@ SELECT
FROM FROM
pivot p pivot p
) )
--SELECT * FROM adj LIMIT 10000
--------------create a log entry-------------------- --------------create a log entry--------------------
,log AS ( ,log AS (
--INSERT INTO INSERT INTO
-- rlarp.osm_log(doc) rlarp.osm_log(doc)
SELECT SELECT
$${ $${
"message":"application of last price and target increases to all forecast orders", "message":"application of last price and target increases to all forecast orders",
"tag":"last price", "tag":"last price",
"type":"build" "type":"build"
}$$::jsonb doc }$$::jsonb doc
--RETURNING * RETURNING *
) )
-------------build the iteration rows---------------- -------------build the iteration rows----------------
,ins AS ( ,ins AS (
@ -288,10 +308,11 @@ SELECT
,o.version ,o.version
---this iteration has to be listed in the master template file in order to be effectively included--- ---this iteration has to be listed in the master template file in order to be effectively included---
,'upload price' iter ,'upload price' iter
,log.id
,COALESCE(log.doc->>'tag','') "tag" ,COALESCE(log.doc->>'tag','') "tag"
,log.doc->>'message' "comment" ,log.doc->>'message' "comment"
,log.doc->>'type' module ,log.doc->>'type' module
------------------------------------- -----------debug columns---------
--,value_usd/units price --,value_usd/units price
--,a.py_gasp --,a.py_gasp
--,a.rate --,a.rate
@ -304,7 +325,7 @@ FROM
,log ,log
WHERE WHERE
i.item = o.part i.item = o.part
AND a.product = i.stlc||'.'||i.colgrp||substring(i.sizc,2,3) AND a.product = i.stlc||'.'||i.colgrp||substring(i.sizc,1,3)
AND a.account = o.billto_group AND a.account = o.billto_group
AND a.shipgrp = o.shipto_group AND a.shipgrp = o.shipto_group
AND a.price_increment <> 0 AND a.price_increment <> 0
@ -313,12 +334,17 @@ WHERE
AND o.order_date >= '2021-06-01' AND o.order_date >= '2021-06-01'
) )
-----------aggregate the impact------------ -----------aggregate the impact------------
SELECT --SELECT * FROM ins limit 10000
order_season --SELECT
,sum(value_usd) val_usd -- order_season
FROM -- ,sum(value_loc) val_loc
ins -- ,sum(value_usd) val_usd
GROUP BY --FROM
order_season; -- ins
--GROUP BY
-- order_season;
INSERT INTO
rlarp.osm_pool
SELECT * FROM ins;
--COMMIT; COMMIT;