From 7ecf3870c3404638a5ec8a9649d7a55a1f399b15 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Tue, 12 Mar 2019 15:31:24 -0400 Subject: [PATCH] update scenario_package route --- index.js | 182 ++++++--------------------------- route_sql/scenario_package.sql | 130 +++++++++++++++++++++++ 2 files changed, 164 insertions(+), 148 deletions(-) create mode 100644 route_sql/scenario_package.sql diff --git a/index.js b/index.js index f3e4a03..41d97d8 100644 --- a/index.js +++ b/index.js @@ -26,6 +26,7 @@ Postgres.FirstRow = function (inSQL, args, inResponse) { inResponse.json(res.rows[0]); return; } + console.log(err.stack); inResponse.json(err.stack); }); }; @@ -75,161 +76,46 @@ server.get('/get_pool', bodyParser.json(), function (req, res) { server.get('/scenario_package', bodyParser.json(), function (req, res) { + var sql = ""; var w = ""; var c = 1; var args = []; + var path = './route_sql/scenario_package.sql'; - for (var i in req.body) { - //console.log(i); - ///console.log(req.body[i]); - if (c > 1) { - w = w + - ` - AND ` + var callback = function(arg){ + sql = arg; + console.log(req.body); + //parse request body into a where clause + for (var i in req.body) { + if (c > 1) { + w = w + + ` + AND ` + } + w = w + i + " = '" + req.body[i] + "'"; + args.push(req.body[i]); + c = c + 1; + }; + //if there was no body sent, return with nothing + if (c == 1) { + res.send("no body was sent"); + return; } - w = w + i + " = '" + req.body[i] + "'"; - args.push(req.body[i]); - c = c + 1; + //parse the where clause into the main sql statement + sql = sql.replace("'where_clause'",w) + //execute the sql and send the result + Postgres.FirstRow(sql,[],res) }; - if (c == 1) { - res.send("no body was sent"); - return; - } - //console.log(w); - //console.log(args); - w = - ` - 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 - `+ w + - `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` - console.log(w); - Postgres.FirstRow(w, [], res) - //res.json("hi") + fs.readFile(path, 'utf8', function(err, data){ + if (!err){ + callback(data); + } else { + console.log("fatal error pulling sql file") + callback(err); + } + }); + }) //---------------------------------------------------------------------------------------------------------------------------------------------------------------- diff --git a/route_sql/scenario_package.sql b/route_sql/scenario_package.sql new file mode 100644 index 0000000..bd78fe3 --- /dev/null +++ b/route_sql/scenario_package.sql @@ -0,0 +1,130 @@ +--\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 \ No newline at end of file