update customer swap route to evaluate a new quota rep and channel based
on the revised customers
This commit is contained in:
commit
d3937fc406
@ -14,20 +14,27 @@ target AS (SELECT $$swap_doc$$::jsonb swap)
|
|||||||
OR rtrim(substring(ship_r,1,8)) IS NOT null
|
OR rtrim(substring(ship_r,1,8)) IS NOT null
|
||||||
)
|
)
|
||||||
,cust AS (
|
,cust AS (
|
||||||
|
----------only return dba if being replaced-------------------------------------------------
|
||||||
|
----------class and rep must always bew returned for both to determine new quota rep--------
|
||||||
SELECT
|
SELECT
|
||||||
billto
|
billto
|
||||||
,bill_r
|
,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
|
,shipto
|
||||||
,ship_r
|
,ship_r
|
||||||
,sc.bvadr6 ship_dba
|
,CASE WHEN ship_r IS NULL THEN NULL::text ELSE sc.bvadr6 END ship_dba
|
||||||
--other stuff doesn't matter becuase it's getting overridden anyways
|
,sc.bvclas ship_class
|
||||||
|
,sc.bvsalm ship_rep
|
||||||
FROM
|
FROM
|
||||||
swap
|
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
|
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
|
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
|
--put bill to and ship to back together and join in channel, terms, descriptions, etc
|
||||||
,seg AS (
|
,seg AS (
|
||||||
@ -129,12 +136,33 @@ target AS (SELECT $$swap_doc$$::jsonb swap)
|
|||||||
,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
|
,o.dsm
|
||||||
,o.quota_rep_descr --master data
|
,(regexp_match(r.repp,'.* - (.*)$'))[1] quota_rep_descr
|
||||||
,o.director
|
,r.director
|
||||||
,COALESCE(c.bill_dba,o.billto_group) billto_group
|
,COALESCE(c.bill_dba,o.billto_group) billto_group
|
||||||
,COALESCE(c.ship_dba,o.shipto_group) shipto_group
|
,COALESCE(c.ship_dba,o.shipto_group) shipto_group
|
||||||
,o.chan --master data
|
,CASE SUBSTRING(c.bill_class,2,3)
|
||||||
,o.chansub
|
--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(c.ship_class,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 chan
|
||||||
|
,CASE SUBSTRING(c.bill_class,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(c.ship_class,2,3)
|
||||||
|
WHEN 'DIS' THEN 'WHS'
|
||||||
|
ELSE CASE SUBSTRING(c.ship_class,1,1) WHEN 'R' THEN 'RDP' ELSE 'DRP' END
|
||||||
|
END
|
||||||
|
WHEN 'MAS' THEN 'RMN'
|
||||||
|
WHEN 'NAT' THEN 'RMN'
|
||||||
|
ELSE CASE SUBSTRING(c.ship_class,1,1) WHEN 'R' THEN 'RDI' ELSE 'DIR' END
|
||||||
|
END chansub
|
||||||
,o.chan_retail
|
,o.chan_retail
|
||||||
,o.part
|
,o.part
|
||||||
,o.part_descr
|
,o.part_descr
|
||||||
@ -178,6 +206,20 @@ target AS (SELECT $$swap_doc$$::jsonb swap)
|
|||||||
INNER JOIN cust c ON
|
INNER JOIN cust c ON
|
||||||
c.billto = SUBSTRING(o.bill_cust_descr,1,8)
|
c.billto = SUBSTRING(o.bill_cust_descr,1,8)
|
||||||
AND c.shipto = SUBSTRING(o.ship_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
|
--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 (
|
,ins AS (
|
||||||
|
Loading…
Reference in New Issue
Block a user