Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Table update using a hierarchy


Table update using a hierarchy

Author
Message
DerbyNeal
DerbyNeal
SSC-Enthusiastic
SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)

Group: General Forum Members
Points: 156 Visits: 909
Hi
I need a table updating using a lookup.
In my example, Table1 has 3 AccType columns which need to be referenced by the Acc column in Table2. If a match is found, then the Id column is updated. However, in this instance, there is a hierarchy to be adhered to, where I need to try to match the leftmost column (AccType1) first, and if no match is found then attempt to match AccType2 and again if no match is found then AccType3.

Table1         
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Table1](
[AccType1] [nvarchar](10) NULL,
[AccType2] [nvarchar](10) NULL,
[AccType3] [nvarchar](10) NULL,
[Id] [nvarchar](5) NULL
) ON [PRIMARY]
;

INSERT INTO dbo.Table1
(AccType1, AccType2, AccType3)
VALUES('','123','123');

INSERT INTO dbo.Table1
(AccType1, AccType2, AccType3)
VALUES('','234','456');

INSERT INTO dbo.Table1
(AccType1, AccType2, AccType3)
VALUES('678','654','532');

INSERT INTO dbo.Table1
(AccType1, AccType2, AccType3)
VALUES('890','432','432');

INSERT INTO dbo.Table1
(AccType1, AccType2, AccType3)
VALUES('898','754','343');

Table2
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Table2](
[Acc] [nvarchar](10) NULL,
[Id] [nvarchar](5) NULL
) ON [PRIMARY]
;

INSERT INTO dbo.Table2
(Acc, Id)
VALUES('123','AA');

INSERT INTO dbo.Table2
(Acc, Id)
VALUES('234','BB');

INSERT INTO dbo.Table2
(Acc, Id)
VALUES('432','DD');

INSERT INTO dbo.Table2
(Acc, Id)
VALUES('456','EE');

INSERT INTO dbo.Table2
(Acc, Id)
VALUES('532','FF');

INSERT INTO dbo.Table2
(Acc, Id)
VALUES('678','CC');



The results should be...

Table1 - Updated
AccType1 AccType2 AccType3 Id
123 123 AA
234 456 BB
678 654 532 CC
890 432 432 DD
898 754 343


Note: The first 2 rows in Table1 contain blank '' AccType1 columns. Also, the last row has no Table2 match against any of the 3 AccTypes.

Any ideas please?

Thanks in advance,
Mark Cowne
Mark Cowne
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2095 Visits: 22803

UPDATE t1
SET Id = COALESCE(t2a.Id,t2b.Id,t2c.Id)
FROM Table1 t1
LEFT OUTER JOIN Table2 t2a ON t2a.Acc = t1.AccType1
LEFT OUTER JOIN Table2 t2b ON t2b.Acc = t1.AccType2
LEFT OUTER JOIN Table2 t2c ON t2c.Acc = t1.AccType3



____________________________________________________

Deja View - The strange feeling that somewhere, sometime you've optimised this query before

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537




Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search