SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


COALESCE?Create comma delimited list field from table field


COALESCE?Create comma delimited list field from table field

Author
Message
vwilliams
vwilliams
SSC-Enthusiastic
SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)

Group: General Forum Members
Points: 127 Visits: 62
I have two tables, TableA, TableB. I need to update a field in TableB - b.newfield to contain the list of distinct values that TableA contains for the possible combinations of two other fields. For this example, the value in field 1 will be consistent. Is this possible with COALESCE?Crying

Example:
TableA field1 field2 field3
1 2 352
1 2 536
1 2 555
1 2 555

1 3 111
1 3 777

1 4 222
1 4 222


So TableB should look like
Field1 Field2 Newfield
1 2 '555, 342, 536'
1 3 '111, 777'
1 4 '222'
winash
winash
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3142 Visits: 1883
Is this what you are looking for? You might want to tweak the code if it doesn't perform well for large amounts of data...

--setup data
DECLARE @Tab1 TABLE(field1 int, field2 int)
INSERT @Tab1(field1,field2)
SELECT 2,352
UNION ALL
SELECT 2,536
UNION ALL
SELECT 2,555
UNION ALL
SELECT 2,555
UNION ALL
SELECT 3,111
UNION ALL
SELECT 3,777
UNION ALL
SELECT 4,222
UNION ALL
SELECT 4,222

DECLARE @Tab2 TABLE(field1 int, field2 varchar(1000))
INSERT @Tab2(field1)
SELECT 1
UNION ALL
SELECT 2
UNION ALL
SELECT 3
UNION ALL
SELECT 4
UNION ALL
SELECT 5

-- check data
SELECT * FROM @Tab1
SELECT * FROM @Tab2

-- check query
SELECT
field1,
STUFF((
SELECT ',' + CAST(T.field2 as varchar(30))
FROM @Tab1 T
WHERE T.field1 = T1.field1
GROUP BY T.field1,T.field2
ORDER BY T.field2
FOR XML PATH('')),1,1,'') AS ConcatStuff
FROM @Tab1 T1
GROUP BY field1

UPDATE @Tab2 SET field2 = T.ConcatStuff FROM
@Tab2 T2 INNER JOIN
(
SELECT
field1,
STUFF((
SELECT ',' + CAST(T.field2 as varchar(30))
FROM @Tab1 T
WHERE T.field1 = T1.field1
GROUP BY T.field1,T.field2
ORDER BY T.field2
FOR XML PATH('')
),1,1,'') AS ConcatStuff
FROM @Tab1 T1
GROUP BY field1
)T ON
T2.field1 = T.field1

-- check update works
SELECT * FROM @Tab2

Just to know - why exactly do you want to get this comma delimited values? I prefer not to do too much of string manipulations in T-SQL and leave that to the front end (if possible)...



vwilliams
vwilliams
SSC-Enthusiastic
SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)SSC-Enthusiastic (127 reputation)

Group: General Forum Members
Points: 127 Visits: 62
Thanks for replying. I actually found a simpler answer:

SELECT t.field1,t.field2,LEFT(sl.numlist,LEN(sl.numlist)-1) as newfield
FROM(SELECT DISTINCT field2,field1 FROM tableA) t
CROSS APPLY(SELECT distinct CAST(field3 AS varchar(10)) + ',' AS [text()]
FROM tableB
WHERE field2= t.field2
FOR XML PATH(''))sl(numlist)

I created a temp table using this, and then joined it to my original table to update the field.
Madhivanan-208264
Madhivanan-208264
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1603 Visits: 476
http://www.simple-talk.com/sql/t-sql-programming/concatenating-row-values-in-transact-sql/



Madhivanan

Failing to plan is Planning to fail
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