forecast_api/route_sql/swap_cust.sql

312 lines
9.8 KiB
SQL

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 (
----------only return dba if being replaced-------------------------------------------------
----------class and rep must always bew returned for both to determine new quota rep--------
SELECT
billto
,bill_r
,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
,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 = COALESCE(swap.bill_r,billto)
LEFT OUTER JOIN lgdat.cust sc ON
sc.bvcust = COALESCE(swap.ship_r,shipto)
)
--put bill to and ship to back together and join in channel, terms, descriptions, etc
,seg AS (
SELECT
x.glec
,x.segm
FROM
(
VALUES
('1SU','Sustainable'),
('1CU','Sustainable'),
('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
,r.rcode dsm
,(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
,CASE SUBSTRING(c.bill_class,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(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.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)
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 (
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