Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more
Hi,
I have an employee table with hire date and end date columns and a date table.
There is an active relation between Date[date] and Employee[end date] and an inactive relation between Date[date] and Employee[hire date].
The requirement is to show no of active employees in each month of the year in a column chart.
I have used the below DAX formula
Then, I have tried this Dax formula
This is a bette outcome.
But, the issue is this formula is not considering the hire date while calculating active resources.
for example, if an employee has a start date as 10/04/24 and end date as 31/07/24, he should only be included in the active employees in April, May, June and July. he shouldn't be included for the months before april 2024.
But this 2nd formula is including the above employee in every month till Jul 24.
Can someone help me to modify the DAX to calculate active employees considering both hire date and end date.
Thanks
Kartheek
Solved! Go to Solution.
Hi @KartheekJ ,
Regarding this topic, the key to solving your headcount issue is to set your calendar (date) table as a disconnected table from your employee table, which contains information such as employee ID, joining date, and leaving date. Then, you can write a DAX formula like the one below, enabling you to calculate headcount at any point in time!
Headcount =
SUMX (
EmployeeFact,
IF (
EmployeeFact[Start] <= [SelectedDate]
&& EmployeeFact[End] >= [SelectedDate],
1,
BLANK ()
)
)
Please refer to the article below if you’d like to explore this topic further.
Best regards,
Hi,
How to calculate the active employees if we have duplicate data in the table.
Ex: the table will have multiple rows for an empoyee when he has changed the department.
Regards,
Darshan
Hi @DarshanKumar ,
That's a very relevant question which happens all the time in the real world scenario. You can deal with this very common situation by maintaining the employee change log table where you have start dates and end dates where employees change departments in the table with department field.
Headcount =
SUMX (
'Employee Change',
IF (
MAX ( 'Calendar'[Date] ) >= 'Employee Change'[Hire date]
&& MAX ( 'Calendar'[Date] ) <= 'Employee Change'[Leaving date],
1,
BLANK ()
)
)
The dax measure above will take care of the headcount situation properly even when the employees change departments as long as the change log for department is also properly maintained as a fact table.
This formula checks if the current report date falls between the hire and leave dates, so even if the employee appears multiple times due to transfers, they'll only be counted once if they're still active.
Best regards,
Hi @KartheekJ ,
Regarding this topic, the key to solving your headcount issue is to set your calendar (date) table as a disconnected table from your employee table, which contains information such as employee ID, joining date, and leaving date. Then, you can write a DAX formula like the one below, enabling you to calculate headcount at any point in time!
Headcount =
SUMX (
EmployeeFact,
IF (
EmployeeFact[Start] <= [SelectedDate]
&& EmployeeFact[End] >= [SelectedDate],
1,
BLANK ()
)
)
Please refer to the article below if you’d like to explore this topic further.
Best regards,
Check out the April 2025 Power BI update to learn about new features.
Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
User | Count |
---|---|
16 | |
10 | |
8 | |
8 | |
7 |