November 17, 2012 at 10:42 am
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,
November 17, 2012 at 11:48 am
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
November 18, 2012 at 5:55 pm
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 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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
November 18, 2012 at 8:19 pm
CELKO (11/18/2012)
Why do you want to write proprietary, unmaintainable code?
Job security?
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
November 19, 2012 at 3:25 am
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.
November 19, 2012 at 5:20 am
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
November 19, 2012 at 9:04 pm
thank you very much Sony Francis @EY,Eugene Elutin,dwain.c for your feedback.
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply