DATESBETWEEN DAX Function (Time Intelligence)
Returns the dates between two given dates.
Syntax
Parameter | Attributes | Description |
---|---|---|
Dates |
A column reference containing dates. |
|
StartDate |
Start date. |
|
EndDate |
End date. |
Return values
A table containing a single column of date values.
Notes
In order to use any time intelligence calculation, you need a well-formed date table. The Date table must satisfy the following requirements:
- All dates need to be present for the years required. The Date table must always start on January 1 and end on December 31, including all the days in this range. If the report only references fiscal years, then the date table must include all the dates from the first to the last day of a fiscal year. For example, if the fiscal year 2008 starts on July 1, 2007, then the Date table must include all the days from July 1, 2007 to June 30, 2008.
- There needs to be a column with a DateTime or Date data type containing unique values. This column is usually called Date. Even though the Date column is often used to define relationships with other tables, this is not required. Still, the Date column must contain unique values and should be referenced by the Mark as Date Table feature. In case the column also contains a time part, no time should be used – for example, the time should always be 12:00 am.
- The Date table must be marked as a date table in the model, in case the relationship between the Date table and any other table is not based on the Date.
Remarks
The dates argument must be a reference to a date/time column.
The result table includes only dates that exist in the dates column.
If StartDate is a blank date value, then StartDate will be the earliest value in the dates column.
If EndDate is a blank date value, then EndDate will be the latest value in the dates column.
The dates used as the StartDate and EndDate are inclusive: that is, if the sales occurred on September 1 and you use September 1 as the start date, sales on September 1 are counted.
If StartDate is larger than EndDate, the result is an empty table.
Examples
-- DATESBETWEEN returns the dates between the boundaries specified. -- The boundaries are both included in the result. -- If EndDate is earlier than LastDate, the result is an empty table. EVALUATE VAR StartDate = DATE ( 2008, 08, 25 ) VAR EndDate = DATE ( 2008, 08, 31 ) RETURN DATESBETWEEN ( 'Date'[Date], StartDate, EndDate ) ORDER BY [Date]
Date |
---|
2008-08-25 |
2008-08-26 |
2008-08-27 |
2008-08-28 |
2008-08-29 |
2008-08-30 |
2008-08-31 |
-- Using BLANK for one boundary means use MIN/MAX of available dates. -- This query returns all the dates from Jan 1, 2005 (first date in the Date table) -- and August 31, 2008 EVALUATE VAR StartDate = BLANK () VAR EndDate = DATE ( 2008, 08, 31 ) RETURN DATESBETWEEN ( 'Date'[Date], StartDate, EndDate ) ORDER BY [Date]
-- DATESBETWEEN returns dates that exist in the Date table. -- A date lower than the minimum makes DATESEBETWEEN start -- from the min value anyway. -- The content of the Date table starts from Jan 1, 2005. EVALUATE VAR StartDate = DATE ( 2004, 01, 01 ) -- Lower than MIN ( 'Date'[Date] ) VAR EndDate = DATE ( 2005, 01, 6 ) RETURN DATESBETWEEN ( 'Date'[Date], StartDate, EndDate ) ORDER BY [Date]
Date |
---|
2005-01-01 |
2005-01-02 |
2005-01-03 |
2005-01-04 |
2005-01-05 |
2005-01-06 |
-- In this example we compute the moving average of [Sales Amount] over 30 days -- Moving periods are easier to compute using DATESINPERIOD, anyway. DEFINE MEASURE Sales[Sales Last 30D] = VAR Last30D = DATESBETWEEN ( 'Date'[Date], MAX ( 'Date'[Date] ) - 29, -- boundaries are included, this is why we use 29 MAX ( 'Date'[Date] ) -- to obtain 30 days ) VAR Result = CALCULATE ( [Sales Amount] / 30, Last30D ) RETURN Result EVALUATE SUMMARIZECOLUMNS ( 'Date'[Date], "Sales Amount", [Sales Amount], "Sales 30D", [Sales Last 30D] ) ORDER BY [Date]
Related articles
Learn more about DATESBETWEEN in the following articles:
-
Counting working days in DAX
This article shows a DAX technique to compute the number of working days between two dates. » Read more
-
Differences between DATEADD and PARALLELPERIOD in DAX
This article describes the difference between the results of DATEADD and PARALLELPERIOD in DAX. These differences also impact many other time intelligence functions that are syntax sugar of these two. » Read more
-
Computing sales to specific customers before and after a time period
This article shows how to manipulate the filter context to create a report with the sales made to a specific customer segment, before and after a selected month. » Read more
-
Optimizing time intelligence in DirectQuery
This article describes how to optimize time intelligence calculations with DirectQuery over SQL in Power BI by avoiding time intelligence DAX functions. » Read more
-
Blank in date columns and DAX time intelligence functions
This article explores the implications of having blank values in date columns and provides the best practices for managing them in DAX calculations and Power BI reports. » Read more
Last update: Dec 14, 2024 » Contribute » Show contributors
Contributors: Alberto Ferrari, Marco Russo
Microsoft documentation: https://docs.microsoft.com/en-us/dax/datesbetween-function-dax