Login or Sign Up to become a member!
LessThanDot Site Logo

LessThanDot

Community Wiki

Less Than Dot is a community of passionate IT professionals and enthusiasts dedicated to sharing technical knowledge, experience, and assistance. Inside you will find reference materials, interesting technical discussions, and expert tips and commentary. Once you register for an account you will have immediate access to the forums and all past articles and commentaries.

LTD Social Sitings

Lessthandot twitter Lessthandot Linkedin Lessthandot facebook Lessthandot rss

Note: Watch for social icons on posts by your favorite authors to follow their postings on these and other social sites.

Navigation

Google Ads

Sort Values Ascending But NULLS Last

From Wiki

Jump to: navigation, search

You want to sort the column in ascending order but don't want the NULLS at the beginning. Oracle has this syntax: ORDER BY ColumnName NULLS LAST; SQL Server does not have this. But there are 2 ways to do this. The first one is by using case and the second one by using COALESCE and the maximum value for the data type in the order by clause.

The 2 approaches with a datetime data type

  1. DECLARE @Temp table(Col datetime)
  2.     INSERT INTO @Temp VALUES(getdate())
  3.     INSERT INTO @Temp VALUES('2007-10-19 09:54:03.730')
  4.     INSERT INTO @Temp VALUES('2006-10-19 09:54:03.730')
  5.     INSERT INTO @Temp VALUES('2005-10-19 09:54:03.730')
  6.     INSERT INTO @Temp VALUES('2006-10-19 09:54:03.730')
  7.     INSERT INTO @Temp VALUES('2004-10-19 09:54:03.730')
  8.     INSERT INTO @Temp VALUES(NULL)
  9.     INSERT INTO @Temp VALUES(NULL)
  10.  
  11.  
  12.     SELECT *
  13.     FROM @Temp
  14.     ORDER BY COALESCE(Col,'9999-12-31 23:59:59.997')
  15.  
  16.  
  17.     SELECT *
  18.     FROM @Temp
  19.     ORDER BY CASE WHEN Col Is NULL Then 1 Else 0 End, Col



The 2 approaches with an integer data type

  1. DECLARE @Temp table(Col int)
  2.     INSERT INTO @Temp VALUES(1)
  3.     INSERT INTO @Temp VALUES(555)
  4.     INSERT INTO @Temp VALUES(444)
  5.     INSERT INTO @Temp VALUES(333)
  6.     INSERT INTO @Temp VALUES(5656565)
  7.     INSERT INTO @Temp VALUES(3)
  8.     INSERT INTO @Temp VALUES(NULL)
  9.     INSERT INTO @Temp VALUES(NULL)
  10.  
  11.  
  12.     SELECT *
  13.     FROM @Temp
  14.     ORDER BY COALESCE(Col,2147483647)
  15.  
  16.  
  17.     SELECT *
  18.     FROM @Temp
  19.     ORDER BY CASE WHEN Col Is NULL Then 1 Else 0 End, Col


Contributed by: --SQLDenis 02:53, 31 May 2008 (GMT)

Part of SQL Server Programming Hacks

Section Handy tricks

176 Rating: 2.4/5 (67 votes cast)