SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


SQL Distinct comma delimited list


SQL Distinct comma delimited list

Author
Message
Simon Parry
Simon Parry
Old Hand
Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)

Group: General Forum Members
Points: 358 Visits: 103
Hi
I am trying to create a comma delimted list of names in a table using the below query

DECLARE @listStr VARCHAR(MAX)
SELECT @listStr = COALESCE(@listStr+',' ,'') + Name
FROM Production.Product

SELECT @listStr

This works fine, however the list does contain duplicates

Can anyone advise how I would make this 'distinct' so the list does not contain duplicates

thanks

simon
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)

Group: General Forum Members
Points: 41767 Visits: 20006
DECLARE @listStr VARCHAR(MAX) 
SELECT @listStr = COALESCE(@listStr+',' ,'') + Name
FROM (SELECT DISTINCT Name FROM Production.Product) d



FOR XML PATH is also worth a look.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
ksatpute123
ksatpute123
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1734 Visits: 383
Easiest way

DECLARE @listStr VARCHAR(MAX)
SELECT @listStr = COALESCE(@listStr+',' ,'') + Name
FROM Production.Product
GROUP BY Name

SELECT @listStr

:-)
Eugene Elutin
Eugene Elutin
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12542 Visits: 5478
ksatpute123 (7/24/2013)
Easiest way

DECLARE @listStr VARCHAR(MAX)
SELECT @listStr = COALESCE(@listStr+',' ,'') + Name
FROM Production.Product
GROUP BY Name

SELECT @listStr

:-)


Yep, does look like. However...
Correct concatenation of string values (eg. accumulating of numeric values) using "SELECT @var = @var + Col FROM Table" costruction is not guaranteed in SQL Server!
Most of times, simple select will work. Having GROUP BY (as well as using JOINS) increases probability that accumulated value will not be correct. Selecting from sub-query with DISTINCT could be a bit safer option.
One of the reasons why all of the above ways may produce wrong results - query parallelising.
Could be some more reasons there too, that why OPTION (MAXDOP 1) may still not help...

I'm aware of only two ways of doing it safely with strings:
1. aggregate CLR function
2. using FOR XML PATH

_____________________________________________
"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
Alan.B
Alan.B
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13490 Visits: 8002
Here's another way... it's kind of a "Quirky-Coalesce":


-- sample data
DECLARE @Production_Product TABLE (name varchar(10));
INSERT INTO @Production_Product VALUES ('aaa'),('bbb'),('ccc'),('ccc');

DECLARE @listStr varchar(max)='';

SELECT @listStr=@listStr+
CASE
WHEN @listStr='' THEN ''+name
ELSE ','+name
END
FROM (SELECT DISTINCT name FROM @Production_Product) AS xxx

SELECT @listStr;
GO



This will produce the same query plan as the query that Chris put together but I also included a CASE statement that prevents a leading comma.

-- Alan Burstein



Best practices for getting help on SQLServerCentral
Need to split a string? Try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL 2012+)
Need a pattern-based splitter? Try PatternSplitCM
Need to remove or replace those unwanted characters? Try PatExclude8K and PatReplace8K.

"I can't stress enough the importance of switching from a 'sequential files' mindset to 'set-based' thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. " -- Itzek Ben-Gan 2001
Erland Sommarskog
Erland Sommarskog
SSCertifiable
SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)

Group: General Forum Members
Points: 5260 Visits: 875
SELECT substring(list, 1, len(list) - 1)
FROM (SELECT list =
(SELECT DISTINCT name + ','
FROM sys.objects
ORDER BY name + ','
FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)')) AS T



Yes, somewhat unwieldy and not fully intuitive. On the other hand, this is guaranteed to work as intended, which is not true for "SELECT @x = @x + col".

Erland Sommarskog, SQL Server MVP, www.sommarskog.se
Alan.B
Alan.B
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13490 Visits: 8002
Erland Sommarskog (7/24/2013)
SELECT substring(list, 1, len(list) - 1)
FROM (SELECT list =
(SELECT DISTINCT name + ','
FROM sys.objects
ORDER BY name + ','
FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)')) AS T



Yes, somewhat unwieldy and not fully intuitive. On the other hand, this is guaranteed to work as intended, which is not true for "SELECT @x = @x + col".



Why is the SELECT @x=@x+ method not guaranteed to work?

-- Alan Burstein



Best practices for getting help on SQLServerCentral
Need to split a string? Try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL 2012+)
Need a pattern-based splitter? Try PatternSplitCM
Need to remove or replace those unwanted characters? Try PatExclude8K and PatReplace8K.

"I can't stress enough the importance of switching from a 'sequential files' mindset to 'set-based' thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. " -- Itzek Ben-Gan 2001
Erland Sommarskog
Erland Sommarskog
SSCertifiable
SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)SSCertifiable (5.3K reputation)

Group: General Forum Members
Points: 5260 Visits: 875
Alan.B (7/24/2013)
Why is the SELECT
@x=@x+ method not guaranteed to work?


Why would it?

See this KB article Pay particular attention to the first sentence under Cause.

Erland Sommarskog, SQL Server MVP, www.sommarskog.se
Steven Willis
Steven Willis
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2059 Visits: 1721


;WITH SampleData (ID,Fruit)
AS
(
SELECT 1,'Apple' UNION ALL
SELECT 2,'Orange' UNION ALL
SELECT 3,'Pear' UNION ALL
SELECT 4,'Grape' UNION ALL
SELECT 3,'Pear' UNION ALL
SELECT 5,'Banana' UNION ALL
SELECT 6,'Lime'
)
SELECT
STUFF((SELECT DISTINCT ','+s.Fruit AS [text()]
FROM
SampleData AS s
FOR XML PATH('')
), 1, 1, '' )





 
Alan.B
Alan.B
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13490 Visits: 8002
Erland Sommarskog (7/24/2013)
Alan.B (7/24/2013)
Why is the SELECT
@x=@x+ method not guaranteed to work?


Why would it?

See this KB article Pay particular attention to the first sentence under Cause.


I say it would work based on the example I posted (which works). It produces the exact same plan and answer (except for the leading comma) as what Chris Posted which I believe is guaranteed to work. I need to read the article a little more (as well as this one) but I think it should work just fine.

The article you posted seems to imply that there is a problem applying expressions to members of the ORDER BY clause; I am not using an ORDER BY since the requirement does not call for it. From the article:

Under Symptoms (emph mine):
You may encounter unexpected results when you apply any operators or expressions to the ORDER BY clause of aggregate concatenation queries.

Under Cause:
The correct behavior for an aggregate concatenation query is undefined...
... When an expression is applied to a member of an ORDER BY clause, that resulting column is not exposed in the SELECT list, resulting in undefined behavior.

Under Work Around: (emph mine)
In order to achieve the expected results from an aggregate concatenation query, apply any Transact-SQL function or expression to the columns in the SELECT list rather than in the ORDER BY clause.

I could be wrong but I don't believe this article applies.

-- Alan Burstein



Best practices for getting help on SQLServerCentral
Need to split a string? Try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL 2012+)
Need a pattern-based splitter? Try PatternSplitCM
Need to remove or replace those unwanted characters? Try PatExclude8K and PatReplace8K.

"I can't stress enough the importance of switching from a 'sequential files' mindset to 'set-based' thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. " -- Itzek Ben-Gan 2001
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