Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

ORDER BY non-sequential number sequence Expand / Collapse
Author
Message
Posted Saturday, January 12, 2013 4:34 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, January 15, 2013 10:15 AM
Points: 5, Visits: 7
I have a table where a certain column contains a status id as an integer. I want to sort on this field, but I want to sort in a specific order. Ie, instead of 1,2,3,4,5 I want the order returning as 3,2,4,5,1. That is, all records with statusid 3 first, then 2, etc.

The only way I can think of is something like this:

SELECT ... FROM ... WHERE ... ORDER BY CASE WHEN statusId = 3 THEN 0 WHEN stautsId = 2 THEN 1 ... ETC ...

But I'm wondering if there's another way thats more readable that I've overlooked. I really don't want to do multiple DB hits unless its going to be quicker (queries done via php).
Post #1406421
Posted Saturday, January 12, 2013 4:38 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 9:18 AM
Points: 1,780, Visits: 5,646
Another way...

ORDER BY CHARINDEX(statusId,'32451')


MM


  • MMGrid Addin
  • MMNose Addin


  • Forum Etiquette: How to post Reporting Services problems
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • How to Post Performance Problems - by Gail Shaw

  • Post #1406422
    Posted Saturday, January 12, 2013 5:04 PM
    Forum Newbie

    Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

    Group: General Forum Members
    Last Login: Tuesday, January 15, 2013 10:15 AM
    Points: 5, Visits: 7
    Thanks, that looks great. However, the number can become 2 decimal places, so I thought something like:

    select ('S'+CAST ([statusId] AS VARCHAR(255))) as sid from tbl_xenix
    order by CHARINDEX(sid,'S5S4')

    but it says 'sid' is an invalid column, despite the fact its in the column header if I miss out the 'order by' !

    Any clues?
    Post #1406429
    Posted Sunday, January 13, 2013 1:39 AM
    Ten Centuries

    Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

    Group: General Forum Members
    Last Login: Today @ 6:08 AM
    Points: 1,072, Visits: 6,333
    select x.NewSid, sid
    from tbl_xenix
    CROSS APPLY (SELECT NewSid = ('S'+CAST ([statusId] AS VARCHAR(255)))) x
    order by CHARINDEX(x.NewSid,'S5S4')




    Low-hanging fruit picker and defender of the moggies





    For better assistance in answering your questions, please read this.




    Understanding and using APPLY, (I) and (II) Paul White

    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
    Post #1406457
    Posted Sunday, January 13, 2013 2:46 AM
    SSC-Enthusiastic

    SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

    Group: General Forum Members
    Last Login: Friday, July 11, 2014 1:53 AM
    Points: 194, Visits: 716
    You should do it another way. When normalizing the database there should be a table containg all available statusids. Your data table should then have a foreignn key to the statusid-table. When doing so you can add a column to the statusid-table where you define the sort order.

    Something like this:
    create table dbo.domStatus(
    StatusId int not null,
    SortOrder int not null
    primary key ( StatusId )
    );
    create table dbo.SomeDataTable(
    Col1 varchar(50),
    Col2 varchar(50),
    StatusId int not null
    );
    alter table dbo.SomeDataTable add constraint fk_SomeDataTable_domStatus
    foreign key ( StatusId ) references dbo.domStatus ( StatusId );

    select ...
    from dbo.SomeDataTable d inner join
    dbo.domStatus s on
    s.StatusId = d.StatusId
    ORDER BY s.SortOrder


    Post #1406459
    Posted Sunday, January 13, 2013 11:06 AM
    Forum Newbie

    Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

    Group: General Forum Members
    Last Login: Tuesday, January 15, 2013 10:15 AM
    Points: 5, Visits: 7
    Thanks, I actually do have such a table (it translates status id to name and description), so its pretty easy to just add another column with the sort order. Thanks for that, it completely slipped my mind to do it like that.

    Actually, I have several web pages, and currently the list of ids for each page is in the PHP file. I think I'll move it into the DB, it'll make it easier to change.

    I wish there was a way of thanking/voting users on this forum.
    Post #1406497
    Posted Sunday, January 13, 2013 12:04 PM


    SSC-Insane

    SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

    Group: General Forum Members
    Last Login: Today @ 10:20 AM
    Points: 22,994, Visits: 31,476
    steve 50602 (1/13/2013)
    Thanks, I actually do have such a table (it translates status id to name and description), so its pretty easy to just add another column with the sort order. Thanks for that, it completely slipped my mind to do it like that.

    Actually, I have several web pages, and currently the list of ids for each page is in the PHP file. I think I'll move it into the DB, it'll make it easier to change.

    I wish there was a way of thanking/voting users on this forum.



    I wish there was a way of thanking/voting users on this forum. << You just did.



    Lynn Pettis

    For better assistance in answering your questions, click here
    For tips to get better help with Performance Problems, click here
    For Running Totals and its variations, click here or when working with partitioned tables
    For more about Tally Tables, click here
    For more about Cross Tabs and Pivots, click here and here
    Managing Transaction Logs

    SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
    Post #1406499
    Posted Sunday, January 13, 2013 3:39 PM


    SSCommitted

    SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

    Group: General Forum Members
    Last Login: Today @ 9:18 AM
    Points: 1,780, Visits: 5,646
    WolfgangE (1/13/2013)
    You should do it another way. When normalizing the database there should be a table containg all available statusids. Your data table should then have a foreignn key to the statusid-table. When doing so you can add a column to the statusid-table where you define the sort order.

    Something like this:
    create table dbo.domStatus(
    StatusId int not null,
    SortOrder int not null
    primary key ( StatusId )
    );
    create table dbo.SomeDataTable(
    Col1 varchar(50),
    Col2 varchar(50),
    StatusId int not null
    );
    alter table dbo.SomeDataTable add constraint fk_SomeDataTable_domStatus
    foreign key ( StatusId ) references dbo.domStatus ( StatusId );

    select ...
    from dbo.SomeDataTable d inner join
    dbo.domStatus s on
    s.StatusId = d.StatusId
    ORDER BY s.SortOrder




    While that may be a good idea for any incredibly simple system, what do you do when you want to order things differently?
    Add more columns to the domStatus table? No thanks.

    What about when you want the end user to choose a sort order? Add all possible combinations to your domStatus table? No thanks.

    There are times when IMHO you can take "Normalisation" too far and this may be one of them, don't you think? Unless you can definitely say that anything with a status will always need to be ORDERED exactly the same way, I would steer clear of putting that sort of metadata into the database design.

    If you use something simple like the CHARINDEX example, you can provide flexibility at very little cost to design.

    But this is just my opinion and I do appreciate the alternative view put forward by Wolfgang


    MM


  • MMGrid Addin
  • MMNose Addin


  • Forum Etiquette: How to post Reporting Services problems
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • How to Post Performance Problems - by Gail Shaw

  • Post #1406521
    Posted Sunday, January 13, 2013 4:08 PM
    Forum Newbie

    Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

    Group: General Forum Members
    Last Login: Tuesday, January 15, 2013 10:15 AM
    Points: 5, Visits: 7
    I completely agree with you, but in this case, the sort order will not be changeable by the user (ever), and there will only ever be one sort order. If the order is ever requested to be changed, then its a simple method of updating a table rather than digging around in the PHP code.

    If I wanted the sort order changeable via the website, then I would definitely use something like CHARINDEX, as it seems a pretty flexible solution. I'd probably just put the concatenation and CAST inside the CHARINDEX function, rather than using a CROSS APPLY.
    Post #1406525
    Posted Monday, January 14, 2013 12:43 AM
    SSC-Enthusiastic

    SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

    Group: General Forum Members
    Last Login: Friday, July 11, 2014 1:53 AM
    Points: 194, Visits: 716
    I cannot agree to that and in my opinion there is just one correct answer to this: it depends!

    What do you call an "incredibly simple system"? How do you call other systems? And how do know all the background about the one requirment of some special sorting?

    The way I have shown works perfekt for some requirements, e.g. sorting the items for cash desk accountings in meaningful way that is standard for all 400 shops.
    On the other hand I have never seen a website where a user can define how single values have to be sorted. I only have seen the possibility of giving a column name for sorting, ascending or descending.

    The disadvantages using the cross-apply-method I see are performance and maintenance:
    If the number of rows of the outer select increases the query will slow down as the apply-operator does the subselect for any outer row.
    And what do you do when you have to change the sort logic or if there is a new statusid? In how many procedures will you have to change your code? Will you even find them all? A simple update of 1 table with a column for sort order seems to be much better.

    But as I said: it depends.

    Giving the user the possibility to choose a column for sorting or even let him decide, which values within a column are sorted as the user wants might be difficult. I wonder if this would even be part of the database procedure at all. On huge systems there might be thougts like "how many execution plan for one query do I want in my procedure cache?" or "will my execution plans be cached and reused?" Maybe it's more efficient doing the query without sorting on database level and sort the data in the frontend-programming.

    Yes, there are many aspects. Depending on the background of the requirement you will have to find an appropriate solution.
    Post #1406580
    « Prev Topic | Next Topic »

    Add to briefcase 12»»

    Permissions Expand / Collapse