July 21, 2009 at 5:41 am
Hi All,
I am working on reporting module where I need to order by the alphanumeric values.
Example:
create table #temp
(
Response varchar(500)
);
insert into #temp values(0)
insert into #temp values(1)
insert into #temp values(2)
insert into #temp values(10)
insert into #temp values(3)
insert into #temp values('ABC')
select response from #temp order by ascii(response) asc;
Output:
0
1
10
2
3
ABC
Expected output:
0
1
2
3
10
ABC
Ascii value for 10 and 1 is same that's why I am not getting the expected result.
Is there any way to resolve this?
July 21, 2009 at 5:44 am
Will this do
select * from #temp order by case when isnumeric(response)=1 then convert(integer,response) else 99999999999 end,response
July 21, 2009 at 5:58 am
Great!!
This is what I required...
Thanks
July 21, 2009 at 6:03 am
another way to do the same thing is to order by the length, then by the column:
select * from #temp order by len(Response),response
...well not the same thing, but similar...with the example data set it's the same results, but if there was a single character 'Z' in the table, the numbers would not be in order any more. it depends on what youy are after, i guess.
Lowell
July 21, 2009 at 6:42 pm
keerthy.vishweshwarachar (7/21/2009)
Great!!This is what I required...
Thanks
Ummm... be careful... try it with the value like '1e2'. Never use "IsNumeric" as an "IsAllDigits" function because it's not. 😉
--Jeff Moden
Change is inevitable... Change for the better is not.
July 21, 2009 at 7:32 pm
Using code very similar to Dave's otherwise great example, try this...
create table #temp
(
Response varchar(500)
);
insert into #temp values(0)
insert into #temp values(1)
insert into #temp values(2)
insert into #temp values(10)
insert into #temp values(3)
insert into #temp values('ABC')
insert into #temp values('AB')
insert into #temp values('A')
insert into #temp values('1EA')
insert into #temp values('1E2')
SELECT * FROM #temp ORDER BY CASE WHEN Response LIKE '%[^0-9]%' THEN 99999999999 ELSE CONVERT(INTEGER,Response) END, Response
--Jeff Moden
Change is inevitable... Change for the better is not.
July 22, 2009 at 4:18 am
That's a very good catch.
Thanks a lot!
July 22, 2009 at 6:09 am
Thanks for the feedback... heh... wish I caught it before the first time I got burned by it. 😛
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply