ORDER BY a specified sequence

I'm trying to create an SQL query with the IN clause where I give the IDs to match. Now I want the order of these records to be the same as I give in the IN clause. But it's not happening.

Hi. I'm trying to create an SQL query with the IN clause where I give the IDs to match:

select * from tblProject
where ProjectID in (3,1,2)

Now I want the order of these records to be the same as I give in the IN clause. But it's not happening. Can you please help me with this problem?

Obtaining a specific sort sequence based on a set of given values is easily accomplished with a CASE expression. The basic strategy is to "assign" specific sorting values to each row in the ORDER BY clause, based on the value of some column or columns in each row. Note that the value assigned is not actually in the row.

order 
    by case when projectid = 3 then 56
            when projectid = 1 then 57
            when projectid = 2 then 58
          else null end 

Let me make a few comments about this. First, the CASE expression will evaluate to either 56, 57, 58 (or NULL). These values were chosen simply to achieve a sequence. They could just as easily have been:

order 
    by case when projectid = 3 then 1
            when projectid = 1 then 2
            when projectid = 2 then 3
          else null end 

However, by assigning 1, 2, and 3 to 3, 1, and 2, many of you might have been hopelessly confused. The point is, the values that are assigned are not actually in the row, they are like a virtual column. Each row is "assigned" or "tagged with" the value of the CASE expression, which is calculated based on the value of the projectid column in that row. It doesn't matter that the CASE expression isn't actually part of the row, because you can still sort on it.

These values, 56, 57, 58 (or NULL), which were "assigned" to each row, could have been anything. Another example might be:

order 
    by case when projectid = 3 then 'Curly'
            when projectid = 1 then 'Larry
            when projectid = 2 then 'Moe'
          else null end 

This CASE expression works exactly the same way as the previous two. The row with ProjectID 3 will sort ahead of the row with ProjectID 1, which will sort ahead of the row with ProjectID 2.

So the basic strategy is to write a CASE expression in the ORDER BY clause to assign a value to each row which will result in that row being sorted into the desired sequence.

But what's with this ELSE NULL business? Well, that's just my way of ensuring data integrity. Since NULLs always sort first, we want any rows where ProjectID isn't 3, 1, or 2 to be at the top of the list. If there actually were such a row, it would obviously be a data integrity problem, and we would need to action it!

Actually, ELSE NULL is redundant. If the ELSE clause is missing from the CASE expression, NULL is assumed. But my coding style is to write it anyway. That makes it easy to go in and change it to 59 or 'Shemp' if I decide that rows where projectid isn't 3, 1, or 2 should sort last.

One final word. In MySQL, there's a lovely function called FIELD that can be used here. If you use MySQL, do look it up in the manual. Its elegance can be seen from this example:

select * 
  from tblproject
 where projectid in (3,1,2)
order 
    by field(projectid,3,1,2)

If you're constructing the SQL with a scripting language (e.g. PHP, ColdFusion), you can see immediately how this simplifies life greatly.

Dig Deeper on Oracle development languages