swap part number and associated masterd data
This commit is contained in:
parent
f71fee5df6
commit
9829d64368
332
route_sql/build/set_part_master.sql
Normal file
332
route_sql/build/set_part_master.sql
Normal file
@ -0,0 +1,332 @@
|
||||
BEGIN;
|
||||
|
||||
WITH
|
||||
repl AS (
|
||||
SELECT * FROM
|
||||
(
|
||||
VALUES
|
||||
('IFA06000G181012LRCIR ','IFA06000G181012LRCIR')
|
||||
) as x(orig,fix)
|
||||
)
|
||||
,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)
|
||||
)
|
||||
,MG AS (
|
||||
SELECT
|
||||
X.F1, X.MING, X.GRP
|
||||
FROM
|
||||
(
|
||||
VALUES
|
||||
('L','000','Branded'),
|
||||
('L','B10','Branded'),
|
||||
('L','B11','Branded'),
|
||||
('L','B52','Branded'),
|
||||
('L','C10','Branded'),
|
||||
('L','D12','Branded'),
|
||||
('L','M11','Branded'),
|
||||
('L','P12','Branded'),
|
||||
('L','P13','Branded'),
|
||||
('L','S10','Branded'),
|
||||
('L','Y10','Branded'),
|
||||
('L','Y11','Branded'),
|
||||
('L','Y12','Branded'),
|
||||
('P','B10','Branded'),
|
||||
('P','B11','Branded'),
|
||||
('P','B52','Branded')
|
||||
) AS X (F1, MING, GRP)
|
||||
)
|
||||
,REPC AS (
|
||||
SELECT
|
||||
LTRIM(RTRIM(C.A9)) RCODE
|
||||
,LTRIM(RTRIM(C.A9)) || ' - ' || C.A30 REPP
|
||||
,COALESCE(Q.DIR,'Other') DIRECTOR
|
||||
FROM
|
||||
LGDAT.CODE C
|
||||
LEFT OUTER JOIN RLARP.QRH Q ON
|
||||
Q.QR = LTRIM(RTRIM(C.A9))
|
||||
WHERE
|
||||
C.A2 = 'MM'
|
||||
)
|
||||
--MOLD DESCRIPTIONS
|
||||
,MD AS (
|
||||
SELECT
|
||||
U.MOLD
|
||||
,MAX(U.DESCR) DESCR
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
SUBSTR(M.AVPART,1,8) MOLD
|
||||
,MAX(M.AVDES1) DESCR
|
||||
FROM
|
||||
LGDAT.STKMM M
|
||||
WHERE
|
||||
LENGTH(M.AVPART) > 8
|
||||
AND SUBSTR(M.AVGLED,1,1) <= '2'
|
||||
GROUP BY
|
||||
SUBSTR(M.AVPART,1,8)
|
||||
UNION ALL
|
||||
SELECT
|
||||
SUBSTR(P.AWPART,1,8) MOLD
|
||||
,MAX(P.AWDES1) DESCR
|
||||
FROM
|
||||
LGDAT.STKMP P
|
||||
WHERE
|
||||
LENGTH(P.AWPART) > 8
|
||||
AND SUBSTR(P.AWGLED,1,1) <= '2'
|
||||
GROUP BY
|
||||
SUBSTR(P.AWPART,1,8)
|
||||
) U
|
||||
GROUP BY
|
||||
U.MOLD
|
||||
)
|
||||
----------------------------------------------------sales major codes----------------------------------------------------------------------------------------------------------------------------------
|
||||
,SJ AS (
|
||||
SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') = ''
|
||||
)
|
||||
----------------------------------------------------sales minor codes----------------------------------------------------------------------------------------------------------------------------------
|
||||
,SI AS (
|
||||
SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') <> ''
|
||||
)
|
||||
,copr AS (
|
||||
SELECT
|
||||
LTRIM(RTRIM(A9)) AS COMP,
|
||||
A30 AS DESCR,
|
||||
SUBSTR(C.A249,242,2) CURR,
|
||||
SUBSTR(C.A249,32,4) AS GL,
|
||||
SUBSTR(C.A249,190,4) AS AR,
|
||||
SUBSTR(C.A249,182,4) AS AP,
|
||||
SUBSTR(C.A249,198,4) AS FA,
|
||||
SUBSTR(C.A249,238,4) AS IC ,
|
||||
SUBSTR(D.A249,9,5) CONS_FUNC
|
||||
FROM
|
||||
LGDAT.CODE
|
||||
LEFT OUTER JOIN LGDAT.NAME C ON
|
||||
'C0000'||LTRIM(RTRIM(A9)) = C.A7
|
||||
LEFT OUTER JOIN LGDAT.NAME D ON
|
||||
'D0000'||LTRIM(RTRIM(A9)) = D.A7
|
||||
WHERE
|
||||
A2 = 'AA' OR A2 IS NULL
|
||||
)
|
||||
,x AS (
|
||||
SELECT
|
||||
o.part origpart
|
||||
,repl.fix as part
|
||||
,COALESCE(m.avdplt,p.awdplt) plnt
|
||||
,COALESCE(m.avglcd, p.awgldc) ord_gldc
|
||||
,COALESCE(m.avmajg,p.awmajg) majg
|
||||
,COALESCE(m.avming,p.awming) ming
|
||||
,COALESCE(m.avmajs,p.awmajs) majs
|
||||
,COALESCE(m.avmins,p.awmins) mins
|
||||
,COALESCE(m.avglcd,p.awgldc) gldc
|
||||
,COALESCE(m.avgled,p.awgled) glec
|
||||
,COALESCE(m.avharm,p.awharm) harm
|
||||
,COALESCE(m.avclss,p.awclss) clss
|
||||
,SUBSTR(COALESCE(m."avcpt#",p."awvpt#"),1,1) brand
|
||||
,COALESCE(m.avassc,p.awassc) assc
|
||||
,COALESCE(cm.cgstcs, cp.chstcs, cr.y0stcs) stdcost
|
||||
,copr.curr c_currency
|
||||
,cx.rate c_rate
|
||||
,SUBSTR(o.part,1,3)||coalesce(' - '||F.DESCR,'') part_family
|
||||
,SUBSTRING(o.part,1,8)||coalesce(' - '||MD.DESCR,'') part_group
|
||||
,COALESCE(MG.GRP,'Unbranded') branding
|
||||
,CASE WHEN substring(COALESCE(m.avgled, p.awgled),1,1) <= '2' THEN SUBSTRING(o.part,9,3) ELSE '' END color
|
||||
,COALESCE(SEG.SEGM,'Other') segm
|
||||
,COALESCE(m.avmajg,p.awmajg)||COALESCE(' - '||BQDES,'') majg_descr
|
||||
,COALESCE(m.avming,p.awming)||COALESCE(' - '||BRDES,'') ming_descr
|
||||
,COALESCE(m.avmajs,p.awmajs)||COALESCE(' - '||SJ.BSDES1,'') majs_descr
|
||||
,COALESCE(m.avmins,p.awmins)||COALESCE(' - '||SI.BSDES1,'') mins_descr
|
||||
--quota rep--------------------------------------------
|
||||
,RTRIM(
|
||||
COALESCE(
|
||||
--retail items go to currep, or if null go to 90005
|
||||
CASE WHEN COALESCE(m.avgled,p.awgled) IN ('1RE','1CU') THEN
|
||||
CASE WHEN bc.bvctry = 'CAN' THEN
|
||||
--Rachel Bowman
|
||||
'50300'
|
||||
ELSE
|
||||
--retail chain got to Mark Wilkinson
|
||||
CASE COALESCE(cg.cgrp,bc.bvname)
|
||||
WHEN 'THE HOME DEPOT' THEN '90005'
|
||||
WHEN 'DO IT BEST' THEN '90005'
|
||||
WHEN 'ACE HARDWARE' THEN '90005'
|
||||
WHEN 'ALDI' THEN '90005'
|
||||
WHEN 'AMAZON.COM' THEN '90005'
|
||||
WHEN 'GARDEN RIDGE CORP' THEN '90005'
|
||||
--all other retail goes to Doran Marable
|
||||
ELSE '50200'
|
||||
END
|
||||
END
|
||||
ELSE
|
||||
CASE WHEN COALESCE(m.avming,p.awming) = 'B52' THEN
|
||||
'PW'
|
||||
--gdir, ndir go to bill-to rep
|
||||
ELSE
|
||||
CASE WHEN bc.bvclas IN ('GDIR','NDIR') THEN
|
||||
bc.bvsalm
|
||||
ELSE
|
||||
sc.bvsalm
|
||||
END
|
||||
END
|
||||
END
|
||||
,''
|
||||
)
|
||||
) quota_rep
|
||||
,repc.repp quota_rep_descr
|
||||
,repc.director director_descr
|
||||
FROM
|
||||
repl
|
||||
INNER JOIN rlarp.osm_fcpool o ON
|
||||
o.part = repl.orig
|
||||
LEFT OUTER JOIN lgdat.stkmm m ON
|
||||
m.avpart = repl.fix
|
||||
LEFT OUTER JOIN lgdat.stkmp p ON
|
||||
p.awpart = repl.fix
|
||||
LEFT OUTER JOIN lgdat.stka a ON
|
||||
a.v6part = repl.fix
|
||||
AND a.v6plnt = COALESCE(m.avdplt,p.awdplt)
|
||||
LEFT OUTER JOIN lgdat.icstm cm ON
|
||||
cm.cgpart = repl.fix
|
||||
AND cm.cgplnt = COALESCE(m.avdplt,p.awdplt)
|
||||
LEFT OUTER JOIN lgdat.icstp cp ON
|
||||
cp.chpart = repl.fix
|
||||
AND cp.chplnt = COALESCE(m.avdplt,p.awdplt)
|
||||
LEFT OUTER JOIN lgdat.icstr cr ON
|
||||
cr.y0part = repl.fix
|
||||
AND cr.y0plnt = COALESCE(m.avdplt,p.awdplt)
|
||||
LEFT OUTER JOIN SEG ON
|
||||
SEG.GLEC = COALESCE(m.avgled,p.awgled)
|
||||
--AND SEG.SEGM <> 'Other'
|
||||
LEFT OUTER JOIN MG ON
|
||||
MG.F1 = SUBSTR(o.part,16,1)
|
||||
AND MG.MING = COALESCE(m.avming,p.awming)
|
||||
LEFT OUTER JOIN rlarp.family F ON
|
||||
F.F3 = SUBSTR(o.part,1,3)
|
||||
LEFT OUTER JOIN MD ON
|
||||
MD.MOLD = SUBSTR(o.part,1,8)
|
||||
LEFT OUTER JOIN SI ON
|
||||
SI.BSMJCD = COALESCE(m.avmajs,p.awmajs)
|
||||
AND SI.BSMNCD = COALESCE(m.avmins,p.awmins)
|
||||
LEFT OUTER JOIN SJ ON
|
||||
SJ.BSMJCD = COALESCE(m.avmajs,p.awmajs)
|
||||
LEFT OUTER JOIN LGDAT.MAJG ON
|
||||
BQGRP = COALESCE(m.avmajg,p.awmajg)
|
||||
LEFT OUTER JOIN LGDAT.MMGP ON
|
||||
BRMGRP = COALESCE(m.avming,p.awming)
|
||||
AND BRGRP = COALESCE(m.avmajg,p.awmajg)
|
||||
LEFT OUTER JOIN lgdat.plnt ON
|
||||
yaplnt = a.v6plnt
|
||||
LEFT OUTER JOIN copr ON
|
||||
copr.comp = yacomp::text
|
||||
LEFT OUTER JOIN rlarp.ffcret cx ON
|
||||
cx.perd = '1910'
|
||||
AND cx.rtyp = 'MA'
|
||||
AND cx.fcur = copr.curr
|
||||
AND cx.tcur = 'US'
|
||||
------for quota rep------------
|
||||
LEFT OUTER JOIN LGDAT.CUST BC ON
|
||||
BC.BVCUST = o.BILL_CUST
|
||||
LEFT OUTER JOIN LGDAT.CUST SC ON
|
||||
SC.BVCUST = o.SHIP_CUST
|
||||
LEFT OUTER JOIN RLARP.FFCUST CG ON
|
||||
CG.CUSTN = BC.BVCUST
|
||||
LEFT OUTER JOIN RLARP.FFCUST SG ON
|
||||
SG.CUSTN = SC.BVCUST
|
||||
LEFT OUTER JOIN REPC ON
|
||||
REPC.RCODE = RTRIM(
|
||||
COALESCE(
|
||||
--retail items go to currep, or if null go to 90005
|
||||
CASE WHEN COALESCE(m.avgled,p.awgled) IN ('1RE','1CU') THEN
|
||||
CASE WHEN bc.bvctry = 'CAN' THEN
|
||||
--Rachel Bowman
|
||||
'50300'
|
||||
ELSE
|
||||
--retail chain got to Mark Wilkinson
|
||||
CASE COALESCE(cg.cgrp,bc.bvname)
|
||||
WHEN 'THE HOME DEPOT' THEN '90005'
|
||||
WHEN 'DO IT BEST' THEN '90005'
|
||||
WHEN 'ACE HARDWARE' THEN '90005'
|
||||
WHEN 'ALDI' THEN '90005'
|
||||
WHEN 'AMAZON.COM' THEN '90005'
|
||||
WHEN 'GARDEN RIDGE CORP' THEN '90005'
|
||||
--all other retail goes to Doran Marable
|
||||
ELSE '50200'
|
||||
END
|
||||
END
|
||||
ELSE
|
||||
CASE WHEN COALESCE(m.avming,p.awming) = 'B52' THEN
|
||||
'PW'
|
||||
--gdir, ndir go to bill-to rep
|
||||
ELSE
|
||||
CASE WHEN bc.bvclas IN ('GDIR','NDIR') THEN
|
||||
bc.bvsalm
|
||||
ELSE
|
||||
sc.bvsalm
|
||||
END
|
||||
END
|
||||
END
|
||||
,''
|
||||
)
|
||||
)
|
||||
)
|
||||
,u AS (
|
||||
UPDATE
|
||||
rlarp.osm_fcpool o
|
||||
SET
|
||||
part = x.part
|
||||
,plnt = x.plnt
|
||||
,ord_gldc = x.ord_gldc
|
||||
,majg = x.majg
|
||||
,ming = x.ming
|
||||
,majs = x.majs
|
||||
,mins = x.mins
|
||||
,gldc = x.gldc
|
||||
,glec = x.glec
|
||||
,harm = x.harm
|
||||
,clss = x.clss
|
||||
,assc = x.assc
|
||||
,brand = x.brand
|
||||
,fb_cst_loc = o.fb_qty * x.stdcost
|
||||
,fb_cst_loc_cur = o.fb_qty * x.stdcost
|
||||
,fb_cst_loc_fut = o.fb_qty * x.stdcost
|
||||
,part_family = x.part_family
|
||||
,part_group = x.part_group
|
||||
,branding = x.branding
|
||||
,color = x.color
|
||||
,segm = x.color
|
||||
,majg_descr = x.majg_descr
|
||||
,ming_descr = x.majg_descr
|
||||
,majs_descr = x.majs_descr
|
||||
,mins_descr = x.mins_descr
|
||||
,quota_rep = x.quota_rep
|
||||
,quota_rep_descr = x.quota_rep_descr
|
||||
,director_descr = x.director_descr
|
||||
FROM
|
||||
x
|
||||
WHERE
|
||||
x.origpart = o.part
|
||||
RETURNING o.*
|
||||
)
|
||||
SELECT * FROM u;
|
||||
|
||||
--ROLLBACK;
|
||||
COMMIT;
|
Loading…
Reference in New Issue
Block a user