add pivoted months list
This commit is contained in:
parent
04b43a8f8d
commit
652fcaf44a
137
index.js
137
index.js
@ -109,7 +109,28 @@ server.get('/scenario_package', bodyParser.json(), function (req, res) {
|
||||
//console.log(args);
|
||||
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
|
||||
order_season
|
||||
,order_month
|
||||
@ -125,53 +146,79 @@ server.get('/scenario_package', bodyParser.json(), function (req, res) {
|
||||
WHERE
|
||||
`+ w +
|
||||
`GROUP BY
|
||||
order_season
|
||||
,order_month
|
||||
,version
|
||||
,iter
|
||||
,part_descr
|
||||
,bill_cust_descr
|
||||
,ship_cust_descr
|
||||
)
|
||||
,months AS (
|
||||
SELECT
|
||||
order_season
|
||||
,order_month
|
||||
,version
|
||||
,iter
|
||||
,part_descr
|
||||
,bill_cust_descr
|
||||
,ship_cust_descr
|
||||
)
|
||||
,months AS (
|
||||
SELECT
|
||||
order_season
|
||||
,version
|
||||
,iter
|
||||
,order_month
|
||||
,sum(units) units
|
||||
,sum(value_usd) value_usd
|
||||
FROM
|
||||
base
|
||||
GROUP BY
|
||||
order_season
|
||||
,version
|
||||
,iter
|
||||
,order_month
|
||||
)
|
||||
,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)
|
||||
,'base'
|
||||
,(SELECT jsonb_agg(row_to_json(base)::jsonb) FROM base)
|
||||
,'totals'
|
||||
,(SELECT jsonb_agg(row_to_json(totals)::jsonb) FROM totals)
|
||||
) package`
|
||||
,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
|
||||
)
|
||||
,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(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);
|
||||
Postgres.FirstRow(w, [], res)
|
||||
//res.json("hi")
|
||||
|
@ -1,6 +1,27 @@
|
||||
\timing
|
||||
--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
|
||||
order_season
|
||||
,order_month
|
||||
@ -17,7 +38,7 @@ WHERE
|
||||
quota_rep_descr = '90005 - MARK WILKINSON'
|
||||
AND segm = 'Retail'
|
||||
AND mod_chan = 'MASS'
|
||||
AND order_month = 'May'
|
||||
--AND order_month = 'May'
|
||||
GROUP BY
|
||||
order_season
|
||||
,order_month
|
||||
@ -33,15 +54,39 @@ GROUP BY
|
||||
,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
|
||||
)
|
||||
,totals AS (
|
||||
SELECT
|
||||
@ -61,6 +106,8 @@ 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'
|
||||
|
Loading…
Reference in New Issue
Block a user