March 1, 2013 at 2:26 pm
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
March 1, 2013 at 2:32 pm
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 1when 'c' then 2 when 'b' then 3 when 'a' then 4 when 'e' then 5 end)
March 1, 2013 at 2:45 pm
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 1when '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
March 1, 2013 at 3:14 pm
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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
March 1, 2013 at 3:16 pm
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
March 1, 2013 at 3:25 pm
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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
March 1, 2013 at 4:03 pm
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
March 4, 2013 at 1:48 am
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 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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply