From 3492c802b953ed9e2709c17c02bbe6bda8878c80 Mon Sep 17 00:00:00 2001 From: Trowbridge Date: Wed, 4 Mar 2020 17:13:17 -0500 Subject: [PATCH 01/19] add route to get suggested swap --- index.js | 40 ++++++++++++++++++++++++ route_sql/swap_fit.sql | 71 ++++++++++++++++++++++++++++++++++++++++++ 2 files changed, 111 insertions(+) create mode 100644 route_sql/swap_fit.sql diff --git a/index.js b/index.js index 65128c8..f068a1f 100644 --- a/index.js +++ b/index.js @@ -134,6 +134,46 @@ server.get('/scenario_package', bodyParser.json(), function(req, res) { }; }) +server.get('/swap_fit', bodyParser.json(), function(req, res) { + + var sql = ""; + var w = ""; + var c = 1; + var d = 1; + var args = []; + var path = './route_sql/swap_fit.sql'; + + fs.readFile(path, 'utf8', function(err, data) { + if (!err) { + callback(data); + } else { + console.log("fatal error pulling sql file") + callback(err); + } + }); + + var callback = function(arg) { + sql = arg; + + //parse request body into a where clause + ({ c, w, d } = build_where(req, c, w, d, args)); + + //if there was no body sent, return with nothing + if (c == 1) { + res.send("no body was sent"); + return; + } + console.log(new Date().toISOString() + "-------------------------get swap fit:------------------------------") + console.log(req.body); + //parse the where clause into the main sql statement + sql = sql.replace(new RegExp("where_clause", 'g'), w); + sql = sql.replace(new RegExp("replace_new_mold", 'g'), req.body.new_mold); + //execute the sql and send the result + console.log(sql); + Postgres.FirstRow(sql, [], res) + }; +}) + server.get('/list_changes', bodyParser.json(), function(req, res) { var sql = ""; diff --git a/route_sql/swap_fit.sql b/route_sql/swap_fit.sql new file mode 100644 index 0000000..da9a861 --- /dev/null +++ b/route_sql/swap_fit.sql @@ -0,0 +1,71 @@ +WITH +target AS (select replace_new_mold new_mold) +,basemix AS ( + SELECT + part, + stlc, + colc, + colgrp, + coltier, + sizc, + SUM(value_usd) value_usd + FROM + rlarp.osm_pool o + LEFT OUTER JOIN rlarp.itemmv i ON + i.item = o.part + WHERE + -----------------scenario---------------------------- + where_clause + -----------------additional params------------------- + AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments + AND order_date <= ship_date + GROUP BY + part, + stlc, + colc, + colgrp, + coltier, + sizc +) +--SELECT * FROM basemix +,tag AS ( + SELECT + b.part + ,b.value_usd + --,b.stlc + --,b.sizc + --,b.colgrp + --,b.coltier + --,b.colc + ,i.item + ,CASE WHEN b.sizc = i.sizc THEN '1' ELSE '0' END|| + CASE WHEN i.aplnt = 'I' THEN '0' ELSE '1' END|| + CASE WHEN b.colgrp = i.colgrp THEN '1' ELSE '0' END|| + CASE WHEN b.coltier = i.coltier THEN '1' ELSE '0' END|| + CASE WHEN b.colc = i.colc THEN '1' ELSE '0' END|| + CASE WHEN substring(b.part,9,12) = substring(i.item,9,12) THEN '1' ELSE 0 END fit + FROM + basemix b + LEFT OUTER JOIN rlarp.itemmv i ON + i.stlc = (SELECT new_mold FROM target) +) +--SELECT * FROM tag +,rsort AS ( +SELECT + part, + value_usd, + item swap, + fit, + ROW_NUMBER() OVER (PARTITION BY tag.part ORDER BY fit DESC) ranked +FROM + tag +ORDER BY + part + ,fit desc +) +SELECT + json_agg(row_to_json(rsort)) x +FROM + rsort +WHERE + ranked = 1 \ No newline at end of file From 28865863bd65cccf42d196b55a115abce47310e5 Mon Sep 17 00:00:00 2001 From: Trowbridge Date: Wed, 4 Mar 2020 17:13:36 -0500 Subject: [PATCH 02/19] filter out low grade matches --- route_sql/swap_fit.sql | 10 ++++++++-- 1 file changed, 8 insertions(+), 2 deletions(-) diff --git a/route_sql/swap_fit.sql b/route_sql/swap_fit.sql index da9a861..a3bdc23 100644 --- a/route_sql/swap_fit.sql +++ b/route_sql/swap_fit.sql @@ -1,5 +1,5 @@ WITH -target AS (select replace_new_mold new_mold) +target AS (select 'replace_new_mold' new_mold) ,basemix AS ( SELECT part, @@ -47,7 +47,13 @@ target AS (select replace_new_mold new_mold) FROM basemix b LEFT OUTER JOIN rlarp.itemmv i ON - i.stlc = (SELECT new_mold FROM target) + i.stlc = (SELECT new_mold FROM target WHERE new_mold <> '') + AND CASE WHEN b.sizc = i.sizc THEN '1' ELSE '0' END|| + CASE WHEN i.aplnt = 'I' THEN '0' ELSE '1' END|| + CASE WHEN b.colgrp = i.colgrp THEN '1' ELSE '0' END|| + CASE WHEN b.coltier = i.coltier THEN '1' ELSE '0' END|| + CASE WHEN b.colc = i.colc THEN '1' ELSE '0' END|| + CASE WHEN substring(b.part,9,12) = substring(i.item,9,12) THEN '1' ELSE 0 END >= '111110' ) --SELECT * FROM tag ,rsort AS ( From 77fe829ece861cfbaf9a491ab13b617306493e28 Mon Sep 17 00:00:00 2001 From: Trowbridge Date: Wed, 4 Mar 2020 17:53:50 -0500 Subject: [PATCH 03/19] posting a part swap --- index.js | 43 +++++++ route_sql/swap_post.sql | 247 ++++++++++++++++++++++++++++++++++++++++ 2 files changed, 290 insertions(+) create mode 100644 route_sql/swap_post.sql diff --git a/index.js b/index.js index f068a1f..d1278b3 100644 --- a/index.js +++ b/index.js @@ -174,6 +174,49 @@ server.get('/swap_fit', bodyParser.json(), function(req, res) { }; }) +server.post('/swap', bodyParser.json(), function(req, res) { + + var sql = ""; + var w = ""; + var c = 1; + var d = 1; + var args = []; + var path = './route_sql/swap_post.sql'; + + fs.readFile(path, 'utf8', function(err, data) { + if (!err) { + callback(data); + } else { + console.log("fatal error pulling sql file") + callback(err); + } + }); + + var callback = function(arg) { + sql = arg; + + //parse request body into a where clause + ({ c, w, d } = build_where(req, c, w, d, args)); + + //if there was no body sent, return with nothing + if (c == 1) { + res.send("no body was sent"); + return; + } + console.log(new Date().toISOString() + "-------------------------get swap fit:------------------------------") + console.log(req.body); + //parse the where clause into the main sql statement + sql = sql.replace(new RegExp("where_clause", 'g'), w); + sql = sql.replace(new RegExp("swap_doc", 'g'), JSON.stringify(req.body.swap)); + sql = sql.replace(new RegExp("replace_version", 'g'), req.body.scenario.version); + sql = sql.replace(new RegExp("replace_source", 'g'), req.body.source); + sql = sql.replace(new RegExp("replace_iterdef", 'g'), JSON.stringify(req.body)); + //execute the sql and send the result + console.log(sql); + Postgres.FirstRow(sql, [], res) + }; +}) + server.get('/list_changes', bodyParser.json(), function(req, res) { var sql = ""; diff --git a/route_sql/swap_post.sql b/route_sql/swap_post.sql new file mode 100644 index 0000000..f126d61 --- /dev/null +++ b/route_sql/swap_post.sql @@ -0,0 +1,247 @@ +WITH +target AS (SELECT $$swap_doc$$::jsonb swap) +,pl AS ( + SELECT + x.* + FROM + TARGET + LEFT JOIN LATERAL jsonb_to_recordset(target.swap->'rows') AS x(original text, sales numeric, replace text, fit text)ON TRUE +) +--select * from pl +,seg AS ( + SELECT + x.glec + ,x.segm + FROM + ( + VALUES + ('1CU','Retail'), + ('1GR','Greenhouse'), + ('1NU','Nursery'), + ('1RE','Retail'), + ('2WI','Greenhouse'), + ('3BM','Other'), + ('3CO','Other'), + ('3PE','Other'), + ('3PP','Other'), + ('4CO','Other'), + ('4RA','Other'), + ('9MI','Other'), + ('9SA','Other'), + ('9TO','Other') + ) x(glec, segm) +) +,log AS ( + INSERT INTO rlarp.osm_log(doc) SELECT $$replace_iterdef$$::jsonb doc RETURNING * +) +,remove 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 units + ,-value_loc value_loc + ,-value_usd value_usd + ,-cost_loc cost_loc + ,-cost_usd 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 + rlarp.osm_pool o + CROSS JOIN log + INNER JOIN pl ON + pl.original = o.part + WHERE + -----------------scenario---------------------------- + where_clause +) +,repl 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 + ,pl.replace part + ,m.item || ' - ' || m.descr partd + ,substring(pl.replace,1,8) part_group + ,m.branding branding + ,m.majgd majg_descr + ,m.mingd ming_descr + ,m.majsd majs_descr + ,m.minsd mins_descr + ,seg.segm + ,substance + ,fs_line --master data + ,r_currency --history cust mix + ,r_rate --master data + ,c_currency --master data + ,c_rate --master data + ,-units units + ,-value_loc value_loc + ,-value_usd value_usd + ,-cost_loc cost_loc + ,-cost_usd 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 + ,o."version" + ,o.iter + ,o.id + ,o."tag" + ,o."comment" + ,o.module + FROM + remove o + INNER JOIN pl ON + pl.original = o.part + INNER JOIN rlarp.itemmv m ON + m.item = o.part + LEFT OUTER JOIN seg ON + seg.glec = m.glec +) +,ins AS ( + INSERT INTO rlarp.osm_pool SELECT * FROM remove UNION ALL SELECT * FROM repl 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 + From 87d5dbceaf0833c47b6241b78dffb865d07f720f Mon Sep 17 00:00:00 2001 From: Trowbridge Date: Thu, 5 Mar 2020 00:59:59 -0500 Subject: [PATCH 04/19] handle costs and major groups --- route_sql/swap_post.sql | 30 ++++++++++++++++++++---------- 1 file changed, 20 insertions(+), 10 deletions(-) diff --git a/route_sql/swap_post.sql b/route_sql/swap_post.sql index f126d61..518d69f 100644 --- a/route_sql/swap_post.sql +++ b/route_sql/swap_post.sql @@ -99,7 +99,7 @@ target AS (SELECT $$swap_doc$$::jsonb swap) ,repl AS ( SELECT fspr - ,plnt ---master data + ,m.dplt plnt ---master data ,promo --history date mix ,terms ,bill_cust_descr --history cust mix @@ -116,22 +116,22 @@ target AS (SELECT $$swap_doc$$::jsonb swap) ,m.item || ' - ' || m.descr partd ,substring(pl.replace,1,8) part_group ,m.branding branding - ,m.majgd majg_descr - ,m.mingd ming_descr - ,m.majsd majs_descr - ,m.minsd mins_descr + ,m.majg||' - '||m.majgd majg_descr + ,m.ming||' - '||m.mingd ming_descr + ,m.majs||' - '||m.majsd majs_descr + ,m.mins||' - '||m.minsd mins_descr ,seg.segm ,substance ,fs_line --master data ,r_currency --history cust mix ,r_rate --master data - ,c_currency --master data - ,c_rate --master data + ,r.curr c_currency --master data + ,x.rate c_rate --master data ,-units units ,-value_loc value_loc ,-value_usd value_usd - ,-cost_loc cost_loc - ,-cost_usd cost_usd + ,-units * c.std cost_loc + ,-units * c.std * x.rate cost_usd ,calc_status --0 ,flag --0 ,order_date --history date mix @@ -154,7 +154,17 @@ target AS (SELECT $$swap_doc$$::jsonb swap) INNER JOIN pl ON pl.original = o.part INNER JOIN rlarp.itemmv m ON - m.item = o.part + m.item = pl.replace + LEFT OUTER JOIN rlarp.icstx c ON + c.part = pl.replace + AND c.plnt = m.dplt + LEFT OUTER JOIN rlarp.plpr r ON + yaplnt = m.dplt + LEFT OUTER JOIN rlarp.ffcret x ON + x.fcur = r.curr + AND x.tcur = 'US' + AND x.rtyp = 'BG' + AND x.perd = '2101' LEFT OUTER JOIN seg ON seg.glec = m.glec ) From 3d5cd9b2ff59170eda5ad82767c0cf1505589395 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Fri, 6 Mar 2020 05:48:39 +0000 Subject: [PATCH 05/19] only swap parts if a replacement is given --- route_sql/swap_post.sql | 2 ++ 1 file changed, 2 insertions(+) diff --git a/route_sql/swap_post.sql b/route_sql/swap_post.sql index 518d69f..13bdc43 100644 --- a/route_sql/swap_post.sql +++ b/route_sql/swap_post.sql @@ -6,6 +6,8 @@ target AS (SELECT $$swap_doc$$::jsonb swap) FROM TARGET LEFT JOIN LATERAL jsonb_to_recordset(target.swap->'rows') AS x(original text, sales numeric, replace text, fit text)ON TRUE + WHERE + COALESCE(x.replace,'') <> '' ) --select * from pl ,seg AS ( From e201302953565e48348d98b0cdb58a5e05607fc5 Mon Sep 17 00:00:00 2001 From: pt Date: Thu, 12 Mar 2020 14:19:46 -0400 Subject: [PATCH 06/19] update customers in pool --- build/snap_cust_pool.sql | 83 ++++++++++++++++++++++++++++++++++++++++ 1 file changed, 83 insertions(+) create mode 100644 build/snap_cust_pool.sql diff --git a/build/snap_cust_pool.sql b/build/snap_cust_pool.sql new file mode 100644 index 0000000..2477189 --- /dev/null +++ b/build/snap_cust_pool.sql @@ -0,0 +1,83 @@ +--BEGIN; + +UPDATE + rlarp.osm_pool o +SET + chan = CASE SUBSTRING(b.bvclas,2,3) + --if the bill to class is ditsributor, then it's either warehouse or drop + WHEN 'DIS' THEN + --if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse + CASE SUBSTRING(s.bvclas,2,3) + WHEN 'DIS' THEN 'WHS' + ELSE 'DRP' + END + --CASE WHEN RTRIM(SUBSTRING(LTRIM(SC.BVADR7)||SC.BVNAME,1,30)) = RTRIM(SUBSTRING(LTRIM(BC.BVADR7)||BC.BVNAME,1,30)) THEN 'DIS' ELSE 'DRP' END + --everything else does not involve a distributor and is considered direct + ELSE 'DIR' + END, + chansub = CASE SUBSTRING(b.bvclas,2,3) + WHEN 'DIS' THEN + --if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse + CASE SUBSTRING(s.bvclas,2,3) + WHEN 'DIS' THEN 'WHS' + ELSE CASE SUBSTRING(s.bvclas,1,1) WHEN 'R' THEN 'RDP' ELSE 'DRP' END + END + WHEN 'MAS' THEN 'RMN' + WHEN 'NAT' THEN 'RMN' + ELSE CASE SUBSTRING(s.bvclas,1,1) WHEN 'R' THEN 'RDI' ELSE 'DIR' END + END, + dsm = RTRIM( + --retail items go to currep, or if null go to 90005 + CASE WHEN o.segm IN ('Retail') THEN + CASE WHEN b.bvctry = 'CAN' THEN + --Rachel Bowman + '50300' + ELSE + --select customers go to select reps + CASE CASE b.bvadr6 WHEN '' THEN b.bvname ELSE b.bvadr6 END + ------Alecia Latini------------------------------- + WHEN 'DO IT BEST' THEN '90006' + WHEN 'ACE HARDWARE' THEN '90006' + WHEN 'ALDI' THEN '90006' + WHEN 'AMAZON.COM' THEN '90006' + WHEN 'GARDEN RIDGE CORP' THEN '90006' --AKA "At Home" + WHEN 'TRUE VALUE' THEN '90006' + WHEN 'WAYFAIR' THEN '90006' + WHEN 'GRIFFIN' THEN '90006' + WHEN 'WAL-MART' THEN '90006' + ------Tony Landino-------------------------------- + WHEN 'THE HOME DEPOT' THEN '50802' + WHEN 'FRED MEYER' THEN '50802' + WHEN 'MENARDS' THEN '50802' + WHEN 'KROGER' THEN '50802' + WHEN 'OCEAN STATE JOBBERS' THEN '50802' + WHEN 'AURORA WHOLESALE' THEN '50802' + WHEN 'LEON KORRAL' THEN '50802' + --all other retail goes to Doran Marable----------- + ELSE '50200' + END + END + --minor group b52 goes to dedicated rep + ELSE + CASE WHEN SUBSTRING(o.ming_descr,1,3) = 'B52' THEN + 'PW' + --gdir, ndir go to bill-to rep + ELSE + CASE WHEN b.bvclas IN ('GDIR','NDIR') THEN + b.bvsalm + ELSE + s.bvsalm + END + END + END + ), + billto_group = CASE b.bvadr6 WHEN '' THEN b.bvname ELSE b.bvadr6 END, + shipto_group = CASE s.bvadr6 WHEN '' THEN s.bvname ELSE s.bvadr6 END +FROM + lgdat.cust b, + lgdat.cust s +WHERE + b.bvcust = rtrim(substring(o.bill_cust_descr,1,8)) + AND s.bvcust = rtrim(substring(o.ship_cust_descr,1,8)); + +--ROLLBACK; \ No newline at end of file From f34b0d539d49b173d3ef9cc1a4df5143ca506734 Mon Sep 17 00:00:00 2001 From: pt Date: Thu, 12 Mar 2020 14:20:09 -0400 Subject: [PATCH 07/19] update quote rep descr and director --- build/snap_cust_pool.sql | 22 ++++++++++++++++++++-- 1 file changed, 20 insertions(+), 2 deletions(-) diff --git a/build/snap_cust_pool.sql b/build/snap_cust_pool.sql index 2477189..df91ed4 100644 --- a/build/snap_cust_pool.sql +++ b/build/snap_cust_pool.sql @@ -1,4 +1,6 @@ ---BEGIN; +BEGIN; + +--SELECT dsm, director, quota_rep_descr, billto_group, shipto_group, sum(value_usd ), count(*) from rlarp.osm_pool where order_season = 2021 group by dsm, director, quota_rep_descr, billto_group, shipto_group; UPDATE rlarp.osm_pool o @@ -80,4 +82,20 @@ WHERE b.bvcust = rtrim(substring(o.bill_cust_descr,1,8)) AND s.bvcust = rtrim(substring(o.ship_cust_descr,1,8)); ---ROLLBACK; \ No newline at end of file +BEGIN; + +UPDATE + rlarp.osm_pool o +SET + quota_rep_descr = c.a30 + ,director = COALESCE(Q.DIR,'Other') +FROM + lgdat.code c + ,rlarp.qrh q +WHERE + LTRIM(RTRIM(c.a9)) = o.dsm + and c.a2 = 'MM' + AND q.qr = LTRIM(RTRIM(c.a9)); + + +ROLLBACK; \ No newline at end of file From 3540c356293ad6747b451579343c6a0059fc74a0 Mon Sep 17 00:00:00 2001 From: pt Date: Thu, 12 Mar 2020 23:58:39 -0400 Subject: [PATCH 08/19] add list of customers --- route_sql/scenario_package.sql | 13 +++++++++++++ 1 file changed, 13 insertions(+) diff --git a/route_sql/scenario_package.sql b/route_sql/scenario_package.sql index 39338cb..b1d68d4 100644 --- a/route_sql/scenario_package.sql +++ b/route_sql/scenario_package.sql @@ -157,6 +157,17 @@ GROUP BY ('volume') ) x(tag) ) +,custs AS ( + SELECT + bill_cust_descr + ,ship_cust_descr + ,SUM(value_usd) value_usd + FROM + base + GROUP BY + bill_cust_descr + ,ship_cust_descr +) SELECT jsonb_build_object( 'months' @@ -169,4 +180,6 @@ SELECT ,(SELECT jsonb_agg(row_to_json(totals)::jsonb) FROM totals) ,'tags' ,(SELECT jsonb_agg(tag) FROM tags) + ,'customers' + ,(SELECT jsonb_agg(row_to_json(custs)::jsonb) FROM custs) ) package \ No newline at end of file From ebc7d90dc591a9d475f4201d6068e588902e1e98 Mon Sep 17 00:00:00 2001 From: pt Date: Fri, 13 Mar 2020 01:37:57 -0400 Subject: [PATCH 09/19] work on customer swap route --- route_sql/swap_cust.sql | 268 ++++++++++++++++++++++++++++++++++++++++ 1 file changed, 268 insertions(+) create mode 100644 route_sql/swap_cust.sql diff --git a/route_sql/swap_cust.sql b/route_sql/swap_cust.sql new file mode 100644 index 0000000..46a66ab --- /dev/null +++ b/route_sql/swap_cust.sql @@ -0,0 +1,268 @@ +WITH +target AS (SELECT $$swap_doc$$::jsonb swap) +,swap AS ( + SELECT + rtrim(substring(bill,1,8)) billto + ,rtrim(substring(bill_r,1,8)) bill_r + ,rtrim(substring(ship,1,8)) shipto + ,rtrim(substring(ship_r,1,8)) ship_r + FROM + TARGET + LEFT JOIN LATERAL jsonb_to_recordset(target.swap->'rows') AS x(bill text, bill_r text, ship text, ship_r text)ON TRUE + WHERE + rtrim(substring(bill_r,1,8)) IS NOT null + OR rtrim(substring(ship_r,1,8)) IS NOT null +) +,cust AS ( + SELECT + billto + ,bill_r + ,bill_dba + ,shipto + ,ship_r + ,ship_dba + --other stuff doesn't matter becuase it's getting overridden anyways + FROM + swap + LEFT out JOIN lgdat.cust bc ON + bc.bvcust = swap.bill_r + LEFT out JOIN lgdat.cust sc ON + bc.bvcust = swap.ship_r +) +--put bill to and ship to back together and join in channel, terms, descriptions, etc +,seg AS ( + SELECT + x.glec + ,x.segm + FROM + ( + VALUES + ('1CU','Retail'), + ('1GR','Greenhouse'), + ('1NU','Nursery'), + ('1RE','Retail'), + ('2WI','Greenhouse'), + ('3BM','Other'), + ('3CO','Other'), + ('3PE','Other'), + ('3PP','Other'), + ('4CO','Other'), + ('4RA','Other'), + ('9MI','Other'), + ('9SA','Other'), + ('9TO','Other') + ) x(glec, segm) +) +,log AS ( + INSERT INTO rlarp.osm_log(doc) SELECT $$replace_iterdef$$::jsonb doc RETURNING * +) +,remove 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 units + ,-value_loc value_loc + ,-value_usd value_usd + ,-cost_loc cost_loc + ,-cost_usd 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 + rlarp.osm_pool o + CROSS JOIN log + INNER JOIN pl ON + pl.original = o.part + WHERE + -----------------scenario---------------------------- + where_clause +) +,repl AS ( + SELECT + o.fspr + ,o.dplt plnt ---master data + ,o.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 + ,o.part + ,o.partd + ,o.part_group + ,o.branding + ,o.majg_descr + ,o.ming_descr + ,o.majs_descr + ,o.mins_descr + ,seg.segm + ,o.substance + ,o.fs_line --master data + ,o.r_currency --history cust mix + ,o.r_rate --master data + ,o.r.curr c_currency --master data + ,o.x.rate c_rate --master data + ,-o.units units + ,-o.value_loc value_loc + ,-o.value_usd value_usd + ,-o.units * c.std cost_loc + ,-o.units * c.std * x.rate cost_usd + ,o.calc_status --0 + ,o.flag --0 + ,o.order_date --history date mix + ,o.order_month + ,o.order_season + ,o.request_date --history date mix + ,o.request_month + ,o.request_season + ,o.ship_date --history date mix + ,o.ship_month + ,o.ship_season + ,o."version" + ,o.iter + ,o.id + ,o."tag" + ,o."comment" + ,o.module + FROM + remove o + LEFT OUTER JOIN bill ON + bill.billto = rtrim(substring(o.bill_cust_desrc,1,8)) + LEFT OUTER JOIN ship ON + ship.shipto = rtrim(substring(o.ship_cust_desrc,1,8)) + +) +,ins AS ( + INSERT INTO rlarp.osm_pool SELECT * FROM remove UNION ALL SELECT * FROM repl 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 + From 37eb9d519f024adda655eb14a05cef6a35b35aef Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Fri, 20 Mar 2020 15:35:03 -0400 Subject: [PATCH 10/19] update customer swap --- build/snap_cust_pool.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/build/snap_cust_pool.sql b/build/snap_cust_pool.sql index df91ed4..7039fa3 100644 --- a/build/snap_cust_pool.sql +++ b/build/snap_cust_pool.sql @@ -82,7 +82,7 @@ WHERE b.bvcust = rtrim(substring(o.bill_cust_descr,1,8)) AND s.bvcust = rtrim(substring(o.ship_cust_descr,1,8)); -BEGIN; +--BEGIN; UPDATE rlarp.osm_pool o @@ -98,4 +98,4 @@ WHERE AND q.qr = LTRIM(RTRIM(c.a9)); -ROLLBACK; \ No newline at end of file +COMMIT; \ No newline at end of file From e3205a94c1e1d13027320eed989f749d4cb913ef Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Thu, 2 Apr 2020 09:55:53 -0400 Subject: [PATCH 11/19] setup history listing to be based on a where clause to allow for director level --- index.js | 11 ++++++++++- route_sql/list_changes.sql | 2 +- 2 files changed, 11 insertions(+), 2 deletions(-) diff --git a/index.js b/index.js index c4636e3..b8e7ae0 100644 --- a/index.js +++ b/index.js @@ -238,10 +238,19 @@ server.get('/list_changes', bodyParser.json(), function(req, res) { var callback = function(arg) { sql = arg; + //parse request body into a where clause + ({ c, w, d } = build_where(req, c, w, d, args)); + + + //if there was no body sent, return with nothing + if (c == 1) { + res.send("no body was sent"); + return; + } console.log(new Date().toISOString() + "-------------------------list changes:------------------------------") console.log(req.body); //parse the where clause into the main sql statement - sql = sql.replace(new RegExp("replace_user", 'g'), req.body.quota_rep_descr) + sql = sql.replace(new RegExp("where_clause", 'g'), w) //execute the sql and send the result console.log(sql); Postgres.FirstRow(sql, [], res) diff --git a/route_sql/list_changes.sql b/route_sql/list_changes.sql index b00a269..a8f4589 100644 --- a/route_sql/list_changes.sql +++ b/route_sql/list_changes.sql @@ -14,7 +14,7 @@ from inner join rlarp.osm_pool on id = logid WHERE - quota_rep_descr = 'replace_user' + where_clause AND tag <> 'Initial Build' group BY ol.doc->>'user' From 834d52a2a2a7a8abd3454f857575c7f2cbae0813 Mon Sep 17 00:00:00 2001 From: pt Date: Tue, 12 May 2020 16:55:37 -0400 Subject: [PATCH 12/19] customer swap route will do nothing --- index.js | 44 +++++++++++++++++++++++++++++++++++++++++ route_sql/swap_cust.sql | 11 ++++++----- 2 files changed, 50 insertions(+), 5 deletions(-) diff --git a/index.js b/index.js index b8e7ae0..0f547a2 100644 --- a/index.js +++ b/index.js @@ -217,6 +217,50 @@ server.post('/swap', bodyParser.json(), function(req, res) { }; }) +server.post('/cust_swap', bodyParser.json(), function(req, res) { + + var sql = ""; + var w = ""; + var c = 1; + var d = 1; + var args = []; + var path = './route_sql/swap_cust.sql'; + + fs.readFile(path, 'utf8', function(err, data) { + if (!err) { + callback(data); + } else { + console.log("fatal error pulling sql file") + callback(err); + } + }); + + var callback = function(arg) { + sql = arg; + + //parse request body into a where clause + ({ c, w, d } = build_where(req, c, w, d, args)); + + //if there was no body sent, return with nothing + if (c == 1) { + res.send("no body was sent"); + return; + } + console.log(new Date().toISOString() + "-------------------------get swap fit:------------------------------") + console.log(req.body); + //parse the where clause into the main sql statement + sql = sql.replace(new RegExp("where_clause", 'g'), w); + sql = sql.replace(new RegExp("swap_doc", 'g'), JSON.stringify(req.body.swap)); + sql = sql.replace(new RegExp("replace_version", 'g'), req.body.scenario.version); + sql = sql.replace(new RegExp("replace_source", 'g'), req.body.source); + sql = sql.replace(new RegExp("replace_iterdef", 'g'), JSON.stringify(req.body)); + //execute the sql and send the result + console.log(sql); + res.json(null); + //Postgres.FirstRow(sql, [], res) + }; +}) + server.get('/list_changes', bodyParser.json(), function(req, res) { var sql = ""; diff --git a/route_sql/swap_cust.sql b/route_sql/swap_cust.sql index 46a66ab..8e1691a 100644 --- a/route_sql/swap_cust.sql +++ b/route_sql/swap_cust.sql @@ -17,17 +17,17 @@ target AS (SELECT $$swap_doc$$::jsonb swap) SELECT billto ,bill_r - ,bill_dba + ,bc.bvadr6 bill_dba ,shipto ,ship_r - ,ship_dba + ,sc.bvadr6 ship_dba --other stuff doesn't matter becuase it's getting overridden anyways FROM swap LEFT out JOIN lgdat.cust bc ON bc.bvcust = swap.bill_r LEFT out JOIN lgdat.cust sc ON - bc.bvcust = swap.ship_r + sc.bvcust = swap.ship_r ) --put bill to and ship to back together and join in channel, terms, descriptions, etc ,seg AS ( @@ -112,8 +112,9 @@ target AS (SELECT $$swap_doc$$::jsonb swap) FROM rlarp.osm_pool o CROSS JOIN log - INNER JOIN pl ON - pl.original = o.part + INNER JOIN swap ON + swap.bill_to = SUBSTRING(o.bill_cust_descr,1,8) + swap.bill_to = SUBSTRING(o.ship_cust_descr,1,8) WHERE -----------------scenario---------------------------- where_clause From 652720ff32e26ed8b6d7f65e66c73aa70f202878 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Tue, 2 Jun 2020 12:36:29 -0400 Subject: [PATCH 13/19] add destination --- build/build_pool.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/build/build_pool.sql b/build/build_pool.sql index a5f0e3a..c0afebc 100644 --- a/build/build_pool.sql +++ b/build/build_pool.sql @@ -60,6 +60,7 @@ SELECT ,terms ,bill_cust||' - '||bc.bvname bill_cust_descr ,ship_cust||' - '||sc.bvname ship_cust_descr + ,dest_ctry||' - '||dest_prov ship_location ,dsm ,coalesce(repc.repp,dsm) quota_rep_descr ,repc.director From 07f36612d52b8f84d0ac430a565df6a4eed0def4 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 7 Apr 2021 10:20:33 -0400 Subject: [PATCH 14/19] clean up missed conflict, matches dev --- build/snap_cust_pool.sql | 4 ---- 1 file changed, 4 deletions(-) diff --git a/build/snap_cust_pool.sql b/build/snap_cust_pool.sql index 8c3fd08..9a783a8 100644 --- a/build/snap_cust_pool.sql +++ b/build/snap_cust_pool.sql @@ -66,10 +66,6 @@ WHERE and c.a2 = 'MM' AND q.qr = LTRIM(RTRIM(c.a9)); -<<<<<<< HEAD - -COMMIT; -======= COMMIT; --ROLLBACK; >>>>>>> dev From 6e4e64b3a43781d49242032bb7de9daff3bfca45 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 7 Apr 2021 10:20:55 -0400 Subject: [PATCH 15/19] clean up missed conflict, matches dev --- build/snap_cust_pool.sql | 1 - 1 file changed, 1 deletion(-) diff --git a/build/snap_cust_pool.sql b/build/snap_cust_pool.sql index 9a783a8..dd6f565 100644 --- a/build/snap_cust_pool.sql +++ b/build/snap_cust_pool.sql @@ -68,4 +68,3 @@ WHERE COMMIT; --ROLLBACK; ->>>>>>> dev From 28ee5dfbb4b5633d04178b51cde3434db62e62fb Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 7 Apr 2021 12:55:35 -0400 Subject: [PATCH 16/19] update history pull to match dev branch --- index.js | 9 --------- route_sql/list_changes.sql | 2 +- 2 files changed, 1 insertion(+), 10 deletions(-) diff --git a/index.js b/index.js index bdea9e1..dc2de2f 100644 --- a/index.js +++ b/index.js @@ -282,15 +282,6 @@ server.get('/list_changes', bodyParser.json(), function(req, res) { var callback = function(arg) { sql = arg; - //parse request body into a where clause - ({ c, w, d } = build_where(req, c, w, d, args)); - - - //if there was no body sent, return with nothing - if (c == 1) { - res.send("no body was sent"); - return; - } console.log(new Date().toISOString() + "-------------------------list changes:------------------------------") console.log(req.body); //parse the where clause into the main sql statement diff --git a/route_sql/list_changes.sql b/route_sql/list_changes.sql index a8f4589..b00a269 100644 --- a/route_sql/list_changes.sql +++ b/route_sql/list_changes.sql @@ -14,7 +14,7 @@ from inner join rlarp.osm_pool on id = logid WHERE - where_clause + quota_rep_descr = 'replace_user' AND tag <> 'Initial Build' group BY ol.doc->>'user' From b48743005791eb14c9c2fd4fb318d6e5a642d746 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 7 Apr 2021 12:56:31 -0400 Subject: [PATCH 17/19] forego adding in the ship-to province at this point --- build/build_pool.sql | 1 - 1 file changed, 1 deletion(-) diff --git a/build/build_pool.sql b/build/build_pool.sql index c0afebc..a5f0e3a 100644 --- a/build/build_pool.sql +++ b/build/build_pool.sql @@ -60,7 +60,6 @@ SELECT ,terms ,bill_cust||' - '||bc.bvname bill_cust_descr ,ship_cust||' - '||sc.bvname ship_cust_descr - ,dest_ctry||' - '||dest_prov ship_location ,dsm ,coalesce(repc.repp,dsm) quota_rep_descr ,repc.director From f7f26b28049dd2666833be569c7775b374a81e56 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 7 Apr 2021 20:23:12 +0000 Subject: [PATCH 18/19] finish work on customer swap, start testing this --- route_sql/swap_cust.sql | 23 +++++++++++------------ 1 file changed, 11 insertions(+), 12 deletions(-) diff --git a/route_sql/swap_cust.sql b/route_sql/swap_cust.sql index 8e1691a..69b6c16 100644 --- a/route_sql/swap_cust.sql +++ b/route_sql/swap_cust.sql @@ -112,9 +112,9 @@ target AS (SELECT $$swap_doc$$::jsonb swap) FROM rlarp.osm_pool o CROSS JOIN log - INNER JOIN swap ON - swap.bill_to = SUBSTRING(o.bill_cust_descr,1,8) - swap.bill_to = SUBSTRING(o.ship_cust_descr,1,8) + INNER JOIN cust c ON + c.billto = SUBSTRING(o.bill_cust_descr,1,8) + AND c.shipto = SUBSTRING(o.ship_cust_descr,1,8) WHERE -----------------scenario---------------------------- where_clause @@ -125,13 +125,13 @@ target AS (SELECT $$swap_doc$$::jsonb swap) ,o.dplt plnt ---master data ,o.promo --history date mix ,terms - ,bill_cust_descr --history cust mix - ,ship_cust_descr --history cust mix + ,COALESCE(c.bill_r||' - '||c.bill_dba,bill_cust_descr) bill_cust_descr + ,COALESCE(c.ship_r||' - '||c.ship_dba,ship_cust_descr) ship_cust_descr ,dsm ,quota_rep_descr --master data ,director - ,billto_group --master data - ,shipto_group + ,COALESCE(c.bill_dba,billto_group) billto_group + ,COALESCE(c.ship_dba,shipto_group) shipto_group ,chan --master data ,chansub ,chan_retail @@ -174,12 +174,11 @@ target AS (SELECT $$swap_doc$$::jsonb swap) ,o.module FROM remove o - LEFT OUTER JOIN bill ON - bill.billto = rtrim(substring(o.bill_cust_desrc,1,8)) - LEFT OUTER JOIN ship ON - ship.shipto = rtrim(substring(o.ship_cust_desrc,1,8)) - + INNER JOIN cust c ON + c.billto = SUBSTRING(o.bill_cust_descr,1,8) + AND c.shipto = SUBSTRING(o.ship_cust_descr,1,8) ) +--select bill_cust_descr, ship_cust_descr, sum(value_usd) from (SELECT * FROM remove UNION ALL SELECT * FROM repl) x group by bill_cust_descr, ship_cust_descr ,ins AS ( INSERT INTO rlarp.osm_pool SELECT * FROM remove UNION ALL SELECT * FROM repl RETURNING * ) From a328aaeaaf868001c63f0fae34abeabcdcaf7815 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 7 Apr 2021 21:23:19 +0000 Subject: [PATCH 19/19] running the SQL was commented out in the router, also the columns were incorrect when swapping customer, and outer join was spelled wrong --- index.js | 4 ++-- route_sql/swap_cust.sql | 50 ++++++++++++++++++++--------------------- 2 files changed, 27 insertions(+), 27 deletions(-) diff --git a/index.js b/index.js index dc2de2f..b8e775b 100644 --- a/index.js +++ b/index.js @@ -256,8 +256,8 @@ server.post('/cust_swap', bodyParser.json(), function(req, res) { sql = sql.replace(new RegExp("replace_iterdef", 'g'), JSON.stringify(req.body)); //execute the sql and send the result console.log(sql); - res.json(null); - //Postgres.FirstRow(sql, [], res) + //res.json(null); + Postgres.FirstRow(sql, [], res) }; }) diff --git a/route_sql/swap_cust.sql b/route_sql/swap_cust.sql index 69b6c16..863c37e 100644 --- a/route_sql/swap_cust.sql +++ b/route_sql/swap_cust.sql @@ -24,9 +24,9 @@ target AS (SELECT $$swap_doc$$::jsonb swap) --other stuff doesn't matter becuase it's getting overridden anyways FROM swap - LEFT out JOIN lgdat.cust bc ON + LEFT OUTER JOIN lgdat.cust bc ON bc.bvcust = swap.bill_r - LEFT out JOIN lgdat.cust sc ON + LEFT OUTER JOIN lgdat.cust sc ON sc.bvcust = swap.ship_r ) --put bill to and ship to back together and join in channel, terms, descriptions, etc @@ -121,42 +121,42 @@ target AS (SELECT $$swap_doc$$::jsonb swap) ) ,repl AS ( SELECT - o.fspr - ,o.dplt plnt ---master data + o.fspr + ,o.plnt ---master data ,o.promo --history date mix - ,terms - ,COALESCE(c.bill_r||' - '||c.bill_dba,bill_cust_descr) bill_cust_descr - ,COALESCE(c.ship_r||' - '||c.ship_dba,ship_cust_descr) ship_cust_descr - ,dsm - ,quota_rep_descr --master data - ,director - ,COALESCE(c.bill_dba,billto_group) billto_group - ,COALESCE(c.ship_dba,shipto_group) shipto_group - ,chan --master data - ,chansub - ,chan_retail + ,o.terms + ,COALESCE(c.bill_r||' - '||c.bill_dba,o.bill_cust_descr) bill_cust_descr + ,COALESCE(c.ship_r||' - '||c.ship_dba,o.ship_cust_descr) ship_cust_descr + ,o.dsm + ,o.quota_rep_descr --master data + ,o.director + ,COALESCE(c.bill_dba,o.billto_group) billto_group + ,COALESCE(c.ship_dba,o.shipto_group) shipto_group + ,o.chan --master data + ,o.chansub + ,o.chan_retail ,o.part - ,o.partd + ,o.part_descr ,o.part_group ,o.branding ,o.majg_descr ,o.ming_descr ,o.majs_descr ,o.mins_descr - ,seg.segm + ,o.segm ,o.substance - ,o.fs_line --master data + ,o.fs_line --master data ,o.r_currency --history cust mix - ,o.r_rate --master data - ,o.r.curr c_currency --master data - ,o.x.rate c_rate --master data + ,o.r_rate --master data + ,o.c_currency --master data + ,o.c_rate --master data ,-o.units units ,-o.value_loc value_loc ,-o.value_usd value_usd - ,-o.units * c.std cost_loc - ,-o.units * c.std * x.rate cost_usd - ,o.calc_status --0 - ,o.flag --0 + ,-o.cost_loc cost_loc + ,-o.cost_usd cost_usd + ,o.calc_status --0 + ,o.flag --0 ,o.order_date --history date mix ,o.order_month ,o.order_season