diff --git a/index.js b/index.js index 1802ef4..fb631ca 100644 --- a/index.js +++ b/index.js @@ -88,20 +88,24 @@ server.get('/baseline', bodyParser.json(), function(req, res) { var path = './routes/baseline/baseline.sql'; var args = []; - fs.readFile(path, 'utf8', function(err, fileContents) { + Postgres.query("SELECT t FROM fc.sql WHERE cmd = 'baseline'", []).then((result, error) => { - if (err) { + if (error) { console.log("fatal error pulling sql file"); return; } + sql = result.rows[0].t + console.log(new Date().toISOString() + "-------------------------baseline build-----------------------------") - sql = SQLTemplate(fileContents, { + sql = SQLTemplate(sql, { ...req.body, app_req: JSON.stringify(req.body) }); + console.log(sql) + Postgres.query(sql, []).then((result, error) => { res.json(result[1].rows[0]); }); @@ -119,13 +123,15 @@ server.get('/scale', bodyParser.json(), function(req, res) { var path = './routes/scale/scale.sql'; - fs.readFile(path, 'utf8', function(err, data) { + Postgres.query("SELECT t FROM fc.sql WHERE cmd = 'scale'", []).then((result, error) => { - if (err) { + if (error) { console.log("fatal error pulling sql file") return } + sql = result.rows[0].t; + ({ c: check, w: where } = build_where(req, check, where)); //if there was no body sent, return with nothing //if (c == 1) { @@ -134,7 +140,7 @@ server.get('/scale', bodyParser.json(), function(req, res) { //} console.log(new Date().toISOString() + "-------------------------scale type adjustment----------------------") - let sql = SQLTemplate(data, { + sql = SQLTemplate(sql, { app_req: JSON.stringify(req.body), app_forecast_name: req.body.app_forecast_name, app_where: where diff --git a/routes/baseline/baseline.sql b/routes/baseline/baseline.sql deleted file mode 100644 index 8e25f02..0000000 --- a/routes/baseline/baseline.sql +++ /dev/null @@ -1,119 +0,0 @@ -DELETE FROM fc.dcard WHERE app_version = 'app_forecast_name'; -WITH -req AS (SELECT $$app_req$$::jsonb j) -,ilog AS ( - INSERT INTO - fc.log (doc) - SELECT - req.j - FROM - req - RETURNING * -) -,baseline AS ( -SELECT - null::integer AS id - ,null::integer AS logid - ,o."Trans. Date" - ,o."Post Date" - ,o."Description" - ,sum(o."Amount") AS "Amount" - ,o."Category" - ,o."Party" - ,o."Reason" - ,sum(o.app_units) AS app_units - ,'app_forecast_name' AS app_version - ,'baseline' AS app_iter - ,(SELECT id FROM ilog) AS app_logid -FROM - fc.dcard o -WHERE - ( - --base period orders booked.... - "Trans. Date" BETWEEN 'app_baseline_from_date'::date AND 'app_baseline_to_date'::date - --...or any open orders currently booked before cutoff.... - OR ("Description" IN (app_openstatus_code) and "Trans. Date" <= 'app_openorder_cutoff'::date) - --...or anything that shipped in that period - OR ("Post Date" BETWEEN 'app_baseline_from_date'::date AND 'app_baseline_to_date'::date) - ) - --be sure to pre-exclude unwanted items, like canceled orders, non-gross sales, and short-ships -GROUP BY - o."Trans. Date" - ,o."Post Date" - ,o."Description" - ,o."Category" - ,o."Party" - ,o."Reason" -UNION ALL -SELECT - null::integer AS id - ,null::integer AS logid - ,o."Trans. Date" + interval '1 year' AS "Trans. Date" - ,o."Post Date" + interval '1 year' AS "Post Date" - ,o."Description" - ,sum(o."Amount") AS "Amount" - ,o."Category" - ,o."Party" - ,o."Reason" - ,sum(o.app_units) AS app_units - ,'app_forecast_name' AS app_version - ,'baseline' AS app_iter - ,(SELECT id FROM ilog) AS app_logid -FROM - fc.dcard o - LEFT OUTER JOIN fc.perd tdate ON - (o."Trans. Date" + interval '1 year' )::date <@ tdate.drange - LEFT OUTER JOIN fc.perd pdate ON - (o."Post Date" + interval '1 year' )::date <@ pdate.drange -WHERE - "Trans. Date" BETWEEN 'app_plug_fromdate'::date AND 'app_plug_todate'::date - --be sure to pre-exclude unwanted items, like canceled orders, non-gross sales, and short-ships -GROUP BY - o."Trans. Date" - ,o."Post Date" - ,o."Description" - ,o."Category" - ,o."Party" - ,o."Reason") -,incr AS ( -SELECT - null::integer AS id - ,null::integer AS logid - ,o."Trans. Date" + interval '1 year' AS "Trans. Date" - ,o."Post Date" + interval '1 year' AS "Post Date" - ,o."Description" - ,sum(o."Amount") AS "Amount" - ,o."Category" - ,o."Party" - ,o."Reason" - ,sum(o.app_units) AS app_units - ,'app_forecast_name' AS app_version - ,'baseline' AS app_iter - ,(SELECT id FROM ilog) AS app_logid -FROM - baseline o -LEFT OUTER JOIN fc.perd tdate ON - (o."Trans. Date" + interval '1 year' )::date <@ tdate.drange - LEFT OUTER JOIN fc.perd pdate ON - (o."Post Date" + interval '1 year' )::date <@ pdate.drange -GROUP BY - o."Trans. Date" - ,o."Post Date" - ,o."Description" - ,o."Category" - ,o."Party" - ,o."Reason" -) -,ins AS ( -INSERT INTO - fc.dcard -SELECT - * -FROM - incr i -WHERE - i."Trans. Date" >= 'app_first_forecast_date'::date - OR i."Post Date" >= 'app_first_forecast_date'::date -RETURNING * -) -SELECT COUNT(*) num_rows FROM ins diff --git a/routes/baseline/generate_route_sql.sh b/routes/baseline/generate_route_sql.sh deleted file mode 100755 index 6a1edf0..0000000 --- a/routes/baseline/generate_route_sql.sh +++ /dev/null @@ -1,4 +0,0 @@ -# execure the sql for baseline which builds the sql and inserts into a table -#$PG -f routes/baseline/gen_baseline.sql -# pull the sql out of the table and write it to route directory -psql -h hptrow.me -p 54329 -d ubm -U ptrowbridge -c "SELECT t FROM fc.sql WHERE cmd = 'baseline'" -t -A -o routes/baseline/baseline.sql diff --git a/routes/scale/generate_route_sql.sh b/routes/scale/generate_route_sql.sh deleted file mode 100755 index 4aa8bcc..0000000 --- a/routes/scale/generate_route_sql.sh +++ /dev/null @@ -1,4 +0,0 @@ -# execure the sql for scale which builds the sql and inserts into a table -psql -h hptrow.me -p 54329 -d ubm -U ptrowbridge -f ./setup_sql/05_gen_scale.sql -# pull the sql out of the table and write it to route directory -psql -h hptrow.me -p 54329 -d ubm -U ptrowbridge -c "SELECT t FROM fc.sql WHERE cmd = 'scale'" -t -A -o ./routes/scale/scale.sql diff --git a/routes/scale/req.json b/routes/scale/req.json deleted file mode 100644 index dc88e4c..0000000 --- a/routes/scale/req.json +++ /dev/null @@ -1,19 +0,0 @@ -{ - "app_scenario": { - "chan": "WHS", - "account": "GRIFFIN", - "part": "XNS0T1G3G18B096", - "iter": [ - "baseline" - ] - }, - "stamp": "2020-02-19 17:03:38", - "user": "Trowbridge, Paul", - "source": "adj", - "message": "2% on volume and price", - "tag": "standard price", - "version": "forecast_name", - "type": "scale_vp", - "app_vincr": 20000, - "app_pincr": 10000 -} diff --git a/routes/scale/scale.sql b/routes/scale/scale.sql deleted file mode 100644 index 7ae06de..0000000 --- a/routes/scale/scale.sql +++ /dev/null @@ -1,159 +0,0 @@ -WITH -req AS (SELECT $$app_req$$::jsonb j) -,target AS ( - SELECT - (req.j->>'app_vincr')::numeric vincr --volume - ,(req.j->>'app_pincr')::numeric pincr --price - FROM - req -) ------this block is supposed to test for new products that might not be in baseline etc------- -,test AS ( - SELECT - sum(app_units) FILTER (WHERE app_iter <> 'ACTUALS') total - ,sum(app_units) FILTER (WHERE app_iter = 'baseline') base - FROM - fc.dcard o - WHERE - app_where -) -,ilog AS ( - INSERT INTO - fc.log (doc) - SELECT - req.j - FROM - req - RETURNING * -) -------need to group basemix and forego any detail iterations -,basemix AS ( -SELECT - o.id - ,o.logid - ,o."Trans. Date" - ,o."Post Date" - ,o."Description" - ,sum(o."Amount") AS "Amount" - ,o."Category" - ,o."Party" - ,o."Reason" - ,sum(o.app_units) AS app_units - ,'app_forecast_name' AS app_version - ,'scale' AS app_iter - ,0::bigint AS app_logid -FROM - fc.dcard o -WHERE - app_where -GROUP BY - o.id - ,o.logid - ,o."Trans. Date" - ,o."Post Date" - ,o."Description" - ,o."Category" - ,o."Party" - ,o."Reason" -), -vscale AS ( - SELECT - (SELECT vincr FROM target) AS target_increment - ,sum(app_units) AS units - ,CASE WHEN sum(app_units) = 0 THEN 0 ELSE (SELECT vincr FROM target)/sum(app_units) END AS factor - FROM - basemix -) -,volume_only AS ( -SELECT - o.id - ,o.logid - ,o."Trans. Date" - ,o."Post Date" - ,o."Description" - ,round(o."Amount" * vscale.factor,2) AS "Amount" - ,o."Category" - ,o."Party" - ,o."Reason" - ,round(o.app_units * vscale.factor,5) AS app_units - ,'app_forecast_name' AS app_version - ,'scale volume' AS app_iter - ,(SELECT id FROM ilog) AS app_logid -FROM - basemix o - CROSS JOIN vscale -WHERE - vscale.factor <> 0 -) -,volume AS ( - SELECT * FROM volume_only - UNION ALL - SELECT * FROM basemix WHERE (SELECT factor FROM vscale) = 0 -) -,pscale AS ( -SELECT - (SELECT pincr FROM target) AS target_increment - ,sum("Amount") AS value - ,CASE WHEN (SELECT sum("Amount") FROM volume) = 0 THEN - --if the base value is -0- scaling will not work, need to generate price, factor goes to -0- - 0 - ELSE - CASE WHEN (SELECT factor FROM vscale) = 0 - --if the incoming volume dataset has just basemix data, then create an absolute factor and multiply by basemix - THEN (SELECT pincr FROM target)/(SELECT sum("Amount") FROM volume) - --if the incoming volume table already has an adjusment, just need to create a true-up factor - --multiplying by the raw factor without adding 1 will work since this data set will be added to the volume data set - ELSE ((SELECT pincr FROM target)-(SELECT sum("Amount") FROM volume))/(SELECT sum("Amount") FROM volume) - END - END factor - ,CASE WHEN (SELECT sum("Amount") FROM volume) = 0 THEN - CASE WHEN ((SELECT pincr::numeric FROM target) - (SELECT sum("Amount") FROM volume)) <> 0 THEN - --if the base value is -0- but the target value hasn't been achieved, derive a price to apply - ((SELECT pincr::numeric FROM target) - (SELECT sum("Amount") FROM volume))/(SELECT sum(app_units) FROM volume) - ELSE - 0 - END - ELSE - 0 - END mod_price -FROM - volume -) -,pricing AS ( -SELECT - o.id - ,o.logid - ,o."Trans. Date" - ,o."Post Date" - ,o."Description" - ,round((CASE WHEN pscale.factor = 0 THEN o.app_units * pscale.mod_price ELSE o."Amount" * pscale.factor END)::numeric,2) AS "Amount" - ,o."Category" - ,o."Party" - ,o."Reason" - ,0::numeric AS app_units - ,'app_forecast_name' AS app_version - ,'scale price' AS app_iter - ,(SELECT id FROM ilog) AS app_logid -FROM - volume o - CROSS JOIN pscale -WHERE - pscale.factor <> 0 or pscale.mod_price <> 0 -) -,ins AS ( -INSERT INTO - fc.dcard -SELECT - * -FROM - volume_only -UNION ALL -SELECT - * -FROM - pricing -RETURNING * -) -SELECT count(*) num_rows FROM ins - - diff --git a/routes/scale/scale_vupd.sql b/routes/scale/scale_vupd.sql deleted file mode 100644 index b25755f..0000000 --- a/routes/scale/scale_vupd.sql +++ /dev/null @@ -1,378 +0,0 @@ -WITH -target AS (select target_vol vincr, target_prc pincr) -,testv AS ( - SELECT - sum(units) tot - ,sum(units) FILTER (WHERE iter = 'copy') base - ,sum(units) FILTER (WHERE module = 'new basket') newpart - FROM - rlarp.osm_pool - WHERE - -----------------scenario---------------------------- - where_clause - -----------------additional params------------------- - AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments - AND order_date <= ship_date - -) -,flagv AS ( - SELECT - tot - ,base - ,newpart - ,CASE WHEN tot = 0 THEN - CASE WHEN base = 0 THEN - CASE WHEN newpart = 0 THEN - 'unclean data. tested -> does not exist' - ELSE - 'scale new part' - END - ELSE - 'scale copy' - END - ELSE - 'scale all' - END flag - FROM - testv -) -,basemix AS ( - SELECT - fspr - ,plnt ---master data - ,promo --history date mix - ,terms - ,bill_cust_descr --history cust mix - ,ship_cust_descr --history cust mix - ,dsm - ,quota_rep_descr --master data - ,director - ,billto_group --master data - ,shipto_group - ,chan --master data - ,chansub - ,chan_retail - ,part - ,part_descr - ,part_group - ,branding - ,majg_descr - ,ming_descr - ,majs_descr - ,mins_descr - ,segm - ,substance - ,fs_line --master data - ,r_currency --history cust mix - ,r_rate --master data - ,c_currency --master data - ,c_rate --master data - ,sum(coalesce(units,0)) units --history value - ,sum(coalesce(value_loc,0)) value_loc --history value - ,sum(coalesce(value_usd,0)) value_usd --0 - ,sum(coalesce(cost_loc,0)) cost_loc --history part mix - ,sum(coalesce(cost_usd,0)) cost_usd - ,calc_status --0 - ,flag --0 - ,order_date --history date mix - ,order_month - ,order_season - ,request_date --history date mix - ,request_month - ,request_season - ,ship_date --history date mix - ,ship_month - ,ship_season - FROM - rlarp.osm_pool - WHERE - -----------------scenario---------------------------- - where_clause - -----------------additional params------------------- - AND CASE (SELECT flag FROM flagv) - WHEN 'scale all' THEN true - WHEN 'scale copy' THEN iter = 'copy' - WHEN 'scale new part' THEN module = 'new basket' - END - AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments - AND order_date <= ship_date - GROUP BY - fspr - ,plnt ---master data - ,promo --history date mix - ,terms - ,bill_cust_descr --history cust mix - ,ship_cust_descr --history cust mix - ,dsm - ,quota_rep_descr --master data - ,director - ,billto_group --master data - ,shipto_group - ,chan --master data - ,chansub - ,chan_retail - ,part - ,part_descr - ,part_group - ,branding - ,majg_descr - ,ming_descr - ,majs_descr - ,mins_descr - ,segm - ,substance - ,fs_line --master data - ,r_currency --history cust mix - ,r_rate --master data - ,c_currency --master data - ,c_rate --master data - ,calc_status --0 - ,flag --0 - ,order_date --history date mix - ,order_month - ,order_season - ,request_date --history date mix - ,request_month - ,request_season - ,ship_date --history date mix - ,ship_month - ,ship_season -) -,vscale AS ( - SELECT - (SELECT vincr::numeric FROM target) incr - ,(SELECT sum(units)::numeric FROM basemix) base - ,(SELECT vincr::numeric FROM target)/(SELECT sum(units)::numeric FROM basemix) factor -) ---select * from vscale -,log AS ( - INSERT INTO rlarp.osm_log(doc) SELECT $$replace_iterdef$$::jsonb doc RETURNING * -) -,volume AS ( - SELECT - fspr - ,plnt ---master data - ,promo --history date mix - ,terms - ,bill_cust_descr --history cust mix - ,ship_cust_descr --history cust mix - ,dsm - ,quota_rep_descr --master data - ,director - ,billto_group --master data - ,shipto_group - ,chan --master data - ,chansub - ,chan_retail - ,part - ,part_descr - ,part_group - ,branding - ,majg_descr - ,ming_descr - ,majs_descr - ,mins_descr - ,segm - ,substance - ,fs_line --master data - ,r_currency --history cust mix - ,r_rate --master data - ,c_currency --master data - ,c_rate --master data - ,units*s.factor units - ,value_loc*s.factor value_loc - ,value_usd*s.factor value_usd - ,cost_loc*s.factor cost_loc - ,cost_usd*s.factor cost_usd - ,calc_status --0 - ,flag --0 - ,order_date --history date mix - ,order_month - ,order_season - ,request_date --history date mix - ,request_month - ,request_season - ,ship_date --history date mix - ,ship_month - ,ship_season - ,'replace_version' "version" - ,'replace_source'||' volume' iter - ,log.id - ,COALESCE(log.doc->>'tag','') "tag" - ,log.doc->>'message' "comment" - ,log.doc->>'type' module -FROM - basemix b - CROSS JOIN vscale s - CROSS JOIN log -) -,pscale AS ( - SELECT - (SELECT pincr::numeric FROM target) incr - ,(SELECT sum(value_loc * r_rate) FROM volume) base - ,CASE WHEN (SELECT sum(value_loc * r_rate) FROM volume) = 0 THEN - --if the base value is -0- scaling will not work, need to generate price, factor goes to -0- - 0 - ELSE - --if the target $amount is not achieved, adjust further - ((SELECT pincr::numeric FROM target)-(SELECT sum(value_loc * r_rate) FROM volume))/(SELECT sum(value_loc * r_rate) FROM volume) - END factor - ,CASE WHEN (SELECT sum(value_loc * r_rate) FROM volume) = 0 THEN - CASE WHEN ((SELECT pincr::numeric FROM target) - (SELECT sum(value_loc * r_rate) FROM volume)) <> 0 THEN - --if the base value is -0- but the target value hasn't been achieved, derive a price to apply - ((SELECT pincr::numeric FROM target) - (SELECT sum(value_loc * r_rate) FROM volume))/(SELECT sum(units) FROM volume) - ELSE - 0 - END - ELSE - 0 - END mod_price -) ---select * from pscale -,pricing AS ( - SELECT - fspr - ,plnt ---master data - ,promo --history date mix - ,terms - ,bill_cust_descr --history cust mix - ,ship_cust_descr --history cust mix - ,dsm - ,quota_rep_descr --master data - ,director - ,billto_group --master data - ,shipto_group - ,chan --master data - ,chansub - ,chan_retail - ,part - ,part_descr - ,part_group - ,branding - ,majg_descr - ,ming_descr - ,majs_descr - ,mins_descr - ,segm - ,substance - ,fs_line --master data - ,r_currency --history cust mix - ,r_rate --master data - ,c_currency --master data - ,c_rate --master data - ,0::numeric units - ,(CASE WHEN s.factor = 0 THEN b.units * s.mod_price/b.r_rate ELSE b.value_loc*s.factor END)::numeric value_loc - ,(CASE WHEN s.factor = 0 THEN b.units * s.mod_price ELSE b.value_usd*s.factor END)::numeric value_usd - ,0::numeric cost_loc - ,0::numeric cost_usd - ,calc_status --0 - ,flag --0 - ,order_date --history date mix - ,order_month - ,order_season - ,request_date --history date mix - ,request_month - ,request_season - ,ship_date --history date mix - ,ship_month - ,ship_season - ,'replace_version' "version" - ,'replace_source'||' price' iter - ,log.id - ,COALESCE(log.doc->>'tag','') "tag" - ,log.doc->>'message' "comment" - ,log.doc->>'type' module - FROM - volume b - CROSS JOIN pscale s - CROSS JOIN log - WHERE - s.factor <> 0 or s.mod_price <> 0 -) ---select sum(value_usd), sum(units) from pricing -, ins AS ( - INSERT INTO rlarp.osm_pool (SELECT * FROM pricing UNION ALL SELECT * FROM volume) RETURNING * -) -,insagg AS ( - SELECT - ---------customer info----------------- - bill_cust_descr - ,billto_group - ,ship_cust_descr - ,shipto_group - ,quota_rep_descr - ,director - ,segm - ,substance - ,chan - ,chansub - ---------product info------------------ - ,majg_descr - ,ming_descr - ,majs_descr - ,mins_descr - --,brand - --,part_family - ,part_group - ,branding - --,color - ,part_descr - ---------dates------------------------- - ,order_season - ,order_month - ,ship_season - ,ship_month - ,request_season - ,request_month - ,promo - ,version - ,iter - ,logid - ,tag - ,comment - --------values------------------------- - ,sum(value_loc) value_loc - ,sum(value_usd) value_usd - ,sum(cost_loc) cost_loc - ,sum(cost_usd) cost_usd - ,sum(units) units - FROM - ins - GROUP BY - ---------customer info----------------- - bill_cust_descr - ,billto_group - ,ship_cust_descr - ,shipto_group - ,quota_rep_descr - ,director - ,segm - ,substance - ,chan - ,chansub - ---------product info------------------ - ,majg_descr - ,ming_descr - ,majs_descr - ,mins_descr - --,brand - --,part_family - ,part_group - ,branding - --,color - ,part_descr - ---------dates------------------------- - ,order_season - ,order_month - ,ship_season - ,ship_month - ,request_season - ,request_month - ,promo - ,version - ,iter - ,logid - ,tag - ,comment -) -SELECT json_agg(row_to_json(insagg)) x from insagg diff --git a/routes/baseline/curl.sh b/test/baseline/curl.sh old mode 100755 new mode 100644 similarity index 100% rename from routes/baseline/curl.sh rename to test/baseline/curl.sh diff --git a/routes/baseline/req.json b/test/baseline/req.json similarity index 100% rename from routes/baseline/req.json rename to test/baseline/req.json diff --git a/routes/scale/curl_route.sh b/test/scale/curl_route.sh old mode 100755 new mode 100644 similarity index 100% rename from routes/scale/curl_route.sh rename to test/scale/curl_route.sh diff --git a/routes/scale/exctract_params.sql b/test/scale/exctract_params.sql similarity index 100% rename from routes/scale/exctract_params.sql rename to test/scale/exctract_params.sql diff --git a/routes/scale/req_dcard.json b/test/scale/req_dcard.json similarity index 100% rename from routes/scale/req_dcard.json rename to test/scale/req_dcard.json