Jump to content


Photo

Sorting datetime fields


  • Please log in to reply
1 reply to this topic

#1 Ham

Ham
  • New Members
  • Pip
  • Newbie
  • 3 posts

Posted 04 January 2006 - 04:39 PM

Why is this query sorting strictly by month only...

select DATE_FORMAT(someDate, '%m/%d/%Y %H:%i:%s') as someDate from someTable order by someDate desc

... while this one sorts the dates properly (but not in the format I desire)

select someDate from someTable order by someDate desc


How do I make the first query work so that it sorts the date properly?


Thanks,


Ham

#2 fenway

fenway
  • Staff Alumni
  • MySQL Si-Fu / PHP Resident Alien
  • 16,199 posts
  • LocationToronto, ON

Posted 04 January 2006 - 06:56 PM

In the first query, since you're reformatting the dates into an arbitrary string, you're now sorting lexcially, which means it will sort by the ASCII value of the characters, so you'll get month "sorting" by accident since you started with the month in your DATE_FORMAT().

In the second query, you're not altering the field at all, and SQL-99 date formats are designed such that they can be sorted lexically and still be sorted "as dates", so there's no issue.

What you need to do is not "destory" your original column value for the sorting, but output another column for your formatting:

select someDate, DATE_FORMAT(someDate, '%m/%d/%Y %H:%i:%s') as someDateFormatted from someTable order by someDate desc

Hope that helps.
Seriously... if people don't start reading this before posting, I'm going to consider not answering at all.




0 user(s) are reading this topic

0 members, 0 guests, 0 anonymous users