Skip to content
Home » Dates and Times in SQL Server: DATEADD()

Dates and Times in SQL Server: DATEADD()

  • by

We are now in the home stretch of the long-running series about dates and times in SQL Server and Azure SQL Database.

This week we look at one of my favourite T-SQL functions when it comes to dates and times: DATEADD().

Syntax

As with similar functions, DATEADD can do arithmetic on dates as well as times. The syntax is straightforward:

DATEADD (datepart, number, date)

The number portion must be an integer, and it must be within the acceptable range of values for the date part.

The datepart portion must be one of the following date parts (which we’ve seen in previous posts):

datepart Abbreviations
year yy, yyyy
quarter qq, q
month mm, m
dayofyear dy, y
day dd, d
week wk, ww
weekday dw, w
hour hh
minute mi, n
second ss, s
millisecond ms
microsecond mcs
nanosecond ns

Although DATEADD supports abbreviations as shown in the preceding table, we should make every effort to use the full expression to ensure clarity in our code. SQL Server does not run any faster if we use abbreviations.

Also keep in mind that although we can add or subtract nanoseconds with DATEADD, the smallest granularity for a DATETIME2 data type is 100 nanoseconds, so rounding needs to be taken into account.

Return type

DATEADD will return a result using the data type that was used in the date parameter. For example, if we use a literal string representing a date in YYYYMMDD format, the return type will be a DATETIME value, because literal strings are implicitly converted to DATETIME.

SELECT DATEADD(DAY, 1, '20181031')
-- returns the DATETIME value '2018-11-01 00:00:00.000'

However, if we use a DATETIME2 input value, the result will be a DATETIME2 value.

SELECT DATEADD(NANOSECOND, 100, CAST('20181031' AS DATETIME2))
-- returns the DATETIME2 value '2018-10-31 00:00:00.0000001'

Addition and subtraction

We saw previously that DATEADD can be used for addition and subtraction, which makes it easy to calculate values backwards as well as forwards. Let’s assume we need to calculate a point in time that was 100 days ago. If we use today as our starting point, it would look as follows:

DECLARE @dt DATETIME2 = SYSUTCDATETIME();
SELECT @dt AS [TimeNow], DATEADD(DAY, -100, @dt) AS [TimeThen];

Notice the use of the negative sign in the number portion. The results would look as follows:

TimeNow: 2018-10-31 09:17:21.7866500
TimeThen: 2018-07-23 09:17:21.7866500

Arithmetic on months

One final thought on this function. When adding or subtracting months, take care with months that do not contain 31 days. For example, let’s add a month to the end of February 2018:

SELECT DATEADD(MONTH, 1, '20180228')
-- returns the DATETIME value '20180328'

However, if we add one, two, or three months to the end of January 2018, we would see different results:

SELECT DATEADD(MONTH, 1, '20180131');
-- returns the DATETIME value '20180228'

SELECT DATEADD(MONTH, 2, '20180131');
-- returns the DATETIME value '20180331'

SELECT DATEADD(MONTH, 3, '20180131');
-- returns the DATETIME value '20180430'

DATEADD is a very useful system function in T-SQL for adding and subtracting values from a date and time, which I make extensive use of. As long as we keep in mind its quirks around data types and length of months, it can be extremely powerful.

Feel free to share your tips and tricks in the comments below.

Photo by rawpixel on Unsplash.