forecast_api/route_sql/build/open_timing.sql

103 lines
2.3 KiB
MySQL
Raw Normal View History

2019-03-24 23:25:23 -04:00
WITH
mseq AS (
SELECT * FROM
(
VALUES
('Jun',1,6,-1)
,('Jul',2,7,-1)
,('Aug',3,8,-1)
,('Sep',4,9,-1)
,('Oct',5,10,-1)
,('Nov',6,11,-1)
,('Dec',7,12,-1)
,('Jan',8,1,0)
,('Feb',9,2,0)
,('Mar',10,3,0)
,('Apr',11,4,0)
,('May',12,5,0)
) x(m,s,cal,yr)
)
,alldates AS (
SELECT
shipgrp
,to_char(orderdate,'Mon') orderm
,extract(month FROM age(requestdate,orderdate)) rmo
,(sum((shipdate - requestdate)* (fb_val_loc * r_rate))/sum(fb_val_loc * r_rate))::int wav_lag
--,sum(fb_val_loc * r_rate) value_usd
FROM
rlarp.osm
WHERE
adj_orderdate >= '2017-06-01'
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
AND adj_orderdate <= adj_shipdate
AND fspr IS NOT NULL
GROUP BY
shipgrp
,to_char(orderdate,'Mon')
,extract(month FROM age(requestdate,orderdate))
HAVING
sum(fb_val_loc * r_rate) <> 0
)
,lag AS (
SELECT
shipgrp
,orderm
,rmo
,wav_lag
FROM
alldates
ORDER BY
shipgrp
,orderm
,rmo
)
,opord AS (
SELECT
shipgrp
,orderdate
,requestdate
,shipdate
,to_char(orderdate,'Mon') orderm
,extract(month FROM age(requestdate,orderdate)) rmo
,sum(fb_val_loc * r_rate) value_usd
FROM
rlarp.osm
WHERE
calc_status NOT IN ('CANCELED','CLOSED')
GROUP BY
shipgrp
,orderdate
,requestdate
,shipdate
,to_char(orderdate,'Mon')
,extract(month FROM age(requestdate,orderdate))
ORDER BY
value_usd DESC
)
,rbld AS (
SELECT
o.shipgrp
,o.orderdate
,o.requestdate
,o.shipdate
,o.orderm
,o.rmo
,o.value_usd
,lag.wav_lag
,o.requestdate + lag.wav_lag + 15 rship
FROM
opord o
LEFT OUTER JOIN lag ON
lag.shipgrp = o.shipgrp
AND lag.orderm = o.orderm
AND lag.rmo = o.rmo
ORDER BY
value_usd desc
)
select
sum(value_usd) filter (where rship >= '2019-04-01')
,sum(value_usd) filter (where rship < '2019-04-01')
from
rbld
where
shipdate < '2019-04-01'