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

A simple T-SQL statement to create a list of lookup values Expand / Collapse
Author
Message
Posted Sunday, March 20, 2011 9:12 PM
SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Friday, September 7, 2012 2:35 PM
Points: 147, Visits: 46
Comments posted to this topic are about the item A simple T-SQL statement to create a list of lookup values
Post #1081065
Posted Sunday, March 20, 2011 9:14 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Sunday, October 19, 2014 3:52 PM
Points: 364, Visits: 385
You can use the following SQL to compose the comma-delimited string, without needed to trim the trailing comma at the end:

SELECT @MyStatusList = ISNULL(@MyStatusList + ',', '') + StatusDesc FROM (SELECT DISTINCT StatusDesc FROM MyStatus) x

Post #1081066
Posted Monday, March 21, 2011 12:54 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, March 21, 2011 4:48 AM
Points: 5, Visits: 22
It can be made simple with the following sql statement

SELECT REPLACE((SELECT DISTINCT RTRIM(LTRIM(StatusDesc)) AS 'data()'
FROM dbo.MyStatus
FOR XML PATH ( '' )), ' ', ', ')
Post #1081095
Posted Monday, March 21, 2011 1:08 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, December 13, 2012 6:19 AM
Points: 1, Visits: 42
Yo can also write example like this:

DECLARE @MyStatusList VARCHAR(1000)
SELECT @MyStatusList = COALESCE(@MyStatusList + ',', '') + StatusDesc FROM MyStatus
select @MyStatusList

Post #1081099
Posted Monday, March 21, 2011 3:07 AM
SSC Eights!

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

Group: General Forum Members
Last Login: Friday, October 3, 2014 9:25 AM
Points: 895, Visits: 2,432
Cursors in MS T-SQL should be avoided unless absolutely necessary as they are extremely slow and inefficent.

Using one of the methods mentioned in previous posts is a better and more efficent alternative to the method you mention, my personal preference is the XML conversion with a nested Replace.



_________________________________________________________________________
SSC Guide to Posting and Best Practices
Post #1081124
Posted Monday, March 21, 2011 3:15 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Sunday, October 19, 2014 2:24 AM
Points: 15, Visits: 77
In regards distinct values:

SELECT @s = ISNULL(@s+',','')+field FROM dbo.TABLE
GROUP BY field

works well too.
Post #1081128
Posted Monday, March 21, 2011 3:17 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Sunday, October 19, 2014 2:24 AM
Points: 15, Visits: 77
arty 15255 (3/21/2011)
In regards distinct values:

SELECT @s = ISNULL(@s+',','')+field FROM dbo.TABLE
GROUP BY field

works well too.


I forgot to mention that ORDER BY field works as well :)
Post #1081129
Posted Monday, March 21, 2011 3:22 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, March 5, 2014 5:49 AM
Points: 12, Visits: 45
Jason: May I ask for a a short example on how to do XML with nested replaces? I have no experience with XML in SQL. Okay. Found it, don't understand it though. 5 minutes later I understand it. A better solution because there's no record limit



Post #1081130
Posted Monday, March 21, 2011 3:25 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, March 5, 2014 5:49 AM
Points: 12, Visits: 45
Jason: May I ask for a a short example on how to do XML with nested replaces? I have no experience with XML in SQL. Okay. Found it, don't understand it though



Post #1081133
Posted Monday, March 21, 2011 3:40 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, October 21, 2014 9:32 AM
Points: 21, Visits: 449
Jason, the method described does not use a cursor. It is good to share the method in the article but it should be known and in use already which judging by posts it is. Comparing the execution plan for XML version and article version shows SQL handling the query in exactly the same way, so no benefit from using XML in this instance that I can see. Might be worthwhile exploring XML though if requirements were more complex.
Post #1081138
« Prev Topic | Next Topic »

Add to briefcase 12345»»»

Permissions Expand / Collapse