diff --git a/.gitignore b/.gitignore index dbf4932..ddde6eb 100644 --- a/.gitignore +++ b/.gitignore @@ -8,3 +8,5 @@ stat.html changes.html *.pem *.log +/.dbeaver +.project diff --git a/Master Template 1.6.xlsm b/Master Template 1.6.xlsm index 3b1ec78..4e53215 100644 Binary files a/Master Template 1.6.xlsm and b/Master Template 1.6.xlsm differ diff --git a/build/build_forecast.sql b/build/build_forecast.sql index 8c5cbb6..7013588 100644 --- a/build/build_forecast.sql +++ b/build/build_forecast.sql @@ -145,9 +145,9 @@ gld AS ( WHERE ( --base period orders booked.... - o.odate BETWEEN '2020-06-01' AND '2021-04-04' + o.odate BETWEEN '2020-06-01' AND '2021-04-11' --...or any open orders currently booked before cutoff.... - OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < '2021-04-04') + OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < '2021-04-11') --...or anything that shipped in that period OR o.fspr BETWEEN '2101' AND '2110' ) @@ -294,7 +294,7 @@ gld AS ( LEFT OUTER JOIN gld ss ON greatest(least(o.sdate,gld.edat),gld.sdat) + interval '1 year' BETWEEN ss.sdat AND ss.edat WHERE - o.odate BETWEEN '2020-04-05' AND '2020-05-31' + o.odate BETWEEN '2020-04-12' AND '2020-05-31' AND fs_line = '41010' AND calc_status <> 'CANCELED' ------exclude actuals for now and use forecast to get the plug for the rest of the year diff --git a/build/build_pool.sql b/build/build_pool.sql index a5f0e3a..690f21b 100644 --- a/build/build_pool.sql +++ b/build/build_pool.sql @@ -26,7 +26,8 @@ repc AS ( FROM ( VALUES - ('1CU','Retail'), + ('1CU','Sustainable'), + ('1SU','Sustainable'), ('1GR','Greenhouse'), ('1NU','Nursery'), ('1RE','Retail'), @@ -68,14 +69,46 @@ SELECT ,chan ,chansub ,CASE seg.segm + --for 1RE coded product WHEN 'Retail' THEN CASE o.bill_class - WHEN 'RMAS' THEN 'MASS' - WHEN 'RNAT' THEN 'NATIONAL' - ELSE 'OTHER' + WHEN 'RONL' THEN 'Online' + WHEN 'RNAT' THEN 'National' + WHEN 'RMAS' THEN 'National' + ELSE + ------ ship-to class --------------------- + CASE o.chan + WHEN 'GDIS' THEN 'Distribution' + WHEN 'NDIS' THEN 'Distribution' + WHEN 'RDIS' THEN 'Distribution' + WHEN 'GDRP' THEN 'Grower' + WHEN 'NDRP' THEN 'Grower' + WHEN 'RDRP' THEN 'Distribution' + WHEN 'GDIR' THEN 'Grower' + WHEN 'NDIR' THEN 'Grower' + -------this will probably need reviewed-------- + WHEN 'RDIR' THEN 'Distribution' + WHEN 'NDIR' THEN 'Grower' + WHEN 'GDIR' THEN 'Grower' + ELSE 'Distribution' + END + END + --for 1SU 1CU coded product + WHEN 'Sustainable' THEN + CASE SUBSTRING(o.coltier,1,1) + --anything with a bio color tier is bio on the channel + WHEN 'R' THEN 'Bio' + ELSE + CASE o.glec + --any 1SU that is not bio is fiber + WHEN '1SU' THEN 'Fiber' + --any 1CU that is not bio is commercial + WHEN '1CU' THEN 'Commercial' + ELSE o.chan + END END ELSE o.chan - END chan_retail + END chan_retail ,part ,part||coalesce(' - '||i.descr,'') part_descr ,stlcd part_group @@ -147,4 +180,4 @@ CREATE INDEX osm_pool_logid ON rlarp.osm_pool(logid); GRANT ALL ON TABLE rlarp.osm_log TO api; GRANT ALL ON TABLE rlarp.osm_pool TO api; -COMMIT; \ No newline at end of file +COMMIT; diff --git a/build/convert_pool_all.sql b/build/convert_pool_all.sql index ebb0034..95df7af 100644 --- a/build/convert_pool_all.sql +++ b/build/convert_pool_all.sql @@ -1,4 +1,7 @@ -BEGIN; +CREATE OR REPLACE PROCEDURE rlarp.convert_pool_all() +LANGUAGE plpgsql AS +$func$ +BEGIN DELETE FROM rlarp.osmfs_dev; @@ -111,6 +114,35 @@ SELECT FROM rlarp.osm_pool; +-------need to set item master values before other things----------- +UPDATE + RLARP.OSMFS_DEV O +SET + COLC = M.COLC + ,COLGRP = M.COLGRP + ,COLTIER = M.COLTIER + ,COLSTAT = M.COLSTAT + ,SIZC = M.SIZC + ,PCKG = M.PACKAGE + ,KIT = M.KIT + ,BRND = M.BRANDING + ,MAJG = M.MAJG + ,MING = M.MING + ,MAJS = M.MAJS + ,MINS = M.MINS + ,GLDC = M.GLCD + ,GLEC = M.GLEC + ,HARM = M.HARM + ,CLSS = M.CLSS + ,BRAND = M.BRAND + ,ASSC = M.ASSC + ,LBS = CASE M.NWUN WHEN 'KG' THEN 2.2046 ELSE 1 END*M.NWHT + ,UNTI = M.UNTI +FROM + RLARP.ITEMM M +WHERE + M.ITEM = O.PART; + WITH plist AS ( @@ -137,8 +169,6 @@ plist AS ( ir.y0part = p.part AND ir.y0plnt = p.plnt ) - - UPDATE rlarp.osmfs_dev o SET @@ -365,64 +395,41 @@ WHERE f.sdate BETWEEN gld.sdat AND gld.edat AND coalesce(f.fspr,'') <> gld.fspr; -UPDATE - rlarp.osmfS_dev -SET - r_rate = .7900 -WHERE - r_currency = 'CA'; - -UPDATE - rlarp.osmfS_dev -SET - r_rate = 1 -WHERE - r_currency = 'US'; - -UPDATE - rlarp.osmfS_dev -SET - c_rate = .7900 -WHERE - c_currency = 'CA'; - -UPDATE - rlarp.osmfS_dev -SET - c_rate = 1 -WHERE - c_currency = 'US'; - -UPDATE - RLARP.OSMFS_DEV O -SET - COLC = M.COLC - ,COLGRP = M.COLGRP - ,COLTIER = M.COLTIER - ,COLSTAT = M.COLSTAT - ,SIZC = M.SIZC - ,PCKG = M.PACKAGE - ,KIT = M.KIT - ,BRND = M.BRANDING - ,MAJG = M.MAJG - ,MING = M.MING - ,MAJS = M.MAJS - ,MINS = M.MINS - ,GLDC = M.GLCD - ,GLEC = M.GLEC - ,HARM = M.HARM - ,CLSS = M.CLSS - ,BRAND = M.BRAND - ,ASSC = M.ASSC - ,LBS = CASE M.NWUN WHEN 'KG' THEN 2.2046 ELSE 1 END*M.NWHT - ,UNTI = M.UNTI -FROM - RLARP.ITEMM M -WHERE - M.ITEM = O.PART; +--avoid setting fx as that should have been done up front to osmf +--UPDATE +-- rlarp.osmfS_dev +--SET +-- r_rate = .7900 +--WHERE +-- r_currency = 'CA'; +-- +--UPDATE +-- rlarp.osmfS_dev +--SET +-- r_rate = 1 +--WHERE +-- r_currency = 'US'; +-- +--UPDATE +-- rlarp.osmfS_dev +--SET +-- c_rate = .7900 +--WHERE +-- c_currency = 'CA'; +-- +--UPDATE +-- rlarp.osmfS_dev +--SET +-- c_rate = 1 +--WHERE +-- c_currency = 'US'; --DELETE FROM rlarp.osmf_dev WHERE iter IN ('adj price','adj volume'); --INSERT INTO rlarp.osmf_dev SELECT * FROM rlarp.osmfs_dev; COMMIT; +END +$func$; + +GRANT ALL ON PROCEDURE rlarp.convert_pool_all() TO PUBLIC; diff --git a/build/readme.md b/build/readme.md new file mode 100644 index 0000000..9a4193d --- /dev/null +++ b/build/readme.md @@ -0,0 +1,13 @@ +Build A New Forecast +------------------------------------------------------------------------------------------------------------------ + +* overwrite osmf: review dates and execute build_forecase.sql +* the product and customer attributes are wiped, they will need to be snapped (itemm must come first) + 1. snap_itemm.sql + 2. snap_customer.sql + 3. snap_cost_current.sql + 4. snap_fx.sql (if necessary) + 5. offline/last_price.sql (if necessary) +* build the pool for the more limited UI data set: build_pool.sql +* copy the pool to osmfs_dev from inclusion in the osm_stack and reporting: convert_pool_all.sql +* refresh osm_stack_refresh() to integrate into reporting diff --git a/build/rebuild_forecast.sh b/build/rebuild_forecast.sh index 0cdb827..16fbcd7 100644 --- a/build/rebuild_forecast.sh +++ b/build/rebuild_forecast.sh @@ -1,6 +1,8 @@ -psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/build_forecast.sql -psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/snap_cost_current.sql -psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/fx.sql -psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/customer.sql -psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/snap_itemm.sql -psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/build_pool.sql \ No newline at end of file +$PG -f build_forecast.sql +$PG -f snap_itemm.sql +$PG -f snap_cost_current.sql +$PG -f snap_customer.sql +$PG -f snap_fx.sql +$PG -f build_pool.sql +$PG -f convert_pool_all.sql +$PG -c "CALL rlarp.osm_stack_refresh();" diff --git a/build/snap_customer.sql b/build/snap_customer.sql index 01937c2..55c1eaf 100644 --- a/build/snap_customer.sql +++ b/build/snap_customer.sql @@ -144,66 +144,37 @@ FROM SELECT DISTINCT VERSION, COALESCE(GLEC,'') GLEC, - COALESCE(MING,'') MING, + MING, BILL_CUST, SHIP_CUST, ------------quota rep column-------------- - RTRIM( - --retail items go to currep, or if null go to 90005 - CASE WHEN S.GLEC IN ('1RE','1CU') THEN - CASE WHEN BVCTRY = 'CAN' THEN - --Rachel Bowman - '50300' - ELSE - --select customers go to select reps - CASE ACCOUNT - ------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 + CASE WHEN COALESCE(ming,'') = 'B52' THEN 'PW' ELSE + --if the gl expense code is 1RE use the retail rep assigned to the bill-to customer if available + CASE WHEN COALESCE(glec,'') = '1RE' AND COALESCE(cu.currep,'') <> '' THEN + cu.currep + --default logic ELSE - CASE WHEN MING = 'B52' THEN - 'PW' - --gdir, ndir go to bill-to rep - ELSE - CASE WHEN BILL_CLASS IN ('GDIR','NDIR') THEN - BILL_REP + CASE SUBSTR(bill_class,2,3) + WHEN 'DIS' THEN + ship_rep ELSE - SHIP_REP - END + bill_rep END END - ) QUOTA_REP + END QUOTA_REP FROM RLARP.OSMF_DEV S LEFT OUTER JOIN LGDAT.CUST ON - BVCUST = BILL_CUST + BVCUST = BILL_CUST + LEFT OUTER JOIN lgpgm.usrcust cu ON + cu.cucust = s.bill_cust WHERE - COALESCE(GLEC,'') IS NOT NULL + version = 'ACTUALS' ) CR WHERE CR.VERSION = S.VERSION AND CR.GLEC = COALESCE(S.GLEC,'') - AND CR.MING = COALESCE(S.MING,'') + AND CR.MING = S.MING AND CR.BILL_CUST = S.BILL_CUST AND CR.SHIP_CUST = S.SHIP_CUST - AND COALESCE(S.DSM,'') <> CR.QUOTA_REP; \ No newline at end of file + AND COALESCE(S.DSM,'') <> CR.QUOTA_REP; diff --git a/build/snap_fx.sql b/build/snap_fx.sql index 098385c..acd0c28 100644 --- a/build/snap_fx.sql +++ b/build/snap_fx.sql @@ -1,9 +1,10 @@ ------------update fx rates----------------------------------------------------------------- -UPDATE rlarp.osmf_dev SET r_rate = .7900 WHERE r_currency = 'CA' AND version = 'b22'; -UPDATE rlarp.osmf_dev SET r_rate = 1.0000 WHERE r_currency = 'US' AND version = 'b22'; -UPDATE rlarp.osmf_dev SET c_rate = .7900 WHERE c_currency = 'CA' AND version = 'b22'; -UPDATE rlarp.osmf_dev SET c_rate = 1.0000 WHERE c_currency = 'US' AND version = 'b22'; -UPDATE rlarp.osm_pool SET r_rate = .7900 WHERE r_currency = 'CA' AND version = 'b22'; -UPDATE rlarp.osm_pool SET value_usd = value_loc * r_rate WHERE r_currency = 'CA' AND version = 'b22'; -UPDATE rlarp.osm_pool SET c_rate = .7900 WHERE c_currency = 'CA' AND version = 'b22'; -UPDATE rlarp.osm_pool SET cost_usd = cost_loc * c_rate WHERE c_currency = 'CA' AND version = 'b22'; +---only apply fx to forecast orders---- +UPDATE rlarp.osmf_dev SET r_rate = .7900 WHERE r_currency = 'CA' AND odate >= '2021-04-08'; +UPDATE rlarp.osmf_dev SET r_rate = 1.0000 WHERE r_currency = 'US' AND odate >= '2021-04-08'; +UPDATE rlarp.osmf_dev SET c_rate = .7900 WHERE c_currency = 'CA' AND odate >= '2021-04-08'; +UPDATE rlarp.osmf_dev SET c_rate = 1.0000 WHERE c_currency = 'US' AND odate >= '2021-04-08'; +--UPDATE rlarp.osm_pool SET r_rate = .7900 WHERE r_currency = 'CA' AND version = 'b22'; +--UPDATE rlarp.osm_pool SET value_usd = value_loc * r_rate WHERE r_currency = 'CA' AND version = 'b22'; +--UPDATE rlarp.osm_pool SET c_rate = .7900 WHERE c_currency = 'CA' AND version = 'b22'; +--UPDATE rlarp.osm_pool SET cost_usd = cost_loc * c_rate WHERE c_currency = 'CA' AND version = 'b22'; diff --git a/index.js b/index.js index 1791024..b8e775b 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 = ""; @@ -242,7 +286,7 @@ server.get('/list_changes', bodyParser.json(), function(req, res) { console.log(req.body); //parse the where clause into the main sql statement sql = sql.replace(new RegExp("replace_user", 'g'), req.body.scenario.quota_rep_descr) - //execute the sql and send the result + //execute the sql and send the result console.log(sql); Postgres.FirstRow(sql, [], res) }; diff --git a/offline/last_price.sql b/offline/last_price.sql index f45db7f..305530d 100644 --- a/offline/last_price.sql +++ b/offline/last_price.sql @@ -1,5 +1,7 @@ ---BEGIN; +BEGIN; + WITH +------------------goal price increases--------------------- incr AS ( SELECT * FROM (VALUES ('110','PP','B',0.25), @@ -66,15 +68,17 @@ incr AS ( ('610','','W',0.02) ) x(MAJG,ASSC,COLTIER,RATE) ) +------------carve out pricing baseline data-------------------- ,p AS ( SELECT o.part - ,o.styc||'.'||o.colgrp||substring(o.sizc,2,3) product + ,o.styc||'.'||o.colgrp||substring(o.sizc,1,3) product ,o.glec ,o.styc ,o.majg ,i.assc ,o.coltier + ,o.colgrp ,o.sizc ,i.suffix ,substring(o.chan,1,1) chgrp @@ -85,7 +89,7 @@ incr AS ( ,round(o.fb_val_loc/o.fb_qty,10) AS price ,o.odate ,o.oseas - ,row_number() OVER (PARTITION BY o.part,o.bill_cust, o.ship_cust ORDER BY o.odate DESC) rn + ,row_number() OVER (PARTITION BY o.styc||'.'||o.colgrp||substring(o.sizc,1,3),o.account, o.shipgrp ORDER BY o.odate DESC) rn FROM rlarp.osm_dev o INNER JOIN rlarp.itemmv i ON @@ -111,6 +115,8 @@ incr AS ( AND o.bill_class <> 'SALE' ---only use recent history AND o.oseas >= 2020 + ---only for direct and drop + --AND o.chan IN ('DIR','DRP') ORDER BY o.part ,o.styc @@ -121,6 +127,8 @@ incr AS ( ,o.shipgrp ,o.odate DESC ) +--SELECT * FROM p WHERE account ~ 'ACOSTA' +------------build global py asp------------------ ,baseline AS ( SELECT product @@ -136,6 +144,7 @@ incr AS ( ,assc ,chgrp ) +----------pivot the pricing out into columns per customer/product-------- ,pivot AS ( SELECT p.product @@ -143,9 +152,11 @@ SELECT ,p.glec ,p.majg ,p.assc + ,p.colgrp ,p.coltier ,p.sizc ,p.suffix + ,p.chgrp ,p.account ,p.shipgrp ,bl.py_gasp @@ -153,7 +164,17 @@ SELECT ,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_asp ,round(avg(price) FILTER (WHERE rn = 1),5) last_price ,max(odate) FILTER (WHERE rn = 1) last_order - ,i.rate + ,CASE p.chgrp + WHEN 'D' THEN i.rate + ELSE CASE p.majg + WHEN '610' THEN .02 + ElSE CASE p.colgrp + WHEN 'B' THEN .1 + WHEN 'C' THEN .15 + ELSE 1 + END + END + END rate ,CASE WHEN sum(val_usd) FILTER (WHERE oseas = 2020) IS NULL THEN CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL THEN 'unknown' @@ -184,13 +205,16 @@ GROUP BY ,p.majg ,p.assc ,p.coltier + ,p.colgrp ,p.sizc ,p.suffix + ,p.chgrp ,p.account ,p.shipgrp ,bl.py_gasp ,i.rate ) +----------------create the new price----------------- ,adj AS ( SELECT p.product @@ -220,17 +244,20 @@ SELECT FROM pivot p ) +--SELECT * FROM adj LIMIT 10000 +--------------create a log entry-------------------- ,log AS ( - --INSERT INTO - -- rlarp.osm_log(doc) + INSERT INTO + rlarp.osm_log(doc) SELECT $${ "message":"application of last price and target increases to all forecast orders", "tag":"last price", "type":"build" }$$::jsonb doc - --RETURNING * + RETURNING * ) +-------------build the iteration rows---------------- ,ins AS ( SELECT o.fspr @@ -281,10 +308,11 @@ SELECT ,o.version ---this iteration has to be listed in the master template file in order to be effectively included--- ,'upload price' iter + ,log.id ,COALESCE(log.doc->>'tag','') "tag" ,log.doc->>'message' "comment" ,log.doc->>'type' module - ------------------------------------- + -----------debug columns--------- --,value_usd/units price --,a.py_gasp --,a.rate @@ -297,20 +325,28 @@ FROM ,log WHERE i.item = o.part - AND a.product = i.stlc||'.'||i.colgrp||substring(i.sizc,2,3) + AND a.product = i.stlc||'.'||i.colgrp||substring(i.sizc,1,3) AND a.account = o.billto_group AND a.shipgrp = o.shipto_group AND a.price_increment <> 0 AND o.units <> 0 ---only apply to 2022 orders---- AND o.order_date >= '2021-06-01' + --only include baseline stuff--- + AND iter IN ('actuals','copy','actuals_plug') ) -SELECT - order_season - ,sum(value_usd) val_usd -FROM - ins -GROUP BY - order_season; +-----------aggregate the impact------------ +--SELECT * FROM ins limit 10000 +--SELECT +-- order_season +-- ,sum(value_loc) val_loc +-- ,sum(value_usd) val_usd +--FROM +-- ins +--GROUP BY +-- order_season; +INSERT INTO + rlarp.osm_pool +SELECT * FROM ins; ---COMMIT; +COMMIT; diff --git a/route_sql/list_changes.sql b/route_sql/list_changes.sql index b00a269..8bd09d4 100644 --- a/route_sql/list_changes.sql +++ b/route_sql/list_changes.sql @@ -15,7 +15,7 @@ from id = logid WHERE quota_rep_descr = 'replace_user' - AND tag <> 'Initial Build' + AND tag NOT IN ('Initial Build','last price') group BY ol.doc->>'user' ,quota_rep_descr @@ -28,4 +28,4 @@ ORDER BY (ol.doc->>'stamp')::timestamptz desc ) SELECT - jsonb_agg(row_to_json(agg)::jsonb ORDER BY agg.stamp desc) x from agg \ No newline at end of file + jsonb_agg(row_to_json(agg)::jsonb ORDER BY agg.stamp desc) x from agg diff --git a/route_sql/swap_cust.sql b/route_sql/swap_cust.sql new file mode 100644 index 0000000..863c37e --- /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 + ,bc.bvadr6 bill_dba + ,shipto + ,ship_r + ,sc.bvadr6 ship_dba + --other stuff doesn't matter becuase it's getting overridden anyways + FROM + swap + LEFT OUTER JOIN lgdat.cust bc ON + bc.bvcust = swap.bill_r + 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 +,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 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 +) +,repl AS ( + SELECT + o.fspr + ,o.plnt ---master data + ,o.promo --history date mix + ,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.part_descr + ,o.part_group + ,o.branding + ,o.majg_descr + ,o.ming_descr + ,o.majs_descr + ,o.mins_descr + ,o.segm + ,o.substance + ,o.fs_line --master data + ,o.r_currency --history cust mix + ,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.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 + ,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 + 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 * +) +,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 +