ORDER BY

The ORDER BY clause is an optional element of the following:

It can also be used in an  CREATE VIEW statement.

An ORDER BY clause allows you to specify the order in which rows appear in the result set. In subqueries, the ORDER BY clause is meaningless unless it is accompanied by one or both of the result offset and fetch first clauses or in conjunction with the ROW_NUMBER function, since there is no guarantee that the order is retained in the outer result set. It is permissible to combine ORDER BY on the outer query with ORDER BY in subqueries.

Syntax

ORDER BY { column-Name |
           ColumnPosition |
           Expression }
    [ ASC | DESC ]
    [ , column-Name | ColumnPosition | Expression
      [ ASC | DESC ]
      [ NULLS FIRST | NULLS LAST ]
    ]*

column-Name

A column name, as described in the SELECT statement. The column name(s) that you specify in the ORDER BY clause do not need to be the SELECT list.

ColumnPosition

An integer that identifies the number of the column in the SelectItems in the underlying query of the SELECT statement. ColumnPosition must be greater than 0 and not greater than the number of columns in the result table. In other words, if you want to order by a column, that column must be specified in the SELECT list.

Expression

A sort key expression, such as numeric, string, and datetime expressions. Expression can also be a row value expression such as a scalar subquery or case expression.

ASC

Specifies that the results should be returned in ascending order. If the order is not specified, ASC is the default.

DESC

Specifies that the results should be returned in descending order.

NULLS FIRST

Specifies that NULL values should be returned before non-NULL values. This is the default value for descending (DESC) order.

NULLS LAST

Specifies that NULL values should be returned after non-NULL values. This is the default value for ascending (ASC) order.

Using

If SELECT DISTINCT is specified or if the SELECT statement contains a GROUP BY clause, the ORDER BY columns must be in the SELECT list.

Example using a correlation name

You can sort the result set by a correlation name, if the correlation name is specified in the select list. For example, to return from the CITIES database all of the entries in the CITY_NAME and COUNTRY columns, where the COUNTRY column has the correlation name NATION, you specify this SELECT statement:

SELECT CITY_NAME, COUNTRY AS NATION
  FROM CITIES
  ORDER BY NATION;

Example using a numeric expression

You can sort the result set by a numeric expression, for example:

SELECT name, salary, bonus FROM employee
  ORDER BY salary+bonus;

In this example, the salary and bonus columns are DECIMAL data types.

Example using a function

You can sort the result set by invoking a function, for example:

SELECT i, len FROM measures
  ORDER BY sin(i);

Example of specifying a NULL ordering

You can sort the result set by invoking a function, for example:

SELECT * FROM Players
  ORDER BY BirthDate DESC NULLS LAST;

See Also