130 lines
2.9 KiB
SQL
130 lines
2.9 KiB
SQL
--\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
|
|
,part_descr
|
|
,bill_cust_descr
|
|
,ship_cust_descr
|
|
,SUM(units) units
|
|
,SUM(value_usd) value_usd
|
|
FROM
|
|
rlarp.osm_fcpool
|
|
WHERE
|
|
'where_clause'
|
|
GROUP BY
|
|
order_season
|
|
,order_month
|
|
,version
|
|
,iter
|
|
,part_descr
|
|
,bill_cust_descr
|
|
,ship_cust_descr
|
|
)
|
|
,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 = 'copy') "2020 base qty"
|
|
,SUM(units) FILTER (WHERE order_season = 2020 AND iter = 'adjustment') "2020 adj qty"
|
|
,SUM(units) FILTER (WHERE order_season = 2020 AND iter IN ('copy','adjustment')) "2020 tot qty"
|
|
,SUM(value_usd) FILTER (WHERE order_season = 2019) "2019 value_usd"
|
|
,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter = 'copy') "2020 base value_usd"
|
|
,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter = 'adjustment') "2020 adj value_usd"
|
|
,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter IN ('copy','adjustment')) "2020 tot value_usd"
|
|
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)
|
|
,'base'
|
|
,(SELECT jsonb_agg(row_to_json(base)::jsonb) FROM base)
|
|
,'totals'
|
|
,(SELECT jsonb_agg(row_to_json(totals)::jsonb) FROM totals)
|
|
) package |