forecast_api/route_sql/scenario_package.sql

155 lines
3.6 KiB
MySQL
Raw Normal View History

2019-03-12 17:20:23 -04:00
--\timing
--explain (analyze, buffers)
WITH
mseq AS (
SELECT * FROM
(
VALUES
('Jun',1)
,('Jul',2)
,('Aug',3)
,('Sep',4)
,('Oct',5)
,('Nov',6)
,('Dec',7)
,('Jan',8)
,('Feb',9)
,('Mar',10)
,('Apr',11)
,('May',12)
) x(m,s)
)
--select * from mseq
,base AS (
SELECT
order_season
,order_month
,version
,iter
2019-03-12 17:20:23 -04:00
,part_descr
,bill_cust_descr
,ship_cust_descr
,SUM(units) units
,SUM(value_usd) value_usd
FROM
rlarp.osm_fcpool
WHERE
where_clause
AND order_season IN (2019,2020)
2019-03-12 17:20:23 -04:00
GROUP BY
order_season
,order_month
,version
,iter
2019-03-12 17:20:23 -04:00
,part_descr
,bill_cust_descr
,ship_cust_descr
)
2019-03-19 00:22:00 -04:00
, basket1 AS (
SELECT
part_descr
,bill_cust_descr
,ship_cust_descr
2019-03-19 00:22:00 -04:00
,SUM(value_usd) value_usd
FROM
base
GROUP BY
part_descr
,bill_cust_descr
,ship_cust_descr
2019-03-19 00:22:00 -04:00
)
,basket AS (
SELECT
part_descr
,bill_cust_descr
,ship_cust_descr
,value_usd/sum(value_usd) over () mix
FROM
basket1
2019-03-19 00:24:57 -04:00
ORDER BY
mix DESC
)
2019-03-12 17:20:23 -04:00
,months AS (
SELECT
order_season
,version
,iter
,order_month
,mseq.s seq
,sum(units) units
,sum(value_usd) value_usd
FROM
base
INNER JOIN mseq ON
mseq.m = base.order_month
GROUP BY
order_season
,version
,iter
,order_month
,s
)
,mpvt AS (
SELECT
order_month
,seq
,SUM(units) FILTER (WHERE order_season = 2019) "2019 qty"
,SUM(units) FILTER (WHERE order_season = 2020 AND iter IN ('copy','short ship','bad_ship')) "2020 base qty"
,SUM(units) FILTER (WHERE order_season = 2020 AND iter NOT IN ('copy','short ship','bad_ship')) "2020 adj qty"
,SUM(units) FILTER (WHERE order_season = 2020) "2020 tot qty"
2019-03-12 17:20:23 -04:00
,SUM(value_usd) FILTER (WHERE order_season = 2019) "2019 value_usd"
,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter IN ('copy','short ship','bad_ship')) "2020 base value_usd"
,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter NOT IN ('copy','short ship','bad_ship')) "2020 adj value_usd"
,SUM(value_usd) FILTER (WHERE order_season = 2020) "2020 tot value_usd"
2019-03-12 17:20:23 -04:00
FROM
months
GROUP BY
order_month
,seq
ORDER BY
seq ASC
)
,mlist AS (
SELECT
mseq.m order_month
,"2019 qty"
,"2020 base qty"
,"2020 adj qty"
,"2020 tot qty"
,"2019 value_usd"
,"2020 base value_usd"
,"2020 adj value_usd"
,"2020 tot value_usd"
FROM
mseq
LEFT OUTER JOIN mpvt ON
mpvt.order_month = mseq.m
ORDER BY
mseq.s ASC
)
,totals AS (
SELECT
order_season
,version
,iter
,sum(units) units
,sum(value_usd) value_usd
FROM
months
GROUP BY
order_season
,version
,iter
)
SELECT
jsonb_build_object(
'months'
,(SELECT jsonb_agg(row_to_json(months)::jsonb) FROM months)
,'mpvt'
,(SELECT jsonb_agg(row_to_json(mlist)::jsonb) FROM mlist)
,'basket'
,(SELECT jsonb_agg(row_to_json(basket)::jsonb) FROM basket)
2019-03-12 17:20:23 -04:00
,'totals'
,(SELECT jsonb_agg(row_to_json(totals)::jsonb) FROM totals)
2019-03-12 15:31:24 -04:00
) package