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


Sort comma separated value in SQL Table


Sort comma separated value in SQL Table

Author
Message
PSB
PSB
SSChampion
SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)

Group: General Forum Members
Points: 11106 Visits: 1720
Hi

I want to sort a column value alphabetically which is already in a sql table to something like below :

Tamesha Rios, Damian Richard, Tim David --> to Damien Richard, Tamesha Rios, Tim David

Thanks,
PSB
Thom A
Thom A
SSC Guru
SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)

Group: General Forum Members
Points: 78359 Visits: 19906
As you're using SQL Server 2016 and ordinal position doesn't matter, have a look at STRING_SPLIT() (Transact-SQL). Then, have a look at how to create a delimited string using T-SQL; there are literally 1,000's of answer out there if you use Google. Post what you've tried if you get stuck, and we'll be happy to nudge you in the right direction.

Ideally, however, don't store your values as a delimited string in SQL Server; store each item in it's own row.


Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

Please always remember to encapsulate your code in IFCode Markup. For example [code=sql] [/code].
Click here to read Jeffs Guide on how to post SQL questions, and get swift and helpful answers from the community
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)

Group: General Forum Members
Points: 848197 Visits: 46691
The question now is, especially since you posted in a 2016 forum, are you actually using SQL Server 2016?

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Thom A
Thom A
SSC Guru
SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)

Group: General Forum Members
Points: 78359 Visits: 19906
Jeff Moden - Thursday, February 1, 2018 5:00 PM
The question now is, especially since you posted in a 2016 forum, are you actually using SQL Server 2016?

One would hope.



Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

Please always remember to encapsulate your code in IFCode Markup. For example [code=sql] [/code].
Click here to read Jeffs Guide on how to post SQL questions, and get swift and helpful answers from the community
Subramaniam Chandrasekar
Subramaniam Chandrasekar
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3346 Visits: 531
PSB - Thursday, February 1, 2018 9:48 AM
Hi

I want to sort a column value alphabetically which is already in a sql table to something like below :

Tamesha Rios, Damian Richard, Tim David --> to Damien Richard, Tamesha Rios, Tim David

Thanks,
PSB

I've created a test table and small static script which produces your desired output,


SELECT * INTO #TestTable FROM (VALUES
('Tamesha Rios,Damian Richard,Tim David')
)v(CSVField);


SELECT CSVField, PARSENAME(REPLACE(CSVField,',','.'),2) + ',' + PARSENAME(REPLACE(CSVField,',','.'),3) + ',' + PARSENAME(REPLACE(CSVField,',','.'),1) 'Name' FROM #TestTable


For realtime dynamic conversion, you'd need to create an user defined function which does the same. Please keep an eye on the performance of your function as well while executing....

Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)

Group: General Forum Members
Points: 848197 Visits: 46691
subramaniam.chandrasekar - Tuesday, February 6, 2018 12:34 AM
PSB - Thursday, February 1, 2018 9:48 AM
Hi

I want to sort a column value alphabetically which is already in a sql table to something like below :

Tamesha Rios, Damian Richard, Tim David --> to Damien Richard, Tamesha Rios, Tim David

Thanks,
PSB

I've created a test table and small static script which produces your desired output,


SELECT * INTO #TestTable FROM (VALUES
('Tamesha Rios,Damian Richard,Tim David')
)v(CSVField);


SELECT CSVField, PARSENAME(REPLACE(CSVField,',','.'),2) + ',' + PARSENAME(REPLACE(CSVField,',','.'),3) + ',' + PARSENAME(REPLACE(CSVField,',','.'),1) 'Name' FROM #TestTable


For realtime dynamic conversion, you'd need to create an user defined function which does the same. Please keep an eye on the performance of your function as well while executing....


That's nice but it will fail if there are more than 4 names.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)

Group: General Forum Members
Points: 848197 Visits: 46691
@PSB,

Where you able to solve your problem from what has been posted so far? Even if you have, you might want to post what you've come up with because, as subramaniam.chandrasekar posted, there can be some pretty severe performance problems with these types of things and we can help.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Jason A. Long
Jason A. Long
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18484 Visits: 7170
Looks like the OP has bailed on this thread but it's still an interesting request from a SQL Server versioning point of view (IMO), due to new functions that have been added in the last two releases.

Below are 3 different possible solutions that will work, depending on what version of SQL Server you're using...

IF OBJECT_ID('tempdb..#Test Data', 'U') IS NOT NULL 
DROP TABLE #TestData;

CREATE TABLE #TestData (
fk_id INT NOT NULL IDENTITY(1,1),
FullNameCSV VARCHAR(8000) NOT NULL
);
INSERT #TestData (FullNameCSV) VALUES
('Tamesha Rios, Damian Richard, Tim David'),
('Jeff Moden, Thom A, PSB, Jason Long');

--================================================================================================

--------------------------------------------------------------------------------------------------
-- SS 2008 & after
SELECT
td.fk_id,
FullNameCSV_Ordered = STUFF(fco.FullNameCSV_Ordered, 1, 2, '')
FROM
#TestData td
CROSS APPLY (
SELECT
', ' + LTRIM(ds.Item)
FROM
dbo.DelimitedSplit8K(td.FullNameCSV, ',') ds --<< http://www.sqlservercentral.com/articles/Tally+Table/72993/
ORDER BY
LTRIM(ds.Item)
FOR XML PATH('')
) fco (FullNameCSV_Ordered)
GROUP BY
td.fk_id,
fco.FullNameCSV_Ordered;

--------------------------------------------------------------------------------------------------
-- SS 2016 & after
SELECT
td.fk_id,
FullNameCSV_Ordered = STUFF(fco.FullNameCSV_Ordered, 1, 2, '')
FROM
#TestData td
CROSS APPLY (
SELECT
', ' + LTRIM(ss.value)
FROM
STRING_SPLIT(td.FullNameCSV, ',') ss --<< STRING_SPLIT() became available in 2016
ORDER BY
LTRIM(ss.value)
FOR XML PATH('')
) fco (FullNameCSV_Ordered)
GROUP BY
td.fk_id,
fco.FullNameCSV_Ordered;

--------------------------------------------------------------------------------------------------
-- SS 2017
SELECT
td.fk_id,
FullNameCSV_Ordered = STRING_AGG(LTRIM(ss.value), ', ') WITHIN GROUP (ORDER BY LTRIM(ss.value)) --<< STRING_AGG() became available in 2017
FROM
#TestData td
CROSS APPLY STRING_SPLIT(td.FullNameCSV, ',') ss
GROUP BY
td.fk_id;

Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)SSC Guru (848K reputation)

Group: General Forum Members
Points: 848197 Visits: 46691
Jason A. Long - Tuesday, February 6, 2018 8:55 AM
Looks like the OP has bailed on this thread but it's still an interesting request from a SQL Server versioning point of view (IMO), due to new functions that have been added in the last two releases.

Below are 3 different possible solutions that will work, depending on what version of SQL Server you're using...

IF OBJECT_ID('tempdb..#Test Data', 'U') IS NOT NULL 
DROP TABLE #TestData;

CREATE TABLE #TestData (
fk_id INT NOT NULL IDENTITY(1,1),
FullNameCSV VARCHAR(8000) NOT NULL
);
INSERT #TestData (FullNameCSV) VALUES
('Tamesha Rios, Damian Richard, Tim David'),
('Jeff Moden, Thom A, PSB, Jason Long');

--================================================================================================

--------------------------------------------------------------------------------------------------
-- SS 2008 & after
SELECT
td.fk_id,
FullNameCSV_Ordered = STUFF(fco.FullNameCSV_Ordered, 1, 2, '')
FROM
#TestData td
CROSS APPLY (
SELECT
', ' + LTRIM(ds.Item)
FROM
dbo.DelimitedSplit8K(td.FullNameCSV, ',') ds --<< http://www.sqlservercentral.com/articles/Tally+Table/72993/
ORDER BY
LTRIM(ds.Item)
FOR XML PATH('')
) fco (FullNameCSV_Ordered)
GROUP BY
td.fk_id,
fco.FullNameCSV_Ordered;

--------------------------------------------------------------------------------------------------
-- SS 2016 & after
SELECT
td.fk_id,
FullNameCSV_Ordered = STUFF(fco.FullNameCSV_Ordered, 1, 2, '')
FROM
#TestData td
CROSS APPLY (
SELECT
', ' + LTRIM(ss.value)
FROM
STRING_SPLIT(td.FullNameCSV, ',') ss --<< STRING_SPLIT() became available in 2016
ORDER BY
LTRIM(ss.value)
FOR XML PATH('')
) fco (FullNameCSV_Ordered)
GROUP BY
td.fk_id,
fco.FullNameCSV_Ordered;

--------------------------------------------------------------------------------------------------
-- SS 2017
SELECT
td.fk_id,
FullNameCSV_Ordered = STRING_AGG(LTRIM(ss.value), ', ') WITHIN GROUP (ORDER BY LTRIM(ss.value)) --<< STRING_AGG() became available in 2017
FROM
#TestData td
CROSS APPLY STRING_SPLIT(td.FullNameCSV, ',') ss
GROUP BY
td.fk_id;


Very cool summary.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
jonathan.crawford
jonathan.crawford
SSCarpal Tunnel
SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)

Group: General Forum Members
Points: 4046 Visits: 1028
your DROP TABLE statement has an extra space, here's the corrected version, and I added in one in the 2008 & After section if you wanted to order by lastname instead of firstname (didn't modify the others because I'm stuck in 2014 at the moment) :


IF OBJECT_ID('tempdb..#TestData', 'U') IS NOT NULL 
DROP TABLE #TestData;

CREATE TABLE #TestData (
fk_id INT NOT NULL IDENTITY(1,1),
FullNameCSV VARCHAR(8000) NOT NULL
);
INSERT #TestData (FullNameCSV) VALUES
('Tamesha Rios, Damian Richard, Tim David'),
('Jeff Moden, Thom A, PSB, Jason Long');

--================================================================================================

--------------------------------------------------------------------------------------------------
-- SS 2008 & after
SELECT
td.fk_id,
FullNameCSV_Ordered = STUFF(fco.FullNameCSV_Ordered, 1, 2, '')
FROM
#TestData td
CROSS APPLY (
SELECT
', ' + LTRIM(ds.Item)
FROM
dbo.DelimitedSplit8K(td.FullNameCSV, ',') ds --<< http://www.sqlservercentral.com/articles/Tally+Table/72993/
ORDER BY
LTRIM(ds.Item)
FOR XML PATH('')
) fco (FullNameCSV_Ordered)
GROUP BY
td.fk_id,
fco.FullNameCSV_Ordered;

--------------------------------------------------------------------------------------------------
-- SS 2008 & after - Lastname first
SELECT
td.fk_id,
FullNameCSV_Ordered = STUFF(fco.FullNameCSV_Ordered, 1, 2, '')
FROM
#TestData td
CROSS APPLY (
SELECT
', ' + substring(LTRIM(ds.Item),charindex(' ',LTRIM(ds.Item))+1,len(ds.Item)) + ', '+ substring(Ltrim(ds.Item),1,charindex(' ',Ltrim(ds.Item)))
FROM
dbo.DelimitedSplit8K(td.FullNameCSV, ',') ds --<< http://www.sqlservercentral.com/articles/Tally+Table/72993/
ORDER BY
--LTRIM(ds.Item)
', ' + substring(LTRIM(ds.Item),charindex(' ',LTRIM(ds.Item))+1,len(ds.Item)) + ', '+ substring(Ltrim(ds.Item),1,charindex(' ',Ltrim(ds.Item)))
FOR XML PATH('')
) fco (FullNameCSV_Ordered)
GROUP BY
td.fk_id,
fco.FullNameCSV_Ordered;
--------------------------------------------------------------------------------------------------
-- SS 2016 & after
SELECT
td.fk_id,
FullNameCSV_Ordered = STUFF(fco.FullNameCSV_Ordered, 1, 2, '')
FROM
#TestData td
CROSS APPLY (
SELECT
', ' + LTRIM(ss.value)
FROM
STRING_SPLIT(td.FullNameCSV, ',') ss --<< STRING_SPLIT() became available in 2016
ORDER BY
LTRIM(ss.value)
FOR XML PATH('')
) fco (FullNameCSV_Ordered)
GROUP BY
td.fk_id,
fco.FullNameCSV_Ordered;

--------------------------------------------------------------------------------------------------
-- SS 2017
SELECT
td.fk_id,
FullNameCSV_Ordered = STRING_AGG(LTRIM(ss.value), ', ') WITHIN GROUP (ORDER BY LTRIM(ss.value)) --<< STRING_AGG() became available in 2017
FROM
#TestData td
CROSS APPLY STRING_SPLIT(td.FullNameCSV, ',') ss
GROUP BY
td.fk_id;


-------------------------------------------------------------------------------------------------------------------------------------
Please follow Best Practices For Posting On Forums to receive quicker and higher quality responses
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