forecast_api/build/move_sales/account_seg_basis.sql

112 lines
3.5 KiB
SQL

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