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


Custom order in SELECT


Custom order in SELECT

Author
Message
RZ52
RZ52
Valued Member
Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)

Group: General Forum Members
Points: 72 Visits: 74
Hi,

How could we change the order in SELECT command based on a custom semicolon delimited phrase.

We have :

[Letters]
----------
a
b
c
d
e

And based on this phrase 'd;c;b;a;e' we want to have :

[Letters]
----------
d
c
b
a
e


Thanks in advance for helps
Erin Ramsay
Erin Ramsay
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2161 Visits: 1119
Something like this maybe?

select letter from 
(select 'a' letter
union
select 'b' letter
union
select 'c' letter
union
select 'd' letter
union
select 'e' letter)source
order by (case letter when 'd' then 1 when 'c' then 2 when 'b' then 3 when 'a' then 4 when 'e' then 5 end)


RZ52
RZ52
Valued Member
Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)

Group: General Forum Members
Points: 72 Visits: 74
Erin Ramsay (3/1/2013)
Something like this maybe?

select letter from 
(select 'a' letter
union
select 'b' letter
union
select 'c' letter
union
select 'd' letter
union
select 'e' letter)source
order by (case letter when 'd' then 1 when 'c' then 2 when 'b' then 3 when 'a' then 4 when 'e' then 5 end)



Dear Erin,

Thanks for suggestion. I think I didn't explain well. what I'm looking for is to run a SELECT against a table based on custom phrase. I have a temp table named @TEST1 like :


DECLARE @TEST1 TABLE (letter varchar(1))
INSERT INTO @TEST1(letter) VALUES('a')
INSERT INTO @TEST1(letter) VALUES('b')
INSERT INTO @TEST1(letter) VALUES('c')
INSERT INTO @TEST1(letter) VALUES('d')
INSERT INTO @TEST1(letter) VALUES('e')



Now I need to "SELECT letter FROM @TEST1" based on order defined in this phrase 'd;c;b;a;e' to have a result like :

[Letters]
----------
d
c
b
a
e

Any idea ?

Thanks
Erin Ramsay
Erin Ramsay
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2161 Visits: 1119
If your custom phrase is static you can use:

select letter from @test1 order by (case letter when 'd' then 1 when 'c' then 2 when 'b' then 3 when 'a' then 4    when 'e' then 5 end)


RZ52
RZ52
Valued Member
Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)

Group: General Forum Members
Points: 72 Visits: 74
Erin Ramsay (3/1/2013)
If your custom phrase is static you can use:

select letter from @test1 order by (case letter when 'd' then 1 when 'c' then 2 when 'b' then 3 when 'a' then 4    when 'e' then 5 end)



Dear Erin,

Thanks, you solved my problem.


Regards.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: General Forum Members
Points: 62963 Visits: 17959
To do this you will first need to parse your delimited string. The easiest way to parse a delimited string like is to use DelimitedSplit8K. You can find out about this splitter by following the article in my signature about splitting strings.

In this case we need to split the string and keep them in order. Here is where we can really harness the power of the DelimitedSplit8K function. The following code should work for you.


DECLARE @TEST1 TABLE (letter varchar(1))
INSERT INTO @TEST1(letter) VALUES('a')
INSERT INTO @TEST1(letter) VALUES('b')
INSERT INTO @TEST1(letter) VALUES('c')
INSERT INTO @TEST1(letter) VALUES('d')
INSERT INTO @TEST1(letter) VALUES('e')

declare @SortString varchar(10) = 'd;c;b;a;e'

select *
from @Test1 t
join
(
select ItemNumber, Item
from dbo.DelimitedSplit8K(@SortString, ';')
) x on t.letter = x.Item
order by x.ItemNumber



Make sure you read that article and understand what it is doing.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Lowell
Lowell
SSC Guru
SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)

Group: General Forum Members
Points: 72316 Visits: 40942
ok i just tested this, but i made some assumptions;
when you say "
I THINK you are saying "If I pass this string 'd;c;b;a;e', i want the companies ordered in that order, instead of normal alphabetical order"

If I read that right, then this works correctly. my example is using sys.objects as sample data. so you see Defaults, then check constraints, then foreign keys in that order, for example:

oh yeah, like many good solutions, you need the DelimitedSplit8K function:
http://www.sqlservercentral.com/articles/Tally+Table/72993/


select * from sys.objects
OUTER apply master.dbo.delimitedsplit8k('d;c;b;a;e',';') myfn
ORDER BY CASE WHEN LEFT(name,1) = myfn.Item THEN 1 ELSE 2 END,myfn.ItemNumber




Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
Sean Lange
Sean Lange
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: General Forum Members
Points: 62963 Visits: 17959
Lowell, you would have to add a where clause to only return those rows that match. Notice below this will return a cartesian product.


select *
from @Test1 t
OUTER apply dbo.delimitedsplit8k('d;c;b;a;e',';') myfn
ORDER BY CASE WHEN LEFT(letter,1) = myfn.Item THEN 1 ELSE 2 END,myfn.ItemNumber



The top 5 rows are sorted perfectly but it returned 25 rows instead of 5.

Add the where clause and it works correctly.


select *
from @Test1 t
OUTER apply dbo.delimitedsplit8k('d;c;b;a;e',';') myfn
where t.letter = myfn.Item
ORDER BY CASE WHEN LEFT(letter,1) = myfn.Item THEN 1 ELSE 2 END,myfn.ItemNumber



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
RZ52
RZ52
Valued Member
Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)

Group: General Forum Members
Points: 72 Visits: 74
Sean Lange (3/1/2013)
Lowell, you would have to add a where clause to only return those rows that match. Notice below this will return a cartesian product.


select *
from @Test1 t
OUTER apply dbo.delimitedsplit8k('d;c;b;a;e',';') myfn
ORDER BY CASE WHEN LEFT(letter,1) = myfn.Item THEN 1 ELSE 2 END,myfn.ItemNumber



The top 5 rows are sorted perfectly but it returned 25 rows instead of 5.

Add the where clause and it works correctly.


select *
from @Test1 t
OUTER apply dbo.delimitedsplit8k('d;c;b;a;e',';') myfn
where t.letter = myfn.Item
ORDER BY CASE WHEN LEFT(letter,1) = myfn.Item THEN 1 ELSE 2 END,myfn.ItemNumber



Dear Sean,

The proposed command works well. However, if we have repeated value of same letter like :


DECLARE @TEST1 TABLE (letter varchar(1))
INSERT INTO @TEST1(letter) VALUES('a')
INSERT INTO @TEST1(letter) VALUES('b')
INSERT INTO @TEST1(letter) VALUES('c')
INSERT INTO @TEST1(letter) VALUES('d')
INSERT INTO @TEST1(letter) VALUES('a')
INSERT INTO @TEST1(letter) VALUES('a')
INSERT INTO @TEST1(letter) VALUES('d')
INSERT INTO @TEST1(letter) VALUES('d')



running the command


select letter
from @Test1 t
OUTER apply dbo.delimitedsplit8k('d;c;b;a;e',';') myfn
where t.letter = myfn.Item
ORDER BY CASE WHEN LEFT(letter,1) = myfn.Item THEN 1 ELSE 2 END,myfn.ItemNumber



will return all rows. I tried to add SELECT DISTINCT to above command :


Select Distinct Letter from
(select letter
from @Test1 t
OUTER apply dbo.delimitedsplit8k('d;c;b;a;e',';') myfn
where t.letter = myfn.Item
ORDER BY CASE WHEN LEFT(letter,1) = myfn.Item THEN 1 ELSE 2 END,myfn.ItemNumber) xx



But it raise the error :


Msg 1033, Level 15, State 1, Line 16
The ORDER BY clause is invalid in views, inline functions, derived tables, subqueries, and common table expressions, unless TOP or FOR XML is also specified.


How could I manage to avoid repeated values ?

Thanks
dwain.c
dwain.c
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17929 Visits: 6431
Try it like this:


DECLARE @TEST1 TABLE (letter varchar(1))
INSERT INTO @TEST1(letter) VALUES('a')
INSERT INTO @TEST1(letter) VALUES('b')
INSERT INTO @TEST1(letter) VALUES('c')
INSERT INTO @TEST1(letter) VALUES('d')
INSERT INTO @TEST1(letter) VALUES('a')
INSERT INTO @TEST1(letter) VALUES('a')
INSERT INTO @TEST1(letter) VALUES('d')
INSERT INTO @TEST1(letter) VALUES('d')

;WITH CTE AS (SELECT DISTINCT letter FROM @Test1)
select letter
from CTE t
OUTER apply dbo.delimitedsplit8k('d;c;b;a;e',';') myfn
where t.letter = myfn.Item
ORDER BY CASE WHEN LEFT(letter,1) = myfn.Item THEN 1 ELSE 2 END,myfn.ItemNumber





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
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