cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
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

Accepted Solutions
Moderator v-sihou-msft
Moderator

Re: YTD Average Employee Headcount on a Given Date

@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
Moderator v-sihou-msft
Moderator

Re: YTD Average Employee Headcount on a Given Date

@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

tango1201
Frequent Visitor

Re: YTD Average Employee Headcount on a Given Date

That worked.  Thank you

Helpful resources

Announcements
New Ranks Launched March 24th!

New Ranks Launched March 24th!

The time has come: We are finally able to share more details on the brand-new ranks coming to the Power BI Community!

‘Better Together’ Contest Finalists Announced!

‘Better Together’ Contest Finalists Announced!

Congrats to the finalists of our ‘Better Together’-themed T-shirt design contest! Click for the top entries.

Arun 'Triple A' Event Video, Q&A, and Slides

Arun 'Triple A' Event Video, Q&A, and Slides

Missed the Arun 'Triple A' event or want to revisit it? We've got you covered! Check out the video, Q&A, and slides now.

Join THE global Microsoft Power Platform event series.

Join THE global Power Platform event series.

Attend for two days of expert-led learning and innovation on topics like AI and Analytics, powered by Dynamic Communities.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Top Solution Authors
Top Kudoed Authors