Rounding SQL DateTime to midnight
--
-- SQL DATEDIFF getting midnight time parts
--
SELECT GETDATE() AS Now,
Convert(DateTime, DATEDIFF(DAY, 0, GETDATE())) AS MidnightToday,
Convert(DateTime, DATEDIFF(DAY, -1, GETDATE())) AS MidnightNextDay,
Convert(DateTime, DATEDIFF(DAY, 1, GETDATE())) AS MidnightYesterDay
go
Now MidnightToday MidnightNextDay MidnightYesterDay
-------------------- --------------------- --------------------- ---------------------
8/27/2014 4:30:22 PM 8/27/2014 12:00:00 AM 8/28/2014 12:00:00 AM 8/26/2014 12:00:00 AM
Here is the simplest thing I've found
-- Midnight floor of current date
SELECT Convert(DateTime, DATEDIFF(DAY, 0, GETDATE()))
The DATEDIFF returns the integer number of days before or since 1900-1-1, and the Convert Datetime obligingly brings it back to that date at midnight.
Since DateDiff returns an integer you can use add or subtract days to get the right offset.
SELECT Convert(DateTime, DATEDIFF(DAY, 0, GETDATE()) + @dayOffset)
This isn't rounding this is truncating...But I think that is what is being asked. (To round add one and truncate...and that's not rounding either, that the ceiling, but again most likely what you want. To really round add .5 (does that work?) and truncate.
It turns out you can add .5 to GetDate() and it works as expected.
-- Round Current time to midnight today or midnight tomorrow
SELECT Convert(DateTime, DATEDIFF(DAY, 0, GETDATE() + .5))
I did all my trials on SQL Server 2008, but I think these functions apply to 2005 as well.
In SQL Server 2008 and newer you can cast the DateTime
to a Date
, which removes the time element.
WHERE Orders.OrderStatus = 'Shipped'
AND Orders.ShipDate >= (cast(GETDATE()-6 as date))
In SQL Server 2005 and below you can use:
WHERE Orders.OrderStatus = 'Shipped'
AND Orders.ShipDate >= DateAdd(Day, Datediff(Day,0, GetDate() -6), 0)