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


Fun task for the afternoon - grouping data


Fun task for the afternoon - grouping data

Author
Message
olibbhq
olibbhq
SSC-Enthusiastic
SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)

Group: General Forum Members
Points: 174 Visits: 351
Hi,

I am trying to create a table with a grouping based on a merged column. Best to explain with SQL

CREATE TABLE [dbo].[#Table_1](
[ID] [int] IDENTITY(1,1) NOT NULL,
[Region] [varchar](50) NULL,
[Prop1] [varchar](50) NULL,
[Prop2] [varchar](50) NULL,
[Prop3] [varchar](50) NULL,
CONSTRAINT [PK_Table_1] PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO


insert into #Table_1 values
('ANZ', 'A', 'B', 'C'),
('CAM', 'F', 'G', 'C'),
('CAM', 'A', 'B', 'C'),
('ME', 'H', 'V', 'N'),
('SAM', 'A', 'B', 'C')

select * from #Table_1

--SOME QUERY HERE to turn the data into something like this:

CREATE TABLE [dbo].[#Table_2](
[Region] [varchar](50) NULL,
[Prop1] [varchar](50) NULL,
[Prop2] [varchar](50) NULL,
[Prop3] [varchar](50) NULL)

insert into #Table_2 values
('ANZ,CAM,SAM', 'A', 'B', 'C'),
('CAM', 'F', 'G', 'C'),
('ME', 'H', 'V', 'N')

select * from #Table_2

--drop Table #Table_1
--drop Table #Table_2




I am thinking that at somepoint I need to use the XML PATH trick to concatenate the fields but I am a bit lost as to how to do this with the above senario. Any help you can pass on would be very useful.

Many Thanks,

Oliver
Eugene Elutin
Eugene Elutin
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: 3054 Visits: 5478
Try this:

SELECT  DISTINCT
STUFF((SELECT ',' + m2.Region
FROM #Table_1 AS m2
WHERE m2.Prop1 = m1.Prop1
AND m2.Prop2 = m1.Prop2
AND m2.Prop3 = m1.Prop3
ORDER BY m2.Region
FOR XML PATH('')),1,1,'') AS Regions
,m1.Prop1
,m1.Prop2
,m1.Prop3
FROM #Table_1 AS m1



_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
olibbhq
olibbhq
SSC-Enthusiastic
SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)SSC-Enthusiastic (174 reputation)

Group: General Forum Members
Points: 174 Visits: 351
Eugene,

Thank you so much, this works a treat. I was working along these lines however I was just adding the non merged rows outside the XML path and wondering why it wasnt working. Simply fantastic, thanks very much have a great weekend.

Oliver
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