Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Farmertree
Frequent Visitor

Days between two dates and a date slicer

I would like to count a total number of available days between a variable range of two dates defined by a slicer. I have a table with employees ID, start date and end date. Missing end dates indicate employees are still employed.

 

Table .jpg

 

In my report I would like to have a card visual that shows the sum of days that employees are available between a date range defined by a slicer. Something like this:

 

Visual.jpg

 

Is it possible to create such a measure?

 

Thank you for your help!

2 ACCEPTED SOLUTIONS
v-shex-msft
Community Support
Community Support

Hi @Farmertree ,

Yes, it is possible. You can add variables to extract min and max date from selected calendar date and compare with start/end date to get datediff. After these, package them with a sumx function to summary datediff result.

Meausre =
VAR selected =
    ALLSELECTED ( Calendar[Date] )
VAR _max =
    MAXX ( selected, [Date] )
VAR _min =
    MINX ( selected, [Date] )
RETURN
    SUMX (
        ADDCOLUMNS (
            ALLSELECTED ( Table ),
            "Diff", DATEDIFF ( MAX ( [Start date], _min ), MIN ( [End date], _max ), DAY )
        ),
        [Diff]
    )

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

@v-shex-msft Thanks! This helps a lot. The only problem is that this formula returns a negative DATEDIFF value for End dates < _min. Do you know how i could apply a filter within this formula that only selects rows in which Enddate >= _min?

View solution in original post

3 REPLIES 3
v-shex-msft
Community Support
Community Support

Hi @Farmertree ,

Yes, it is possible. You can add variables to extract min and max date from selected calendar date and compare with start/end date to get datediff. After these, package them with a sumx function to summary datediff result.

Meausre =
VAR selected =
    ALLSELECTED ( Calendar[Date] )
VAR _max =
    MAXX ( selected, [Date] )
VAR _min =
    MINX ( selected, [Date] )
RETURN
    SUMX (
        ADDCOLUMNS (
            ALLSELECTED ( Table ),
            "Diff", DATEDIFF ( MAX ( [Start date], _min ), MIN ( [End date], _max ), DAY )
        ),
        [Diff]
    )

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

@v-shex-msft Thanks! This helps a lot. The only problem is that this formula returns a negative DATEDIFF value for End dates < _min. Do you know how i could apply a filter within this formula that only selects rows in which Enddate >= _min?

HI @Farmertree ,

You can do compare between date and _min to get the bigger one and use in datediff function:

Measure =
VAR selected =
    ALLSELECTED ( Calendar[Date] )
VAR _max =
    MAXX ( selected, [Date] )
VAR _min =
    MINX ( selected, [Date] )
RETURN
    SUMX (
        ADDCOLUMNS (
            ALLSELECTED ( Table ),
            "Diff", DATEDIFF (
                MAX ( [Start date], _min ),
                MIN ( MAX ( [End date], _min ), _max ),
                DAY
            )
        ),
        [Diff]
    )

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.