DATESINPERIOD DAX Function (Time Intelligence)

Returns the dates from the given period.

Syntax

DATESINPERIOD ( <Dates>, <StartDate>, <NumberOfIntervals>, <Interval> )
Parameter Attributes Description
Dates

A column reference containing dates.

StartDate

Start date.

NumberOfIntervals

The number of intervals.

Interval

One of: Day, Month, Quarter, Year.

Return values

Table A table with a single column.

A table containing a single column of unique 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.
The result of time intelligence functions has the same data lineage as the date column or table provided as an argument.

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.
A BLANK value provided as StartDate uses MIN ( Dates ) as StartDate argument.

» 4 related articles

Examples

The following expression evaluates the measure Sales Amount in the last 12 months starting from the last day of the period in the filter context.

Sales Moving Annual Total =
CALCULATE (
    [Sales Amount],
    DATESINPERIOD (
        'Date'[Date],
        MAX ( 'Date'[Date] ),
        -1,
        YEAR
    )
)
--  DATESINPERIOD returns an entire period, given a reference date and
--  the period.

--  The first query returns 1 day, starting from August 15, 2008
EVALUATE
    DATESINPERIOD ( 
        'Date'[Date],           -- Return dates in Date[Date]
        DATE ( 2008, 08, 15 ),  -- Starting from 08/15/2008
        1,                      -- the set needs to contain 1
        DAY                     -- day
    )
    
--  The second query returns 3 days, starting from August 15, 2008
EVALUATE
    DATESINPERIOD ( 
        'Date'[Date],           -- Return dates in Date[Date]
        DATE ( 2008, 08, 15 ),  -- Starting from 08/15/2008
        3,                      -- the set needs to contain 3
        DAY                     -- days
    )

--  The second query returns an empty table because we reques 0 days
EVALUATE
    DATESINPERIOD ( 
        'Date'[Date],           -- Return dates in Date[Date]
        DATE ( 2008, 08, 15 ),  -- Starting from 08/15/2008
        0,                      -- the set needs to contain 0
        DAY                     -- days
    )

Date
2008-08-15
Date
2008-08-15
2008-08-16
2008-08-17
--  When the offset is negative, DATESINPERIOD goes back to find
--  the dates to use

--  The first query returns 2 days, the last one is August 15, 2008
EVALUATE
    DATESINPERIOD ( 
        'Date'[Date],           -- Return dates in Date[Date]
        DATE ( 2008, 08, 15 ),  -- Starting from 08/15/2008
        -2,                     -- the set needs to contain 2
        DAY                     -- days, going back in time
    )
    
--  The second query returns an entire month (31 days), the last day is August 15, 2008.
--  The number of days for a month might vary between 28 and 31, depending on the month.
EVALUATE
    DATESINPERIOD ( 
        'Date'[Date],           -- Return dates in Date[Date]
        DATE ( 2008, 08, 15 ),  -- Starting from 08/15/2008
        -1,                     -- going back one
        MONTH                   -- month
    )
Date
2008-08-14
2008-08-15
Date
2008-07-16
2008-07-17
2008-07-18
2008-07-19
2008-07-20
2008-07-21
2008-07-22
2008-07-23
2008-07-24
2008-07-25
2008-07-26
2008-07-27
2008-07-28
2008-07-29
2008-07-30
2008-07-31
2008-08-01
2008-08-02
2008-08-03
2008-08-04
2008-08-05
2008-08-06
2008-08-07
2008-08-08
2008-08-09
2008-08-10
2008-08-11
2008-08-12
2008-08-13
2008-08-14
2008-08-15
--
--  In this example we compute the moving annual average of [Sales Amount]
--  only when DATESINPERIOD contains 12 months of sales
--
DEFINE
    MEASURE Sales[Sales MAT] =
        VAR OneYearBack =
            DATESINPERIOD ( 'Date'[Date], MAX ( 'Date'[Date] ), -1, YEAR )
        VAR Result =
            CALCULATE (
                VAR NumberOfMonths =
                    COUNTROWS ( SUMMARIZE ( Sales, 'Date'[Calendar Year Month Number] ) )
                VAR SalesMAT = [Sales Amount]
                VAR Result   = IF ( NumberOfMonths = 12, SalesMAT / NumberOfMonths )
                RETURN
                    Result,
                OneYearBack
            )
        RETURN
            Result
EVALUATE
SUMMARIZECOLUMNS (
    'Date'[Calendar Year Month Number],
    'Date'[Calendar Year Month],
    TREATAS ( { "CY 2008" }, 'Date'[Calendar Year] ),
    "Sales Amount", [Sales Amount],
    "Sales MAT", [Sales MAT]
)
ORDER BY [Calendar Year Month Number]
Calendar Year Month Number Calendar Year Month Sales Amount Sales MAT
200801 2008-01-01 656,766.69 931,038.71
200802 2008-02-01 600,080.00 906,784.06
200803 2008-03-01 559,538.52 873,304.83
200804 2008-04-01 999,667.17 862,601.69
200805 2008-05-01 893,231.96 859,021.63
200806 2008-06-01 845,141.60 847,591.39
200807 2008-07-01 890,547.41 844,925.09
200808 2008-08-01 721,560.95 825,652.29
200809 2008-09-01 963,437.23 821,782.97
200810 2008-10-01 719,792.99 805,576.26
200811 2008-11-01 1,156,109.32 833,118.55
200812 2008-12-01 921,709.14 827,298.58

Related articles

Learn more about DATESINPERIOD in the following articles:

Last update: Dec 14, 2024   » Contribute   » Show contributors

Contributors: Alberto Ferrari, Marco Russo, Bernat Agullo

Microsoft documentation: https://docs.microsoft.com/en-us/dax/datesinperiod-function-dax

2018-2024 © SQLBI. All rights are reserved. Information coming from Microsoft documentation is property of Microsoft Corp. » Contact us   » Privacy Policy & Cookies

Context Transition

This function performs a Context Transition if called in a Row Context. Click to read more.

Row Context

This expression is executed in a Row Context. Click to read more.

Iterator

Not recommended

The use of this function is not recommended. See Remarks and Related functions for alternatives.

Not recommended

The use of this parameter is not recommended.

Deprecated

This function is deprecated. Jump to the Alternatives section to see the function to use.

Volatile

A volatile function may return a different result every time you call it, even if you provide the same arguments. Click to read more.

Deprecated

This parameter is deprecated and its use is not recommended.

DirectQuery compatibility

Limitations are placed on DAX expressions allowed in measures and calculated columns.
The state below shows the DirectQuery compatibility of the DAX function.

Contribute

Want to improve the content of DATESINPERIOD? Did you find any issue?
Please, report it us! All submissions will be evaluated for possible updates of the content.


This site is protected by reCAPTCHA and the Google Privacy Policy and Terms of Service apply.