add pivoted months list

This commit is contained in:
Trowbridge 2019-03-02 00:30:29 -05:00
parent 04b43a8f8d
commit 652fcaf44a
2 changed files with 141 additions and 47 deletions

137
index.js
View File

@ -109,7 +109,28 @@ server.get('/scenario_package', bodyParser.json(), function (req, res) {
//console.log(args); //console.log(args);
w = w =
` `
WITH base AS ( 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 SELECT
order_season order_season
,order_month ,order_month
@ -125,53 +146,79 @@ server.get('/scenario_package', bodyParser.json(), function (req, res) {
WHERE WHERE
`+ w + `+ w +
`GROUP BY `GROUP BY
order_season
,order_month
,version
,iter
,part_descr
,bill_cust_descr
,ship_cust_descr
)
,months AS (
SELECT
order_season order_season
,order_month
,version ,version
,iter ,iter
,part_descr ,order_month
,bill_cust_descr ,mseq.s seq
,ship_cust_descr ,sum(units) units
) ,sum(value_usd) value_usd
,months AS ( FROM
SELECT base
order_season INNER JOIN mseq ON
,version mseq.m = base.order_month
,iter GROUP BY
,order_month order_season
,sum(units) units ,version
,sum(value_usd) value_usd ,iter
FROM ,order_month
base ,s
GROUP BY )
order_season ,mpvt AS (
,version SELECT
,iter order_month
,order_month ,seq
) ,SUM(units) FILTER (WHERE order_season = 2019) "2019 qty"
,totals AS ( ,SUM(units) FILTER (WHERE order_season = 2020 AND iter = 'copy') "2020 base qty"
SELECT ,SUM(units) FILTER (WHERE order_season = 2020 AND iter = 'adjustment') "2020 adj qty"
order_season ,SUM(units) FILTER (WHERE order_season = 2020 AND iter IN ('copy','adjustment')) "2020 tot qty"
,version ,SUM(value_usd) FILTER (WHERE order_season = 2019) "2019 value_usd"
,iter ,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter = 'copy') "2020 base value_usd"
,sum(units) units ,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter = 'adjustment') "2020 adj value_usd"
,sum(value_usd) value_usd ,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter IN ('copy','adjustment')) "2020 tot value_usd"
FROM FROM
months months
GROUP BY GROUP BY
order_season order_month
,version ,seq
,iter ORDER BY
) seq ASC
SELECT )
jsonb_build_object( ,totals AS (
'months' SELECT
,(SELECT jsonb_agg(row_to_json(months)::jsonb) FROM months) order_season
,'base' ,version
,(SELECT jsonb_agg(row_to_json(base)::jsonb) FROM base) ,iter
,'totals' ,sum(units) units
,(SELECT jsonb_agg(row_to_json(totals)::jsonb) FROM totals) ,sum(value_usd) value_usd
) package` 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(mpvt)::jsonb) FROM mpvt)
,'base'
,(SELECT jsonb_agg(row_to_json(base)::jsonb) FROM base)
,'totals'
,(SELECT jsonb_agg(row_to_json(totals)::jsonb) FROM totals)
) package`
console.log(w); console.log(w);
Postgres.FirstRow(w, [], res) Postgres.FirstRow(w, [], res)
//res.json("hi") //res.json("hi")

View File

@ -1,6 +1,27 @@
\timing \timing
--explain (analyze, buffers) --explain (analyze, buffers)
WITH base AS ( 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 SELECT
order_season order_season
,order_month ,order_month
@ -17,7 +38,7 @@ WHERE
quota_rep_descr = '90005 - MARK WILKINSON' quota_rep_descr = '90005 - MARK WILKINSON'
AND segm = 'Retail' AND segm = 'Retail'
AND mod_chan = 'MASS' AND mod_chan = 'MASS'
AND order_month = 'May' --AND order_month = 'May'
GROUP BY GROUP BY
order_season order_season
,order_month ,order_month
@ -33,15 +54,39 @@ GROUP BY
,version ,version
,iter ,iter
,order_month ,order_month
,mseq.s seq
,sum(units) units ,sum(units) units
,sum(value_usd) value_usd ,sum(value_usd) value_usd
FROM FROM
base base
INNER JOIN mseq ON
mseq.m = base.order_month
GROUP BY GROUP BY
order_season order_season
,version ,version
,iter ,iter
,order_month ,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
) )
,totals AS ( ,totals AS (
SELECT SELECT
@ -61,6 +106,8 @@ SELECT
jsonb_build_object( jsonb_build_object(
'months' 'months'
,(SELECT jsonb_agg(row_to_json(months)::jsonb) FROM months) ,(SELECT jsonb_agg(row_to_json(months)::jsonb) FROM months)
'mpvt'
,(SELECT jsonb_agg(row_to_json(mpvt)::jsonb) FROM mpvt)
,'base' ,'base'
,(SELECT jsonb_agg(row_to_json(base)::jsonb) FROM base) ,(SELECT jsonb_agg(row_to_json(base)::jsonb) FROM base)
,'totals' ,'totals'