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
tango1201
Frequent Visitor

YTD Average Employee Headcount on a Given Date

I am attempting to calculate Employee Turnover, for which I need to first calculate the average number of employees per day (or month).  For instance and if we had 1,000 employees in January and 1,200 in February, then the February YTD average would be 1,100 per month.

I only have hire dates and termination dates at my disposal.  I found the below DAX (modified from this blog) to be useful in calculating the number of employees on any given day, but I am now struggling to measure this as a daily or monthly average.

Any help appreciated.

 

Employee Count =
SUMX (
GENERATE (
CALCULATETABLE (
SUMMARIZE (
EmployeeRosterHires,
EmployeeRosterHires[Hire Date],
EmployeeRosterHires[Termination Date],
"Rows", COUNTROWS ( EmployeeRosterHires )
),
ALL ( 'Date' )
),
INTERSECT (
DATESBETWEEN ( 'Date'[Date], EmployeeRosterHires[Hire Date], EmployeeRosterHires[Termination Date] ),
LASTDATE ( 'Date'[Date] )
)
),
[Rows]
)

1 ACCEPTED SOLUTION
v-sihou-msft
Employee
Employee

@tango1201

 

In this scenario, as you already have Employee Count measure to get available employees on any date. To analysis on month level, you only need to get the "Employee Count" on end of each month. I suggest you add a "Tag" column in your Calendar table for filtering "End Of Month".

 

IsEOMONTH = IF('Calendar'[Date]=EOMONTH('Calendar'[Date],0),1,0)

Then you can create a measure for Monthly Average:

 

 

AVG Monthly =
CALCULATE (
    AVERAGEX ( 'Calendar', [Employee Count] ),
    FILTER ( ALLSELECTED ( 'Calendar' ), 'Calendar'[IsEOMONTH] = 1 )
)

For Daily Average, you just need to calculate average on existing Employee Count measure:

 

 

AVG Daily = AVERAGEX(ALLSELECTED('Calendar'),[Employee Count])

Regards,

 

View solution in original post

2 REPLIES 2
v-sihou-msft
Employee
Employee

@tango1201

 

In this scenario, as you already have Employee Count measure to get available employees on any date. To analysis on month level, you only need to get the "Employee Count" on end of each month. I suggest you add a "Tag" column in your Calendar table for filtering "End Of Month".

 

IsEOMONTH = IF('Calendar'[Date]=EOMONTH('Calendar'[Date],0),1,0)

Then you can create a measure for Monthly Average:

 

 

AVG Monthly =
CALCULATE (
    AVERAGEX ( 'Calendar', [Employee Count] ),
    FILTER ( ALLSELECTED ( 'Calendar' ), 'Calendar'[IsEOMONTH] = 1 )
)

For Daily Average, you just need to calculate average on existing Employee Count measure:

 

 

AVG Daily = AVERAGEX(ALLSELECTED('Calendar'),[Employee Count])

Regards,

 

That worked.  Thank you

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.

Top Solution Authors