Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
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.
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:
Is it possible to create such a measure?
Thank you for your help!
Solved! Go to Solution.
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
@Anonymous 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 ,
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
@Anonymous 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
Check out the November 2025 Power BI update to learn about new features.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
| User | Count |
|---|---|
| 97 | |
| 70 | |
| 50 | |
| 42 | |
| 40 |