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

Fun task for the afternoon - grouping data Expand / Collapse
Author
Message
Posted Friday, July 5, 2013 8:53 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, May 12, 2014 7:10 AM
Points: 151, Visits: 283
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
Post #1470776
Posted Friday, July 5, 2013 9:16 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Friday, July 4, 2014 3:55 AM
Points: 2,836, Visits: 5,062
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!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1470789
Posted Friday, July 5, 2013 9:48 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, May 12, 2014 7:10 AM
Points: 151, Visits: 283
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
Post #1470801
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse