| Author |
Topic |
|
choccy81
Starting Member
1 Post |
Posted - 2011-02-09 : 05:46:31
|
| Hi there - If anybody can help with this I'd really appreciate it.I have got a requirement on an ongoing basis to take comma separated values all stored in one database field and return a list of all possible distinct values from any of the values in that database field.Example:Row 1Computers/softw,EmployeeSupport,HealthSafety,HRSoftware,Incentives/Empl,KnowledgeMan,Legal/Insurance,Recruitment,SourceHRInfo,Training packag,TrainingProvideRow 2Computers/softw,EmployeeSupport,HealthSafety,HRSoftware,KnowledgeMan,Legal/Insurance,Recruitment,SourceHRInfo,TestingAssess,Training packag,TrainingProvideRow 3Computers/softw,EmployeeSupport,HealthSafety,HRSoftware,KnowledgeMan,No influence,Recruitment,SourceHRInfo,Training packag,TrainingProvideComputers/softw,HealthSafety,Incentives/Empl,KnowledgeMan,Legal/Insurance,Recruitment,SourceHRInfo,TestingAssess,Training packagRow 4Computers/softw,HRSoftware,Incentives/Empl,KnowledgeMan,Recruitment,SourceHRInfo,Training packagI need to output a distinct list of all values e.g. Computers/softwHRSoftwareIncentives/EmplKnowledgeMan......I was thinking I need to use dynamic sql maybe? But I'm lost...Any help anyone can offer?Ta. |
|
|
pk_bohra
Master Smack Fu Yak Hacker
1182 Posts |
Posted - 2011-02-09 : 06:52:40
|
| have a look at :http://www.sommarskog.se/arrays-in-sql-2005.html |
 |
|
|
Transact Charlie
Master Smack Fu Yak Hacker
3451 Posts |
Posted - 2011-02-09 : 09:18:57
|
OK -- Interesting question.Here's what I'd do initially. This uses a number table to split the strings (which I think is the fastest way to split them). There may be some clever optimisations you could do first.You could replace the DISTINCT with a GROUP BY if you also wanted to know how many of each part there are.This has a few 'deep' techniques in it so please ask questions!-- Numbers TableIF OBJECT_ID('tempdb..#numbers') IS NULLBEGIN CREATE TABLE #numbers ([n] INT PRIMARY KEY) -- Populate Number Table ; WITH naturals AS ( SELECT 1 AS [n] UNION ALL SELECT nats.[n] + 1 FROM naturals AS nats WHERE nats.[n] < 32767 ) INSERT #numbers (n) SELECT [n] FROM naturals OPTION (MAXRECURSION 0)ENDIF OBJECT_ID('tempdb..#splurge') IS NOT NULL DROP TABLE #splurgeCREATE TABLE #splurge ( [splurgeID] INT IDENTITY (1,1) , [splurge] VARCHAR(MAX) PRIMARY KEY CLUSTERED ( [splurgeID] ) )INSERT #splurge ([splurge]) SELECT 'Computers/softw,EmployeeSupport,HealthSafety,HRSoftware,Incentives/Empl,KnowledgeMan,Legal/Insurance,Recruitment,SourceHRInfo,Training packag,TrainingProvide'UNION SELECT 'Computers/softw,EmployeeSupport,HealthSafety,HRSoftware,KnowledgeMan,Legal/Insurance,Recruitment,SourceHRInfo,TestingAssess,Training packag,TrainingProvide'UNION SELECT 'Computers/softw,EmployeeSupport,HealthSafety,HRSoftware,KnowledgeMan,No influence,Recruitment,SourceHRInfo,Training packag,TrainingProvide'UNION SELECT 'Computers/softw,HealthSafety,Incentives/Empl,KnowledgeMan,Legal/Insurance,Recruitment,SourceHRInfo,TestingAssess,Training packag'UNION SELECT 'Computers/softw,HRSoftware,Incentives/Empl,KnowledgeMan,Recruitment,SourceHRInfo,Training packag'SELECT DISTINCT splitSplurge.[parts]FROM ( SELECT s.[splurgeId] AS [splurgeId] , split.[parts] AS [parts] FROM #splurge AS s CROSS APPLY ( SELECT SUBSTRING(',' + s.[splurge] + ',', num.[n] + 1, CHARINDEX(',', ',' + s.[splurge] + ',', num.[n] + 1) - num.[n] - 1) AS [Parts] FROM #numbers AS num WHERE SUBSTRING(',' + s.[splurge] + ',', num.[n], 1) = ',' AND num.[n] < LEN(',' + s.[splurge] + ',') ) AS split ) AS splitSplurgeCharlie===============================================================Msg 3903, Level 16, State 1, Line 1736The ROLLBACK TRANSACTION request has no corresponding BEGIN TRANSACTION |
 |
|
|
Transact Charlie
Master Smack Fu Yak Hacker
3451 Posts |
Posted - 2011-02-09 : 09:21:07
|
| Here's a good link which explains how to use a number table to do stuff that you would think you'd need a loop for.http://www.sqlservercentral.com/articles/T-SQL/62867/Charlie===============================================================Msg 3903, Level 16, State 1, Line 1736The ROLLBACK TRANSACTION request has no corresponding BEGIN TRANSACTION |
 |
|
|
|
|
|