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

Convert values of mulitiple rows into single column with no duplicate entries Expand / Collapse
Author
Message
Posted Saturday, November 17, 2012 10:42 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, April 08, 2014 12:23 PM
Points: 31, Visits: 370
hi all,
i went through the forum and found out a way of concatenating row values into column using stuff, but can't figure out how to remove duplicates and only display them once.
if you have any function so i could use that with more columns rather then using this stuff function.

IF OBJECT_ID('TempDB..#Result','U') IS NOT NULL
DROP TABLE #Result
create Table #Result
(
Province varchar(100),
District varchar(100),
Fp varchar(10),
Cycle int
)
insert into #Result
select 'LOGAR','Charkh','Abc',1 union ALL
select 'LOGAR','Charkh','Dacaar',2 union ALL
select 'LOGAR','Charkh','Ze',3 union ALL
select 'LOGAR','Charkh','ARTs',4 union ALL
select 'LOGAR','Charkh','Abc',5

SELECT a.Province ,a.District ,
FPS =
STUFF ( ( SELECT ','+ b.fp
FROM #Result b
WHERE a.Province = b.Province
AND a.district = b.district
ORDER BY b.fp
FOR XML PATH(''),TYPE
).value('.','VARCHAR(MAX)')
, 1,1,SPACE(0))
FROM #Result a
GROUP BY a.Province,a.district

-- Require Output with out duplicates fps

select 'LOGAR' as Province,'Charkh' as District,'Abc,ARTs,Dacaar,Ze' as FPS

thanks,
Post #1385954
Posted Saturday, November 17, 2012 11:48 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, April 08, 2014 12:23 PM
Points: 31, Visits: 370
the solution is to convert the column to varchar and run that inside subquery, hope it will help some one else with similar problem, now one more thing here left is the order of entries.

SELECT a.Province ,a.District ,
FPS =
(select stuff((SELECT distinct ',' + cast(fp as varchar(10))
FROM #Result t2
where t2.Province = a.province and
t2.district=a.district
FOR XML PATH('')),1,1,''))
FROM #Result a
GROUP BY a.Province,a.district
Post #1385967
Posted Sunday, November 18, 2012 5:55 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 6:57 PM
Points: 3,590, Visits: 5,099
Here's another way to do it while avoiding the use of DISTINCT:

SELECT Province, District
,FPS=STUFF((
SELECT ',' + b.FP
FROM #Result b
WHERE a.Province = b.Province AND a.District = b.District
GROUP BY Province, District, FP
FOR XML PATH('')), 1, 1, '')
FROM #Result a
GROUP BY Province, District





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1386117
Posted Sunday, November 18, 2012 8:17 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, January 15, 2013 11:11 AM
Points: 1,945, Visits: 2,782
I went through the forum and found out a way of concatenating row values into column using stuff, but can't figure out how to remove duplicates and only display them once.


Why do you wish to destroy and violate the principle of tiered architectures? Why do you want to write proprietary, unmaintainable code?


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1386132
Posted Sunday, November 18, 2012 8:19 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 6:57 PM
Points: 3,590, Visits: 5,099
CELKO (11/18/2012)
Why do you want to write proprietary, unmaintainable code?


Job security?



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1386134
Posted Monday, November 19, 2012 3:25 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Thursday, April 03, 2014 10:10 AM
Points: 2,792, Visits: 4,874
CELKO (11/18/2012)
I went through the forum and found out a way of concatenating row values into column using stuff, but can't figure out how to remove duplicates and only display them once.


Why do you wish to destroy and violate the principle of tiered architectures? Why do you want to write proprietary, unmaintainable code?


I cannot see how concatenating distinct values from rows into single (some-character separated) value is destroying and violating principals of tiered architecture. More than that, when it became available to achieve easily in T-SQL, it was real help in many solutions (client applications and especially - reporting ones).
Also, there is absolutely nothing wrong with using proprietary functionality of MS T-SQL. It would be stupid to suggest not to use features of T-SQL which quite often makes it stand out from another RDBMS solutions. Would you ask Oracle developers not to use Oracle specific features/libraries?
Actually, if you so against "proprietary" coding, what do you think in coding practices generally?
No C#, VB.NET as it's MS proprietary, no Java as it's IBM one... Looks like every language (eg. assembler), in certain extend is a proprietary...
Why do you think that there is a real need of porting every single solution from one language/system base to another? How often does it happen in real life? Is it use of proprietary features, is the main issue when you port an application?
My answers to above three questions would be:
1. No much need!
2. Not very often, definitely less often then replacing system completely.
3. No, it's clearly not. Replacing ISNULL with COALESCE, for example is nothing in comparison with issues related with use of new drivers, OS architecture, security and many other...

And about "unmaintainable code". The technique used by OP is well known among T-SQL professionals and it's one of the best and used methods to achieve what OP needs. How does it compromise maintainability? If this block of code is appropriately commented and nicely formatted (for ease of read), it will not effect code maintainability in any manner.


_____________________________________________
"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 #1386266
Posted Monday, November 19, 2012 5:20 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Thursday, April 03, 2014 4:01 AM
Points: 63, Visits: 277
May be this will help you

SELECT a.Province ,a.District ,
FPS =
STUFF ( ( SELECT ','+ b.fp
FROM #Result b
WHERE a.Province = b.Province
AND a.district = b.district
GROUP BY FP
ORDER BY b.fp
FOR XML PATH(''),TYPE
).value('.','VARCHAR(MAX)')
, 1,1,SPACE(0))
FROM #Result a
GROUP BY a.Province,a.district
Post #1386313
Posted Monday, November 19, 2012 9:04 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, April 08, 2014 12:23 PM
Points: 31, Visits: 370
thank you very much Sony Francis @EY,Eugene Elutin,dwain.c for your feedback.
Post #1386660
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse