February 20, 2014 at 8:02 am
Folks:
I need help with a UPDATE SQL Statement.
CREATE TABLE #TEST1
(
AID INT ,
EmailID VARCHAR (200)
);
INSERT INTO #TEST1
VALUES (100, 'jack@microsoft.com');
INSERT INTO #TEST1
VALUES (100, 'david@microsoft.com');
INSERT INTO #TEST1
VALUES (100, 'paul@microsoft.com');
INSERT INTO #TEST1
VALUES (200, 'amy@microsoft.com');
INSERT INTO #TEST1
VALUES (200, 'bill@microsoft.com');
INSERT INTO #TEST1
VALUES (300, 'chris@microsoft.com');
INSERT INTO #TEST1
VALUES (400, 'katrina@microsoft.com');
INSERT INTO #TEST1
VALUES (500, 'john@microsoft.com');
INSERT INTO #TEST1
VALUES (500, 'jack@microsoft.com');
INSERT INTO #TEST1
VALUES (500, 'david@microsoft.com');
CREATE TABLE #TEST2
(
AID INT ,
EmailIDs VARCHAR (1000) NULL
);
INSERT INTO #TEST2 (AID)
VALUES (100);
INSERT INTO #TEST2 (AID)
VALUES (200);
INSERT INTO #TEST2 (AID)
VALUES (300);
INSERT INTO #TEST2 (AID)
VALUES (400);
INSERT INTO #TEST2 (AID)
VALUES (500);
I would like to update the Email IDs column in #TEST2 with Email ID value from #TEST1 table for matching AID column. Instead of having the email ids on seperate row I would like the email Id for each AID in a single column seperated with semi colon(;). Any help on update SQL is appreciated.
OUTPUT:
AIDEmailIDs
100jack@microsoft.com; david@microsoft.com; paul@microsoft.com
200amy@microsoft.com; bill@microsoft.com
500john@microsoft.com; jack@microsoft.com; david@microsoft.com
Thanks !
February 20, 2014 at 8:15 am
You shouldn't store lists for delimited values in a single line for a single value. It violates the first normal form.
If you really need this (I suggest to use it only for display or email generation purposes), you could use the method described in this article: http://www.sqlservercentral.com/articles/comma+separated+list/71700/
This is really fast and you don't need to store the values as arrays.
February 20, 2014 at 8:22 am
sorry wrong code
-----------------------------------------------------------------------------------------------------------
"Ya can't make an omelette without breaking just a few eggs" 😉
February 20, 2014 at 8:41 am
It is only for display purpose in reporting because the user doesn't want to see 4 rows for each record if there are 4 email ids for that AID.
February 20, 2014 at 8:50 am
sqldba20 (2/20/2014)
It is only for display purpose in reporting because the user doesn't want to see 4 rows for each record if there are 4 email ids for that AID.
So, do you need more help? Or can you find a solution from the article on your own?If you get the solution on your own, you'll learn more than getting the answer already processed.
February 20, 2014 at 8:53 am
sqldba20 (2/20/2014)
It is only for display purpose in reporting because the user doesn't want to see 4 rows for each record if there are 4 email ids for that AID.
You may find it more efficient to perform this relatively simple operation in the code which generates the #temp table, rather than updating the temp table afterwards. If you're not sure how to do this, post the code and we'll help.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
February 20, 2014 at 9:01 am
Nevermind...I was able to figure out using the link posted by Luis. Came with this SQL and it works.
WITH Ranked (AID, rnk, EmailID)
AS (SELECT AID,
ROW_NUMBER() OVER (PARTITION BY AID ORDER BY AID),
CAST (EmailID AS VARCHAR (8000))
FROM #TEST1),
AnchorRanked (AID, rnk, EmailID)
AS (SELECT AID,
rnk,
EmailID
FROM Ranked
WHERE rnk = 1),
RecurRanked (AID, rnk, EmailID)
AS (SELECT AID,
rnk,
EmailID
FROM AnchorRanked
UNION ALL
SELECT Ranked.AID,
Ranked.rnk,
RecurRanked.EmailID + '; ' + Ranked.EmailID
FROM Ranked
INNER JOIN
RecurRanked
ON Ranked.AID = RecurRanked.AID
AND Ranked.rnk = RecurRanked.rnk + 1)
SELECT AID AS AID,
MAX(EmailID) AS EmaiID
FROM RecurRanked
GROUP BY AID
February 20, 2014 at 9:35 am
sqldba20 (2/20/2014)
Nevermind...I was able to figure out using the link posted by Luis. Came with this SQL and it works.
How on earth did you figure that out from the link I posted? :hehe:
This method might kill the performance as it will create more rows than needed.
February 20, 2014 at 9:46 am
Luis Cazares (2/20/2014)
sqldba20 (2/20/2014)
Nevermind...I was able to figure out using the link posted by Luis. Came with this SQL and it works.How on earth did you figure that out from the link I posted? :hehe:
This method might kill the performance as it will create more rows than needed.
Baffled me too, Luis.
rCTE's aren't the best choice for this - slower than FOR XML PATH, waaaaay overcomplicated.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
February 20, 2014 at 10:51 am
If this is not appropriate then could you help me a updated SQL ?
February 20, 2014 at 10:58 am
It would be as simple as this, as explained in the article:
SELECT t.AID,
Emails = STUFF((SELECT '; ' + t1.EmailID
FROM #TEST1 t1
WHERE t1.AID = t.AID
FOR XML PATH('')), 1, 2, '')
FROM #TEST1 t
GROUP BY t.AID
ORDER BY t.AID
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply