November 26, 2008 at 12:24 pm
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'
November 26, 2008 at 2:08 pm
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)...
November 26, 2008 at 2:27 pm
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.
November 27, 2008 at 4:28 am
http://www.simple-talk.com/sql/t-sql-programming/concatenating-row-values-in-transact-sql/
Failing to plan is Planning to fail
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply