242 lines
6.7 KiB
MySQL
242 lines
6.7 KiB
MySQL
|
WITH
|
||
|
---------collapse iterations--------------------------------------
|
||
|
collapse AS (
|
||
|
SELECT
|
||
|
o.fspr
|
||
|
,o.plnt
|
||
|
,o.promo
|
||
|
,o.terms
|
||
|
,o.bill_cust_descr
|
||
|
,o.ship_cust_descr
|
||
|
,o.dsm
|
||
|
,o.quota_rep_descr
|
||
|
,o.director
|
||
|
,o.billto_group
|
||
|
,o.shipto_group
|
||
|
,o.chan
|
||
|
,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
|
||
|
,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.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
|
||
|
WHERE
|
||
|
--all June and earlier orders originally shipping in October now move back to June ship date
|
||
|
ship_season||substring(ship_month,1,2) = '202201'
|
||
|
and order_season||substring(order_month,1,2) BETWEEN '202111' AND '202111'
|
||
|
and segm = 'Nursery'
|
||
|
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
|
||
|
,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
|
||
|
)
|
||
|
--SELECT
|
||
|
-- sum(value_usd)
|
||
|
--FROM
|
||
|
-- collapse
|
||
|
------------------create a log entry--------------------
|
||
|
,log AS (
|
||
|
INSERT INTO
|
||
|
rlarp.osm_log(doc)
|
||
|
SELECT
|
||
|
$${
|
||
|
"message":"NU sales smooth",
|
||
|
"tag":"NU sales smooth",
|
||
|
"type":"build"
|
||
|
}$$::jsonb doc
|
||
|
RETURNING *
|
||
|
)
|
||
|
,rem AS (
|
||
|
SELECT
|
||
|
o.fspr
|
||
|
,o.plnt
|
||
|
,o.promo
|
||
|
,o.terms
|
||
|
,o.bill_cust_descr
|
||
|
,o.ship_cust_descr
|
||
|
,o.dsm
|
||
|
,o.quota_rep_descr
|
||
|
,o.director
|
||
|
,o.billto_group
|
||
|
,o.shipto_group
|
||
|
,o.chan
|
||
|
,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
|
||
|
,o.r_currency
|
||
|
,o.r_rate
|
||
|
,o.c_currency
|
||
|
,o.c_rate
|
||
|
,-units units
|
||
|
,-value_loc value_loc
|
||
|
,-value_usd value_usd
|
||
|
------exclude any prior pricing adjustments from the "current" price in the forecast------
|
||
|
,-cost_loc cost_loc
|
||
|
,-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
|
||
|
---this iteration has to be listed in the master template file in order to be effectively included---
|
||
|
,'b22' AS version
|
||
|
,'upload volume' iter
|
||
|
,log.id
|
||
|
,COALESCE(log.doc->>'tag','') "tag"
|
||
|
,log.doc->>'message' "comment"
|
||
|
,log.doc->>'type' module
|
||
|
FROM
|
||
|
collapse o
|
||
|
,log
|
||
|
)
|
||
|
,ins AS (
|
||
|
SELECT
|
||
|
'2209' fspr
|
||
|
,o.plnt
|
||
|
,o.promo
|
||
|
,o.terms
|
||
|
,o.bill_cust_descr
|
||
|
,o.ship_cust_descr
|
||
|
,o.dsm
|
||
|
,o.quota_rep_descr
|
||
|
,o.director
|
||
|
,o.billto_group
|
||
|
,o.shipto_group
|
||
|
,o.chan
|
||
|
,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
|
||
|
,o.r_currency
|
||
|
,o.r_rate
|
||
|
,o.c_currency
|
||
|
,o.c_rate
|
||
|
,units
|
||
|
,value_loc
|
||
|
,value_usd
|
||
|
-----exclude any prior pricing adjustments from the "current" price in the forecast------
|
||
|
,cost_loc
|
||
|
,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
|
||
|
,'2022-02-01'::date ship_date --history date mix
|
||
|
,'09 - Feb' ship_month
|
||
|
,2022 ship_season
|
||
|
---this iteration has to be listed in the master template file in order to be effectively included---
|
||
|
,'b22' AS version
|
||
|
,'upload volume' iter
|
||
|
,log.id
|
||
|
,COALESCE(log.doc->>'tag','') "tag"
|
||
|
,log.doc->>'message' "comment"
|
||
|
,log.doc->>'type' module
|
||
|
FROM
|
||
|
collapse o
|
||
|
,log
|
||
|
)
|
||
|
INSERT INTO
|
||
|
rlarp.osm_pool
|
||
|
SELECT * FROM rem
|
||
|
UNION ALL
|
||
|
SELECT * FROM ins;
|