Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
I've gone thru a few dozen posts that seemingly asked t he same question but the answers never quite worked for me so I'm going to post this in hopes it helps me and others. We have members that join our program and then will leave the program. The same person can rejoin the program and that's completely fine and we treat that as multiple joins (Enrollments). So I need to show the number of members active during a set timeframe. I have a Date Dimension table setup already based on the min/max date range of the data
Date Dimension Table:
Date MM/DD/YYYY was meant to be used as the slicer.
-- Because i'm dealing with two dates I've tried a few of the measures that show filtering between MIN and MAX, however it doesn't appear to work with my data and still only returns people CURRENTLY enrolled rather than that were enrolled during the date/time I have.
id | enrollment_start | enrollment_end |
6CC4-ED11-97AC-005056980AA1 | 8/18/2023 | 3/5/2024 |
18F5-ED11-97AC-005056980AA1 | 12/4/2023 | 3/5/2024 |
7D38-EE11-97AE-005056980AA1 | 8/21/2023 | |
2F54-EE11-97AE-005056980AA1 | 10/30/2023 | 3/4/2024 |
AE51-ED11-97A9-005056980AA1 | 9/15/2023 | 3/4/2024 |
18F5-ED11-97AC-005056980AA1 | 11/29/2023 | 3/4/2024 |
38AF-ED11-97AB-005056980AA1 | 3/6/2023 | |
C092-EC11-97A6-005056980AA1 | 3/6/2023 | 3/4/2024 |
18ED-EC11-97A7-005056980AA1 | 3/6/2023 | 3/4/2024 |
6CC4-ED11-97AC-005056980AA1 | 4/5/2023 | 3/4/2024 |
C092-EC11-97A6-005056980AA1 | 3/3/2023 | 3/1/2024 |
DB8B-ED11-97A9-005056980AA1 | 3/3/2023 | |
971E-ED11-97A8-005056980AA1 | 10/18/2023 | 3/1/2024 |
38AF-ED11-97AB-005056980AA1 | 3/2/2023 | 2/29/2024 |
C092-EC11-97A6-005056980AA1 | 3/2/2023 | 2/29/2024 |
C092-EC11-97A6-005056980AA1 | 3/2/2023 | 2/29/2024 |
650A-EE11-97AD-005056980AA1 | 7/14/2023 | 2/28/2024 |
FBC7-EC11-97A7-005056980AA1 | 12/1/2023 | 2/28/2024 |
C092-EC11-97A6-005056980AA1 | 3/1/2023 | 2/28/2024 |
C092-EC11-97A6-005056980AA1 | 3/1/2023 | 2/28/2024 |
C092-EC11-97A6-005056980AA1 | 1/12/2024 | 2/27/2024 |
7922-EE11-97AD-005056980AA1 | 9/11/2023 | 2/27/2024 |
38AF-ED11-97AB-005056980AA1 | 8/23/2023 | 2/27/2024 |
EBCA-EE11-97B1-005056980AA1 | 2/14/2024 | |
C092-EC11-97A6-005056980AA1 | 2/28/2023 | 2/27/2024 |
7D38-EE11-97AE-005056980AA1 | 11/30/2023 | 2/27/2024 |
C092-EC11-97A6-005056980AA1 | 10/2/2023 | 2/27/2024 |
C092-EC11-97A6-005056980AA1 | 7/14/2023 | |
C092-EC11-97A6-005056980AA1 | 2/12/2024 | 2/27/2024 |
AE51-ED11-97A9-005056980AA1 | 10/23/2023 | 2/27/2024 |
971E-ED11-97A8-005056980AA1 | 2/28/2023 | 2/27/2024 |
C092-EC11-97A6-005056980AA1 | 2/28/2023 | 2/27/2024 |
38AF-ED11-97AB-005056980AA1 | 2/28/2023 | 2/27/2024 |
ADB5-EE11-97B0-005056980AA1 | 1/29/2024 | 2/27/2024 |
C092-EC11-97A6-005056980AA1 | 2/6/2024 | |
5EB2-ED11-97AC-005056980AA1 | 1/26/2024 | 2/27/2024 |
5EB2-ED11-97AC-005056980AA1 | 3/20/2023 | 2/27/2024 |
630A-EE11-97AD-005056980AA1 | 7/10/2023 | 2/27/2024 |
ADB5-EE11-97B0-005056980AA1 | 1/23/2024 | 2/27/2024 |
C092-EC11-97A6-005056980AA1 | 6/19/2023 | 2/26/2024 |
38AF-ED11-97AB-005056980AA1 | 2/27/2023 | 2/26/2024 |
CEDB-EC11-97A7-005056980AA1 | 2/27/2023 | 2/26/2024 |
C092-EC11-97A6-005056980AA1 | 10/12/2023 | 2/26/2024 |
EBCA-EE11-97B1-005056980AA1 | 2/20/2024 | 2/26/2024 |
C092-EC11-97A6-005056980AA1 | 11/28/2023 | 2/26/2024 |
AB7E-EE11-97AF-005056980AA1 | 11/27/2023 | 2/26/2024 |
2C84-EE11-97AF-005056980AA1 | 11/27/2023 | 2/26/2024 |
C092-EC11-97A6-005056980AA1 | 7/12/2023 | 2/26/2024 |
18F5-ED11-97AC-005056980AA1 | 6/7/2023 | 2/26/2024
|
As you can see there are Blanks which indicates still active so we'd treat that as essentially +1day to whatever the filter is set to.
Ideally I'd set a date slicer and be able to see for instance on 3.1.2024 only, I'd see anyone that has blanks from before that date, and anyone that has an end date after that date. So results would simply show 15 for 3.1.2024, if we look at 2.27.2024 I'd expect to see 39 But ideally I need to be able to select any range.
Ultimately I need counts, so I had been trying to do this with measures and have tried several similar to this:
One further intention is to create a table to use several measures from the same data but most of those have 'hard' dates specifically looking at the end date with 'reason' as a seperate thing I'd be counting. So the date dimension table is important to me, but maybe I should just add more dimensions to my existing table? I know I add start of month/end of month/etc.
I can't seem to wrap my head around some of these solutions using 'inactive' relationships and getting this to work so maybe thats my own inexperience. Thanks in advance for trying to help!
Solved! Go to Solution.
Number of Active People =
VAR _selDateMin = MIN('Date'[Date])
VAR _selDateMax = MAX('Date'[Date])
RETURN
CALCULATE (
DISTINCTCOUNT ( 'Table'[id] ),
FILTER (
'Table',
'Table'[enrollment_start] <= _selDateMax
&& (
'Table'[enrollment_end] >= _selDateMin
|| ISBLANK ( 'Table'[enrollment_end] )
)
)
)
This was the fix for this. It allows me to filter anyone that was active at some time during this time. This was largely thanks to you but this was the actual solution. I just needed to account for the MIN and MAX.
Thank you for all of your help @v-yiruan-msft
I'm curious as to how your date table works. I tested this and while it works if I select a SINGLE date, it doesn't seem to accept/handle a date range. I'm just not sure what I'm missing exactly.
I also went into your file and added a card jsut to show the total count of the timespan and it seems to be not giving me any number when it should in theory show the total count of people active at any point in time during that span. So this is what I'm probably missing on mine as well
Hi @tagban ,
Please update the formula of measure as below and check if can return the expected result...
Number of Active People =
VAR _seldate =
MAX ( 'Date'[Date] )
RETURN
CALCULATE (
DISTINCTCOUNT ( 'Table'[id] ),
FILTER (
'Table',
'Table'[enrollment_start] <= _seldate
&& (
'Table'[enrollment_end] >= _seldate
|| ISBLANK ( 'Table'[enrollment_end] )
)
)
)
Best Regards
Tried this out and it seems to be better, but still having some issues. I -think- I know what the problem is, I think the measure isn't accounting for the min side of date table. IE when you have a slider you're really getting a range of dates like a list right? So you'd look for enrollment start <= minimum(date), and enrollment end is >= max(date)
But the ttruth is, I actually don't care if they leave during that time, what we're looking for is the total people active during those two thresholds.
So for instance someone joins on 10/30/2023 and leaves on 2/25/2024. The slider would be set to 10/20/2023 - 11/2/2023
That person would be considered enrolled during that time. Despite starting after the start time, and ending after the end time.
The same would hold true with the same filter for someone that enrolled on 10/29/2023 and left on 11/1/2023, Still active at some point in that window.
Just testing the formula you provided unfortunately shows still the inaccuracy of the min date, but it seems to be closer to what I'd expect at the max (Single point in time).
Like anyone in the above window should also be in this next one:
Number of Active People =
VAR _selDateMin = MIN('Date'[Date])
VAR _selDateMax = MAX('Date'[Date])
RETURN
CALCULATE (
DISTINCTCOUNT ( 'Table'[id] ),
FILTER (
'Table',
'Table'[enrollment_start] <= _selDateMin || 'Table'[enrollment_start] < _selDateMax
&& (
'Table'[enrollment_end] >= _selDateMax || 'Table'[enrollment_end] >= _selDateMin
|| ISBLANK ( 'Table'[enrollment_end] )
)
)
)
I tried tweaking it a bit, but it seems to still ignore the minimum date, but I feel like this might make more sense to what I'm trying to do?
Number of Active People =
VAR _selDateMin = MIN('Date'[Date])
VAR _selDateMax = MAX('Date'[Date])
RETURN
CALCULATE (
DISTINCTCOUNT ( 'Table'[id] ),
FILTER (
'Table',
'Table'[enrollment_start] <= _selDateMax
&& (
'Table'[enrollment_end] >= _selDateMin
|| ISBLANK ( 'Table'[enrollment_end] )
)
)
)
This was the fix for this. It allows me to filter anyone that was active at some time during this time. This was largely thanks to you but this was the actual solution. I just needed to account for the MIN and MAX.
Thank you for all of your help @v-yiruan-msft
Hi @tagban ,
It's glad to hear that your problem has been resolved. Thanks for sharing your solution here. Could you please mark your post as Answered? It will help the others in the community find the solution easily if they face the same problem as yours. Thank you.
Best Regards
Hi @tagban ,
Base on your description, it seems like you want to get the number of active people during the selected date period. You can create a measure as below to get it, please find the details in the attachment.
Number of Active People =
VAR _seldate =
SELECTEDVALUE('Date'[Date])
RETURN
SUMX (
'Table',
VAR peopleStartDate = [enrollment_start]
VAR peopleEndDate = [enrollment_end]
RETURN
IF (
peopleStartDate <= _seldate
&& OR ( peopleEndDate >= _seldate, peopleEndDate = BLANK () ),
1,
0
)
)
In additional, you can refer the following links to get it:
Power BI: Employee count by month tutorial - Finance BI (finance-bi.com)
Employee Count =
VAR selectedDate =
MAX ( 'Date'[Date] )
RETURN
SUMX (
'Employees',
VAR employeeStartDate = [Start Date]
VAR employeeEndDate = [End Date]
RETURN
IF (
employeeStartDate <= selectedDate
&& OR ( employeeEndDate >= selectedDate, employeeEndDate = BLANK () ),
1,
0
)
)
How Many Staff Do We Currently Have – Multiple Dates Logic In Power BI Using DAX
powerbi - Calculating the number of active employees as at previous months with DAX
ActiveEmps :=
VAR ThisDate =
MIN( Dim_Date[Date] )
RETURN
CALCULATE(
COUNTROWS( employee ),
FILTER(
ALL( employee ),
employee[Start Date] < ThisDate
&& employee[Termination Date] > ThisDate
)
)
Best Regards
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
97 | |
65 | |
45 | |
39 | |
31 |
User | Count |
---|---|
164 | |
111 | |
61 | |
53 | |
38 |