diff --git a/route_sql/swap_cust.sql b/route_sql/swap_cust.sql index 56e2f65..4bbb2d7 100644 --- a/route_sql/swap_cust.sql +++ b/route_sql/swap_cust.sql @@ -14,20 +14,27 @@ target AS (SELECT $$swap_doc$$::jsonb swap) OR rtrim(substring(ship_r,1,8)) IS NOT null ) ,cust AS ( + ----------only return dba if being replaced------------------------------------------------- + ----------class and rep must always bew returned for both to determine new quota rep-------- SELECT billto ,bill_r - ,bc.bvadr6 bill_dba + ,CASE WHEN bill_r IS NULL THEN NULL::text ELSE bc.bvadr6 END bill_dba + ,bc.bvclas bill_class + ,bc.bvsalm bill_rep ,shipto ,ship_r - ,sc.bvadr6 ship_dba - --other stuff doesn't matter becuase it's getting overridden anyways + ,CASE WHEN ship_r IS NULL THEN NULL::text ELSE sc.bvadr6 END ship_dba + ,sc.bvclas ship_class + ,sc.bvsalm ship_rep FROM swap + ----default to the replacement customer but join to original otherwise since still neeed + ----customer info for revised quote rep LEFT OUTER JOIN lgdat.cust bc ON - bc.bvcust = swap.bill_r + bc.bvcust = COALESCE(swap.bill_r,billto) LEFT OUTER JOIN lgdat.cust sc ON - sc.bvcust = swap.ship_r + sc.bvcust = COALESCE(swap.ship_r,shipto) ) --put bill to and ship to back together and join in channel, terms, descriptions, etc ,seg AS ( @@ -129,8 +136,8 @@ target AS (SELECT $$swap_doc$$::jsonb swap) ,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 + ,(regexp_match(r.repp,'.* - (.*)$'))[1] quota_rep_descr + ,r.director ,COALESCE(c.bill_dba,o.billto_group) billto_group ,COALESCE(c.ship_dba,o.shipto_group) shipto_group ,o.chan --master data @@ -178,6 +185,20 @@ target AS (SELECT $$swap_doc$$::jsonb swap) INNER JOIN cust c ON c.billto = SUBSTRING(o.bill_cust_descr,1,8) AND c.shipto = SUBSTRING(o.ship_cust_descr,1,8) + LEFT OUTER JOIN rlarp.repc r ON + r.rcode = 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 + CASE WHEN COALESCE(o.segm,'') = 'Retail' AND COALESCE((SELECT currep FROM lgpgm.usrcust where cucust = c.bill_r),'') <> '' + THEN + (SELECT currep FROM lgpgm.usrcust where cucust = c.bill_r) + --default logic + ELSE + CASE SUBSTR(c.bill_class,2,3) + WHEN 'DIS' THEN c.ship_rep + ELSE c.bill_rep + END + END + END ) --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 (