From 1c0e07502d20b32e27ff62ad82464f0824e150ff Mon Sep 17 00:00:00 2001 From: pt Date: Fri, 13 Mar 2020 14:48:26 +0000 Subject: [PATCH] swap (#45) --- build/snap_cust_pool.sql | 101 +++++++++++++ index.js | 83 +++++++++++ route_sql/scenario_package.sql | 13 ++ route_sql/swap_fit.sql | 77 ++++++++++ route_sql/swap_post.sql | 259 +++++++++++++++++++++++++++++++++ 5 files changed, 533 insertions(+) create mode 100644 build/snap_cust_pool.sql create mode 100644 route_sql/swap_fit.sql create mode 100644 route_sql/swap_post.sql diff --git a/build/snap_cust_pool.sql b/build/snap_cust_pool.sql new file mode 100644 index 0000000..df91ed4 --- /dev/null +++ b/build/snap_cust_pool.sql @@ -0,0 +1,101 @@ +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 +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)); + +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 diff --git a/index.js b/index.js index 65128c8..d1278b3 100644 --- a/index.js +++ b/index.js @@ -134,6 +134,89 @@ 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.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/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 diff --git a/route_sql/swap_fit.sql b/route_sql/swap_fit.sql new file mode 100644 index 0000000..a3bdc23 --- /dev/null +++ b/route_sql/swap_fit.sql @@ -0,0 +1,77 @@ +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 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 ( +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 diff --git a/route_sql/swap_post.sql b/route_sql/swap_post.sql new file mode 100644 index 0000000..13bdc43 --- /dev/null +++ b/route_sql/swap_post.sql @@ -0,0 +1,259 @@ +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 + WHERE + COALESCE(x.replace,'') <> '' +) +--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 + ,m.dplt 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.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 + ,r.curr c_currency --master data + ,x.rate c_rate --master data + ,-units units + ,-value_loc value_loc + ,-value_usd value_usd + ,-units * c.std cost_loc + ,-units * c.std * x.rate 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 = 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 +) +,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 +