DATEADD

Applies to: Calculated column Calculated table Measure Visual calculation

Note

This function is discouraged for use in visual calculations as it likely returns meaningless results.

Returns a table that contains a column of dates, shifted either forward or backward in time by the specified number of intervals from the dates in the current context.

Syntax

DATEADD(<dates>,<number_of_intervals>,<interval>)

Parameters

Term Definition
dates A column that contains dates.
number_of_intervals An integer that specifies the number of intervals to add to or subtract from the dates.
interval The interval by which to shift the dates. The value for interval can be one of the following: year, quarter, month, day

Return value

A table containing a single column of date values.

Remarks

The dates argument can be any of the following:

  • A reference to a date/time column,

  • A table expression that returns a single column of date/time values,

  • A Boolean expression that defines a single-column table of date/time values.

    Note

    Constraints on Boolean expressions are described in the topic, CALCULATE function.

  • If the number specified for number_of_intervals is positive, the dates in dates are moved forward in time; if the number is negative, the dates in dates are shifted back in time.

  • The interval parameter is an enumeration, not a set of strings; therefore values should not be enclosed in quotation marks. Also, the values: year, quarter, month, day should be spelled in full when using them.

  • The result table includes only dates that exist in the dates column.

  • If the dates in the current context do not form a contiguous interval, the function returns an error.

  • This function is not supported for use in DirectQuery mode when used in calculated columns or row-level security (RLS) rules.

Example - Shifting a set of dates

The following formula calculates dates that are one year before the dates in the current context.

= DATEADD(DateTime[DateKey],-1,year)

Special behavior

When the selection includes the last two days of month, DATEADD will use "extension" semantics and will include the days till the end of month. For example, when Feb 27 and 28 of 2013 are included in the selection and a month is added, DATEADD will return March 27 to 31.

This behavior only happens when last two days of month are included in the selection. If only Feb 27 is selected, it will go to March 27.

= DATEADD(DateTime[DateKey], 1, month)

Time intelligence functions Date and time functions