Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2012 Forums
 Transact-SQL (2012)
 Unable to sort a date column correctley

Author  Topic 

emyk
Yak Posting Veteran

57 Posts

Posted - 2013-11-07 : 11:26:36
I am unable to sort a date column (VARCHAR TYPE column) correctley.
The DATE column has dates entry with yyyy/mm/dd hh:mm and yyyy-mm-dd hh:mm format. So I am trying to cleanup the format so that I can do an order by DESC. Any suggestion?

11/07/2013 10:28:14
11/07/2013 10:30:03
11/07/2013 10:47:57
2013-04-21 12:55
2013-04-21 13:00
2013-07-25 00:30
2013-07-25 00:30
2013-07-25 00:30


visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-11-07 : 11:49:34
why not just keep them as dates itself and then sort?
or if you cant change column datatype do casting and order by it.

Make sure you read this
http://visakhm.blogspot.in/2011/12/why-iso-format-is-recommended-while.html

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

sz1
Aged Yak Warrior

555 Posts

Posted - 2013-11-13 : 06:46:30
Select Convert(Varchar(10), YourDate,112) as MyDate
From MyTable
Order By MyDate DESC

To Include time part use 113

SZ1
Please help me to enable me to help others!
Go to Top of Page

Jeff Moden
Aged Yak Warrior

652 Posts

Posted - 2013-11-23 : 14:00:01
quote:
Originally posted by emyk

I am unable to sort a date column (VARCHAR TYPE column) correctley.
The DATE column has dates entry with yyyy/mm/dd hh:mm and yyyy-mm-dd hh:mm format. So I am trying to cleanup the format so that I can do an order by DESC. Any suggestion?
11/07/2013 10:28:14
11/07/2013 10:30:03
11/07/2013 10:47:57
2013-04-21 12:55
2013-04-21 13:00
2013-07-25 00:30
2013-07-25 00:30
2013-07-25 00:30

As has been suggested or implied by the others, you should never store dates or times, properly formatted or not, in a VARCHAR column except for I/O staging tables. Period. No good ever comes of it as you're finding out right now.

Provided that all of the dates and times are valid in your column and provided that the width of the column is at least 23, the following code will update the dates/times in the column into a sortable ODBC canonical format, which isn't quite the same as ISO8601 but very similar. The details are in the comments in the code.
--===== Conditionally drop the test table to make reruns in SSMS easier
IF OBJECT_ID('tempdb..#TestTable','U') IS NOT NULL
DROP TABLE #TestTable
;
--===== Setup a test table for demonstration purposes.
-- This is NOT a part of the solution.

SELECT SomeVarcharDateTime = CONVERT(VARCHAR(24),d.SomeVarcharDateTime)
INTO #TestTable
FROM (
SELECT '11/07/2013 10:28:14' UNION ALL
SELECT '11/07/2013 10:30:03' UNION ALL
SELECT '11/07/2013 10:47:57' UNION ALL
SELECT '2013-04-21 12:55' UNION ALL
SELECT '2013-21-04 12:55' UNION ALL --Added invalid date/time
SELECT '2013-04-21 13:00' UNION ALL
SELECT '2013-07-25 00:30' UNION ALL
SELECT '2013-07-25 25:30' UNION ALL --Added invalid date/time
SELECT '2013-07-25 00:30' UNION ALL
SELECT '2013-07-25 00:30'
)d(SomeVarcharDateTime)
;
--===== Show what we have before
SELECT * FROM #TestTable
;
--===== Reformat only valid dates in the table and mark the invalid ones
-- with a leading "*"

UPDATE #TestTable
SET SomeVarcharDateTime =
CASE
WHEN ISDATE(SomeVarcharDateTime) = 1
THEN CONVERT(CHAR(23),CAST(SomeVarcharDateTime AS DATETIME),121)
ELSE '*' + SomeVarcharDateTime
END
WHERE LEFT(SomeVarcharDateTime,1) <> '*' --Ignores previous bad rows
;
--===== Show what the reformatting did in sorted order
SELECT * FROM #TestTable ORDER BY SomeVarcharDateTime
;

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

When writing schedules, keep the following in mind:
"If you want it real bad, that's the way you'll likely get it."
Go to Top of Page
   

- Advertisement -