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 12»»

SQL Distinct comma delimited list Expand / Collapse
Author
Message
Posted Wednesday, July 24, 2013 5:10 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Tuesday, September 30, 2014 5:18 AM
Points: 62, Visits: 84
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
Post #1476992
Posted Wednesday, July 24, 2013 5:15 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:55 AM
Points: 6,782, Visits: 13,988
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
Post #1476995
Posted Wednesday, July 24, 2013 7:40 AM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Thursday, October 16, 2014 6:17 AM
Points: 566, Visits: 259
Easiest way

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

SELECT @listStr

Post #1477061
Posted Wednesday, July 24, 2013 8:45 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 8:55 AM
Points: 2,873, Visits: 5,185
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!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1477106
Posted Wednesday, July 24, 2013 2:46 PM


SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Friday, October 17, 2014 7:06 AM
Points: 612, Visits: 2,853
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



Read this article for best practices on asking questions.
Need to split a string? Try this (Jeff Moden)
Need a pattern-based string spitter? Try this (Dwain Camps)

"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

My blog
Post #1477277
Posted Wednesday, July 24, 2013 3:37 PM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Saturday, October 11, 2014 11:41 AM
Points: 806, Visits: 723
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
Post #1477297
Posted Wednesday, July 24, 2013 3:57 PM


SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Friday, October 17, 2014 7:06 AM
Points: 612, Visits: 2,853
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



Read this article for best practices on asking questions.
Need to split a string? Try this (Jeff Moden)
Need a pattern-based string spitter? Try this (Dwain Camps)

"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

My blog
Post #1477308
Posted Wednesday, July 24, 2013 4:01 PM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Saturday, October 11, 2014 11:41 AM
Points: 806, Visits: 723
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
Post #1477309
Posted Wednesday, July 24, 2013 4:26 PM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Sunday, September 29, 2013 1:24 AM
Points: 429, Visits: 1,721

;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, '' )



 
Post #1477315
Posted Wednesday, July 24, 2013 4:38 PM


SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Friday, October 17, 2014 7:06 AM
Points: 612, Visits: 2,853
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



Read this article for best practices on asking questions.
Need to split a string? Try this (Jeff Moden)
Need a pattern-based string spitter? Try this (Dwain Camps)

"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

My blog
Post #1477316
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse