Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 1234»»»

Concatenating field values in one string Expand / Collapse
Author
Message
Posted Thursday, March 19, 2009 9:40 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, March 19, 2014 10:23 AM
Points: 11, Visits: 101
Hi All.

I am trying to concatenate multiple field values from a table in one string.

Example:

IF Select * from TABLE TEST gives following :

ColA ColB

1 John
1 Josh
1 Bob
2 Kathy
2 Jill


How would I render it to give below data:

ColA ColB
1 John, Josh, Bob
2 Kathy, Jill


Can someone give their inputs. Thanks for the help.
Post #679572
Posted Thursday, March 19, 2009 9:54 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 6:59 AM
Points: 22,492, Visits: 30,186
Here is some code you can work with on this.
declare @TestTab table (ColA int, ColB Varchar(10));
insert into @TestTab
select 1, 'John' union all
select 1, 'Josh' union all
select 1, 'Bob' union all
select 2, 'Kathy' union all
select 2, 'Jill'
;

select * from @TestTab;

select
ColA,
stuff((select ', ' + ColB from @TestTab t2 where t2.ColA = t1.ColA for xml path('')),1,2,'')
from
@TestTab t1
group by
ColA;




Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #679589
Posted Thursday, March 19, 2009 9:57 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, March 19, 2014 10:23 AM
Points: 11, Visits: 101
Thanks ! Lynn. Will give it a try.
Post #679593
Posted Thursday, March 19, 2009 11:16 AM
Right there with Babe

Right there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with Babe

Group: General Forum Members
Last Login: Thursday, September 19, 2013 6:00 AM
Points: 715, Visits: 2,706
Nice Job Lynn, tried to solve it myself, and I couldn't get to group them. I've seen you use the FOR XML a few times in other posts.

I got a question though, why do you use stuff at the end, wouldn't a substring function, or a right function be easier?

And oh, yeah.. when I use FOR XML on a simply column, it does not give the same output. i.e:
 (ColA)Test1(/ColA)(ColA)TEst2(/ColA) 

why does appending a string to it stop doing the ColA thing?

Thanks


Cheers,

J-F
Post #679691
Posted Thursday, March 19, 2009 11:38 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 6:59 AM
Points: 22,492, Visits: 30,186
I am going to have to defer your questions to someone who has a better knowledge of FOR XML PATH. I picked up this little trick here on SSC and it works very well, so when someone asks how to do it (which does happen a lot here on SSC), it's something easy to post back.



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #679715
Posted Thursday, March 19, 2009 11:49 AM
Right there with Babe

Right there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with Babe

Group: General Forum Members
Last Login: Thursday, September 19, 2013 6:00 AM
Points: 715, Visits: 2,706
Thanks Lynn, hope a XML Guru can see this post! ;)

Cheers,

J-F
Post #679731
Posted Thursday, March 19, 2009 12:21 PM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: Monday, April 14, 2014 1:34 PM
Points: 15,442, Visits: 9,588
Stuff gets rid of a preceding comma at the beginning of the string. That's all. Try the query without it, and you get:


, John, Josh, Bob


The Stuff command, as written here, puts a zero-length string in, the 1 tells it to put it at the beginning of the string, and the 2 tells it to replace 2 characters. Thus, it gets rid of the comma-space at the beginning. Can't use Replace, or you'd get rid of all of the commas, which would kind of defeat the purpose.

I guess I'm not clear on the other question about the XML. Using "path('')" is what gets rid of the column names, if that's what you're asking. Well, it replaces the column names with a zero-length string, to be precise.


- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
Post #679769
Posted Thursday, March 19, 2009 12:27 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 6:59 AM
Points: 22,492, Visits: 30,186
It's the FOR XML PATH part that I am not really sure about myself. That's why I was asking for some help here. I'd like to understand it better myself.


Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #679773
Posted Thursday, March 19, 2009 12:31 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 12:31 PM
Points: 10,910, Visits: 12,545
Lynn Pettis (3/19/2009)
It's the FOR XML PATH part that I am not really sure about myself. That's why I was asking for some help here. I'd like to understand it better myself.


Sent out a "tweet" about it that Grant re-tweeted to expand the knowledge base.




Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
Post #679776
Posted Thursday, March 19, 2009 12:39 PM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: Monday, April 14, 2014 1:34 PM
Points: 15,442, Visits: 9,588
Try this, see if it helps:

if object_id(N'tempdb..#T') is not null
drop table #T;

create table #T (
ID int identity primary key,
Col1 char(1) not null);

insert into #T (Col1)
select substring('abcdefghijklmnopqrstuvwxyz', number, 1)
from dbo.Numbers
where number between 1 and 26;

select Col1
from #T
for XML path;

select Col1
from #T
for XML path('');

select ', ' + Col1
from #T
for XML path;

select ', ' + Col1
from #T
for XML path('');

You'll see that the comma gets rid of the Col1 header, and the ('') gets rid of the row header, so all you're left with is the value and the comma.

Try some variations on it. Put an "a" in there instead of a comma, or a vertical-pipe instead of a comma. Basically, anything that would result in "(no column name)" if you ran it as a regular query will accomplish what the comma does there.


- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
Post #679781
« Prev Topic | Next Topic »

Add to briefcase 1234»»»

Permissions Expand / Collapse