work on making sales adjustments
This commit is contained in:
parent
3e11a3305c
commit
11f6ae2e42
260
build/move_sales/segment_basis.sql
Normal file
260
build/move_sales/segment_basis.sql
Normal file
@ -0,0 +1,260 @@
|
||||
WITH
|
||||
targ AS (
|
||||
SELECT * FROM (VALUES
|
||||
('Pierre','Nursery','HYDROFARM',267888.16),
|
||||
('Pierre','Nursery','ALTMAN PLANTS',71626.22),
|
||||
('Pierre','Nursery','RS GROWERS SUPPLY',17154.0599999999),
|
||||
('Pierre','Nursery','MID-AMERICAN GROWERS',51663.75),
|
||||
('Pierre','Nursery','KAWAHARA NURSERY',48859.2),
|
||||
('Baggetta','Nursery','PACIFIC NURSERY POTS',194412.359999999),
|
||||
('Baggetta','Nursery','FARRAND',171375.300000001),
|
||||
('Baggetta','Nursery','ALPHA FOLIAGE',59200.45),
|
||||
('Baggetta','Nursery','HOLMBERG FARMS INC',52911.6),
|
||||
('Baggetta','Nursery','MATSUDAS BY GREEN ACRES LLC',46723.47),
|
||||
('Baggetta','Nursery','GREENLEAF NURSERY CO',24829.2),
|
||||
('Baggetta','Nursery','GREENHOUSE MEGASTORE',22552.0399999999),
|
||||
('Baggetta','Nursery','HICKORY HILL NURSERY',11072.7),
|
||||
('Baggetta','Nursery','BRANTLEY NURSERIES',9762.47999999998),
|
||||
('Baggetta','Nursery','DALLAS JOHNSON GREENHOUSE',8229.6),
|
||||
('Baggetta','Nursery','BAMA GREEN',1165.5),
|
||||
('Vander Deen','Greenhouse','HJS WHOLESALE LTD',310027.34),
|
||||
('Vander Deen','Greenhouse','DEGOEYS NURSERY FLOWERS',26858.558706),
|
||||
('Vander Deen','Greenhouse','DEVRY GREENHOUSES',10713.15),
|
||||
('Vander Deen','Greenhouse','BIOFLORAL INC',9192.59000000001),
|
||||
('Baggetta','Greenhouse','COSTA',600234.409999999),
|
||||
('Baggetta','Greenhouse','SPARETIME SUPPLY',37966.8499999999),
|
||||
('Baggetta','Greenhouse','ALPHA FOLIAGE',32183.66),
|
||||
('Baggetta','Greenhouse','CASSCO',24248.74)
|
||||
) x(director,glec,account,amount)
|
||||
)
|
||||
,sdate AS (
|
||||
SELECT
|
||||
targ.director
|
||||
,targ.glec
|
||||
,targ.account
|
||||
,targ.amount
|
||||
,p.order_season
|
||||
,p.order_date
|
||||
,p.ship_date
|
||||
,p.ship_season
|
||||
,p.part
|
||||
,sum(p.value_usd) value_usd
|
||||
FROM
|
||||
rlarp.osm_pool p
|
||||
INNER JOIN targ ON
|
||||
p.billto_group = targ.account
|
||||
AND p.segm = targ.glec
|
||||
AND p.director = targ.director
|
||||
WHERE
|
||||
--order_season = 2021
|
||||
ship_season = 2021
|
||||
GROUP BY
|
||||
targ.director
|
||||
,targ.glec
|
||||
,targ.account
|
||||
,targ.amount
|
||||
,p.order_season
|
||||
,p.order_date
|
||||
,p.ship_date
|
||||
,p.ship_season
|
||||
,p.part
|
||||
)
|
||||
,rev AS (
|
||||
SELECT
|
||||
director
|
||||
,glec
|
||||
,account
|
||||
,amount
|
||||
,order_season
|
||||
,order_date
|
||||
,part
|
||||
,ship_date
|
||||
,ship_season
|
||||
,(ship_date + INTERVAL '1 year')::date rev_date
|
||||
,gld.ssyr
|
||||
,gld.fspr
|
||||
,value_usd
|
||||
,sum(value_usd) OVER (PARTITION BY director, glec, account, amount ORDER BY ship_date DESC, part) agg
|
||||
,row_number() OVER (PARTITION BY director, glec, account, amount ORDER BY ship_date DESC) rn
|
||||
,CASE WHEN sum(value_usd) OVER (PARTITION BY director, glec, account, amount ORDER BY ship_date DESC, part) >= amount THEN true ELSE false END flag
|
||||
FROM
|
||||
sdate
|
||||
LEFT OUTER JOIN rlarp.gld gld ON
|
||||
gld.drange @> (ship_date + INTERVAL '1 year')::date
|
||||
ORDER BY
|
||||
director
|
||||
,glec
|
||||
,account
|
||||
,order_season
|
||||
,amount
|
||||
,ship_date DESC
|
||||
)
|
||||
,rnk AS (
|
||||
SELECT
|
||||
director,glec ,account
|
||||
,min(rn) FILTER (WHERE flag = true) mflag
|
||||
FROM
|
||||
rev
|
||||
GROUP BY
|
||||
director,glec ,account ,account
|
||||
)
|
||||
,rejoin AS (
|
||||
SELECT
|
||||
rev.*
|
||||
,rnk.mflag
|
||||
,account || ' - '||to_char(amount,'FM999,999') goal
|
||||
,rev.rn <= rnk.mflag AS include
|
||||
FROM
|
||||
rnk
|
||||
NATURAL JOIN rev
|
||||
)
|
||||
--SELECT * FROM rejoin
|
||||
,logl AS (
|
||||
INSERT INTO
|
||||
rlarp.osm_log(doc)
|
||||
SELECT
|
||||
jsonb_build_object(
|
||||
'stamp',current_timestamp
|
||||
,'user','Trowbridge, Paul'
|
||||
,'source','script'
|
||||
,'tag','smooth sales'
|
||||
,'message','need to carry more orders to reflect what happened in 2020'
|
||||
,'type','smooth sales'
|
||||
,'version','b21'
|
||||
) doc RETURNING *
|
||||
)
|
||||
,remove AS (
|
||||
SELECT
|
||||
p.fspr
|
||||
,p.plnt
|
||||
,p.promo
|
||||
,p.terms
|
||||
,p.bill_cust_descr
|
||||
,p.ship_cust_descr
|
||||
,p.dsm
|
||||
,p.quota_rep_descr
|
||||
,p.director
|
||||
,p.billto_group
|
||||
,p.shipto_group
|
||||
,p.chan
|
||||
,p.chansub
|
||||
,p.chan_retail
|
||||
,p.part
|
||||
,p.part_descr
|
||||
,p.part_group
|
||||
,p.branding
|
||||
,p.majg_descr
|
||||
,p.ming_descr
|
||||
,p.majs_descr
|
||||
,p.mins_descr
|
||||
,p.segm
|
||||
,p.substance
|
||||
,p.fs_line
|
||||
,p.r_currency
|
||||
,p.r_rate
|
||||
,p.c_currency
|
||||
,p.c_rate
|
||||
,-p.units units
|
||||
,-p.value_loc value_loc
|
||||
,-p.value_usd value_usd
|
||||
,-p.cost_loc cost_loc
|
||||
,-p.cost_usd cost_usd
|
||||
,p.calc_status
|
||||
,p.flag
|
||||
,p.order_date
|
||||
,p.order_month
|
||||
,p.order_season
|
||||
,p.request_date
|
||||
,p.request_month
|
||||
,p.request_season
|
||||
,p.ship_date
|
||||
,p.ship_month
|
||||
,p.ship_season
|
||||
,'b21' AS version
|
||||
,'adj timing' iter
|
||||
,logl.id logid
|
||||
,logl.doc->>'tag' tag
|
||||
,logl.doc->>'message' "comment"
|
||||
,logl.doc->>'type' module
|
||||
FROM
|
||||
rlarp.osm_pool p
|
||||
INNER JOIN rejoin r ON
|
||||
r.account = p.billto_group
|
||||
AND r.director = p.director
|
||||
AND r.glec = p.segm
|
||||
AND r.order_date = p.order_date
|
||||
AND r.ship_date = p.ship_date
|
||||
AND r.part = p.part
|
||||
CROSS JOIN logl
|
||||
WHERE
|
||||
r.include
|
||||
)
|
||||
,repl AS (
|
||||
SELECT
|
||||
gld.fspr
|
||||
,p.plnt
|
||||
,p.promo
|
||||
,p.terms
|
||||
,p.bill_cust_descr
|
||||
,p.ship_cust_descr
|
||||
,p.dsm
|
||||
,p.quota_rep_descr
|
||||
,p.director
|
||||
,p.billto_group
|
||||
,p.shipto_group
|
||||
,p.chan
|
||||
,p.chansub
|
||||
,p.chan_retail
|
||||
,p.part
|
||||
,p.part_descr
|
||||
,p.part_group
|
||||
,p.branding
|
||||
,p.majg_descr
|
||||
,p.ming_descr
|
||||
,p.majs_descr
|
||||
,p.mins_descr
|
||||
,p.segm
|
||||
,p.substance
|
||||
,p.fs_line
|
||||
,p.r_currency
|
||||
,p.r_rate
|
||||
,p.c_currency
|
||||
,p.c_rate
|
||||
,p.units units
|
||||
,p.value_loc value_loc
|
||||
,p.value_usd value_usd
|
||||
,p.cost_loc cost_loc
|
||||
,p.cost_usd cost_usd
|
||||
,p.calc_status
|
||||
,p.flag
|
||||
,p.order_date
|
||||
,p.order_month
|
||||
,p.order_season
|
||||
,p.request_date
|
||||
,p.request_month
|
||||
,p.request_season
|
||||
,p.ship_date + INTERVAL '1 year'
|
||||
,gld.sspr || ' - ' || to_char(p.ship_date,'Mon') ship_month
|
||||
,gld.ssyr ship_season
|
||||
,'b21' AS version
|
||||
,'adj timing' iter
|
||||
,logl.id logid
|
||||
,logl.doc->>'tag' tag
|
||||
,logl.doc->>'message' "comment"
|
||||
,logl.doc->>'type' module
|
||||
FROM
|
||||
rlarp.osm_pool p
|
||||
INNER JOIN rejoin r ON
|
||||
r.account = p.billto_group
|
||||
AND r.director = p.director
|
||||
AND r.glec = p.segm
|
||||
AND r.order_date = p.order_date
|
||||
AND r.ship_date = p.ship_date
|
||||
AND r.part = p.part
|
||||
CROSS JOIN logl
|
||||
LEFT OUTER JOIN rlarp.gld gld ON
|
||||
gld.drange @> (p.ship_date + INTERVAL '1 year')::date
|
||||
WHERE
|
||||
r.include
|
||||
)
|
||||
INSERT INTO rlarp.osm_pool SELECT * FROM remove UNION ALL SELECT * FROM repl;
|
208
offline/scale_salesmargin.sql
Normal file
208
offline/scale_salesmargin.sql
Normal file
@ -0,0 +1,208 @@
|
||||
--BEGIN;
|
||||
|
||||
WITH
|
||||
--------for this script the req values are just the increment---------
|
||||
req AS (
|
||||
SELECT
|
||||
-1000000 value_d
|
||||
,-582302 cost_d
|
||||
)
|
||||
---------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
|
||||
o.segm = 'Greenhouse'
|
||||
AND o.ship_season = '2022'
|
||||
AND o.ship_month = '08 - Jan'
|
||||
AND o.order_month = '08 - Jan'
|
||||
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
|
||||
)
|
||||
------------------cost/units adjustment percent------------------
|
||||
,adj_c AS (
|
||||
SELECT
|
||||
(SELECT cost_d FROM req) adj_d
|
||||
,(SELECT cost_d FROM req)/SUM(o.cost_usd) adj_p
|
||||
FROM
|
||||
collapse o
|
||||
)
|
||||
-----------------sales value adjustment percent-----------------
|
||||
,adj_v AS (
|
||||
SELECT
|
||||
(SELECT value_d FROM req) adj_d
|
||||
,(SELECT value_d FROM req)/SUM(o.value_usd) adj_p
|
||||
FROM
|
||||
collapse o
|
||||
)
|
||||
--SELECT * from adj;
|
||||
----------------create a log entry--------------------
|
||||
,log AS (
|
||||
INSERT INTO
|
||||
rlarp.osm_log(doc)
|
||||
SELECT
|
||||
$${
|
||||
"message":"sales smooth",
|
||||
"tag":"sales smooth",
|
||||
"type":"build"
|
||||
}$$::jsonb doc
|
||||
RETURNING *
|
||||
)
|
||||
-------------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
|
||||
,units *adj_c.adj_p units
|
||||
,value_loc *adj_v.adj_p value_loc
|
||||
,value_usd *adj_v.adj_p value_usd
|
||||
,cost_loc *adj_c.adj_p cost_loc
|
||||
,cost_usd *adj_c.adj_p 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
|
||||
--need to join to itemm to get the product from osm_pool
|
||||
,log
|
||||
,adj_c
|
||||
,adj_v
|
||||
)
|
||||
--SELECT *, SUM(VALUE_USD) OVER() FROM (SELECT order_season, order_month, sum(value_usd) value_usd from ins group by order_season, order_month) as x;
|
||||
INSERT INTO rlarp.osm_pool SELECT * FROM ins;
|
||||
--SELECT * FROM ins WHERE shipto_group = 'BATTLEFIELD FARMS' and part = 'XNT0TQT3X56B220PYDKP';
|
||||
-----------aggregate the impact------------
|
||||
|
||||
--COMMIT;
|
Loading…
Reference in New Issue
Block a user