order by alphanumeric value

  • 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?

  • Will this do

    select * from #temp order by case when isnumeric(response)=1 then convert(integer,response) else 99999999999 end,response



    Clear Sky SQL
    My Blog[/url]

  • Great!!

    This is what I required...

    Thanks

  • 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


    --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!

  • 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


    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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • 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


    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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • That's a very good catch.

    Thanks a lot!

  • Thanks for the feedback... heh... wish I caught it before the first time I got burned by it. 😛

    --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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 8 posts - 1 through 7 (of 7 total)

You must be logged in to reply to this topic. Login to reply