cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
tango1201 Frequent Visitor
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,

 

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,

 

tango1201 Frequent Visitor
Frequent Visitor

Re: YTD Average Employee Headcount on a Given Date

That worked.  Thank you

Helpful resources

Announcements
Back to School Contest

Back to School Contest

Engage and empower students with Power BI!

MBAS Gallery

Watch Sessions On Demand!

Continue your learning in our online communities.

Summit Australia 2019

Summit Australia 2019

Travel to Melbourne and network with thousands of peers!

PBI Community Highlights

PBI Community Highlights

Check out what's new in the Power BI Community!

Top Ideas
Users Online
Currently online: 228 members 2,913 guests
Please welcome our newest community members: