update script to snap the whole pool to the

appropriate quota rep.
This commit is contained in:
Paul Trowbridge 2021-04-16 13:58:30 -04:00
commit 1f96081a41
2 changed files with 51 additions and 62 deletions

View File

@ -1,70 +1,59 @@
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; --forego setting other customer attributes as they are not stored in osm_pool anyways
UPDATE UPDATE
rlarp.osm_pool o RLARP.OSM_POOL S
SET SET
chan = CASE SUBSTRING(b.bvclas,2,3) DSM = CR.QUOTA_REP
--if the bill to class is ditsributor, then it's either warehouse or drop FROM
WHEN 'DIS' THEN (
--if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse SELECT DISTINCT
CASE SUBSTRING(s.bvclas,2,3) VERSION,
WHEN 'DIS' THEN 'WHS' COALESCE(SEGM,'') SEGM,
ELSE 'DRP' MING_DESCR,
END BILL_CUST_DESCR,
--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 SHIP_CUST_DESCR,
--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 =
------------quota rep column-------------- ------------quota rep column--------------
CASE WHEN COALESCE(substring(ming_descr,1,3),'') = 'B52' THEN 'PW' ELSE CASE WHEN COALESCE(SUBSTRING(ming_descr,1,3),'') = 'B52' THEN 'PW' ELSE
--if the gl expense code is 1RE use the retail rep assigned to the bill-to customer if available --if the gl expense code is 1RE use the retail rep assigned to the bill-to customer if available
CASE WHEN COALESCE(o.segm,'') = 'Retail' AND COALESCE((SELECT currep FROM lgpgm.usrcust where cucust = b.bvcust),'') <> '' CASE WHEN COALESCE(segm,'') = 'Retail' AND COALESCE(cu.currep,'') <> '' THEN
THEN cu.currep
(SELECT currep FROM lgpgm.usrcust where cucust = b.bvcust)
--default logic --default logic
ELSE ELSE
CASE SUBSTR(b.bvclas,2,3) CASE SUBSTR(bc.bvclas,2,3)
WHEN 'DIS' THEN s.bvsalm WHEN 'DIS' THEN
ELSE b.bvsalm sc.bvsalm
ELSE
bc.bvsalm
END END
END END
END, END QUOTA_REP
billto_group = CASE b.bvadr6 WHEN '' THEN b.bvname ELSE b.bvadr6 END, FROM
shipto_group = CASE s.bvadr6 WHEN '' THEN s.bvname ELSE s.bvadr6 END RLARP.OSM_POOL S
FROM LEFT OUTER JOIN LGDAT.CUST BC ON
lgdat.cust b, BC.BVCUST = (regexp_match(S.bill_cust_descr,'(.*) - .*'))[1]
lgdat.cust s LEFT OUTER JOIN LGDAT.CUST SC ON
SC.BVCUST = (regexp_match(S.ship_cust_descr,'(.*) - .*'))[1]
LEFT OUTER JOIN lgpgm.usrcust cu ON
cu.cucust = (regexp_match(S.bill_cust_descr,'(.*) - .*'))[1]
) CR
WHERE WHERE
b.bvcust = rtrim(substring(o.bill_cust_descr,1,8)) CR.VERSION = S.VERSION
AND s.bvcust = rtrim(substring(o.ship_cust_descr,1,8)); AND CR.SEGM = COALESCE(S.SEGM,'')
--BEGIN; AND CR.MING_DESCR = S.MING_DESCR
AND CR.BILL_CUST_DESCR = S.BILL_CUST_DESCR
AND CR.SHIP_CUST_DESCR = S.SHIP_CUST_DESCR
AND COALESCE(S.DSM,'') <> CR.QUOTA_REP;
UPDATE UPDATE
rlarp.osm_pool o rlarp.osm_pool o
SET SET
quota_rep_descr = c.a30 quota_rep_descr = (regexp_match(r.repp,'.* - (.*)$'))[1]
,director = COALESCE(Q.DIR,'Other')
FROM FROM
lgdat.code c rlarp.repc r
,rlarp.qrh q
WHERE WHERE
LTRIM(RTRIM(c.a9)) = o.dsm r.rcode = o.dsm
and c.a2 = 'MM' AND quota_rep_descr <> (regexp_match(r.repp,'.* - (.*)$'))[1];
AND q.qr = LTRIM(RTRIM(c.a9));
COMMIT; COMMIT;
--ROLLBACK;

View File

@ -135,7 +135,7 @@ target AS (SELECT $$swap_doc$$::jsonb swap)
,o.terms ,o.terms
,COALESCE(c.bill_r||' - '||c.bill_dba,o.bill_cust_descr) bill_cust_descr ,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 ,COALESCE(c.ship_r||' - '||c.ship_dba,o.ship_cust_descr) ship_cust_descr
,o.dsm ,r.rcode dsm
,(regexp_match(r.repp,'.* - (.*)$'))[1] quota_rep_descr ,(regexp_match(r.repp,'.* - (.*)$'))[1] quota_rep_descr
,r.director ,r.director
,COALESCE(c.bill_dba,o.billto_group) billto_group ,COALESCE(c.bill_dba,o.billto_group) billto_group