cancel
Showing results for 
Search instead for 
Did you mean: 
amitchandak

HR Analytics - Active Employee, Hire and Termination trend

In this article, we will cover the following HR Analytics calculations.

  1. Active Employees: Current Employees
  2. Hired Employees
  3. Terminated/ Separated Employees
  4. Last Period Active Employees: Last Period Employees
  5. Period over Period Change %: Employee Change% 

 

To achieve this, we have created an Employee Table. Also, we generated a Date table.

To get the best of the time intelligence function. We need to make sure we have a date calendar and it has been marked as the date in model view. Also, join it with the date column of fact/s. Refer to how to create.

This is the data we have:
Screenshot 2019-12-22 12.37.51.pngScreenshot 2019-12-22 12.37.58.png

 

 

And this is what the relationship diagram looks like.  Start Date joined with Date of Date Dimension and Active, in addition to Inactive relation Termination Date and Date.

Screenshot 2019-12-22 12.36.54.pngScreenshot 2019-12-22 12.37.29.pngScreenshot 2019-12-22 12.37.33.png

 

We can also have both relations inactive.  There is an advantage to calculate Active employees if both are inactive.

Screenshot 2019-12-22 12.37.05.png

 

Calculations:

 

 

 

Hired Employee = CALCULATE(COUNT(Employee[Employee Id ]),USERELATIONSHIP(Employee[Start Date],'Date'[Date]) )

Terminated Employees = CALCULATE(COUNT(Employee[Employee Id ]),USERELATIONSHIP(Employee[End Date],'Date'[Date]),not(ISBLANK(Employee[End Date])))

Current Employees = CALCULATE(COUNTx(FILTER(Employee,Employee[Start Date]<=max('Date'[Date]) && (ISBLANK(Employee[End Date]) || Employee[End Date]>max('Date'[Date]))),(Employee[Employee Id ])),CROSSFILTER(Employee[Start Date],'Date'[Date],None))

Last Period Employee = 
var _min_date = minx(all('Date'),'Date'[Date])
var _Expression=if(ISFILTERED('Date'[Month Year]),maxx('Date',DATEADD('Date'[Date],-1,MONTH)),maxx('Date',DATEADD('Date'[Date],-1,YEAR)))
Return
 CALCULATE(COUNTx(FILTER(Employee,Employee[Start Date]<=_Expression && Employee[Start Date]>=_min_date && (ISBLANK(Employee[End Date]) || Employee[End Date]>_Expression)),(Employee[Employee Id ])),CROSSFILTER(Employee[Start Date],'Date'[Date],None))

Employee Change% = if(not(ISBLANK([Last Period Employee])),CALCULATE( (divide([Current Employees],[Last Period Employee]) -1)*100))

 

 

 

In case Start/Hire date join is active, you can use this:

 

 

Hired Employee = CALCULATE(COUNT(Employee[Employee Id ]) )

 

 

 

No need for USERELATIONSHIP.

 

Also if both joins are inactive, you can use this:

 

 

Current Employees = CALCULATE(COUNTx(FILTER(Employee,Employee[Start Date]<=max('Date'[Date]) && (ISBLANK(Employee[End Date]) 
|| Employee[End Date]>max('Date'[Date]))),(Employee[Employee Id ])))

 

 

 

No need for CROSSFILTER. We can also use count in that case in place of countx.

 

In the last period calculation, we have used ISFILTERED to check, which period we are using. Additional filter Employee[Start Date]>=_min_date is used to avoid going back in the past.

 

This how the trend looks like:

Screenshot 2019-12-23 20.29.49.png

 

And Dashboard with new Ribbon and using new ribbon theme looks like this:

Screenshot 2019-12-23 21.33.46.png

 

The pbix is attached to this article for you to explore.

 

There can be few more ways to get that. There can be better ways too. We are looking forward to hearing back from you on that.

 

 

Comments

Thank you so much amit, you are supber and life savior for me.

 

Please help me how to find two dates differnace in power BI.

Start Date	End Date	Date Difference	Excel Formula
1-Jan-12	30-Apr-21	9 Year 3 Month 29 Days 	DATEDIF(A2,B2,"Y")&" Year "&DATEDIF(A2,B2,"YM")& " Month "&DATEDIF(A2,B2,"MD")& " Days "
31-Dec-12	30-Apr-21	8 Year 3 Month 30 Days 	
15-May-14	30-Apr-21	6 Year 11 Month 15 Days 	
27-Sep-15	30-Apr-21	5 Year 7 Month 3 Days 	
26-Sep-16	30-Apr-21	4 Year 7 Month 4 Days 	
8-Feb-18	30-Apr-21	3 Year 2 Month 22 Days 	

 

Thanks a lot Amit. You save my day 🙂

Hi @amitchandak , Thank you very much for posting this solution.

It is excatly what I was looking for!

The pbix save me a lot of time too.

I would give you 100 kudos if I could 😊

Thanks @amitchandak , this really helped a lot.

 

I have few questions , will need your help here

1) Hires, i need to show the data for current FY - I am able to get the count but there is blank row reflecting which is summing up the rest of HC as below table, Can you guide here.

 

  
HiredMonth year
3000 
114Apr-21
90May-21
88Jun-21

 

note - I added the date table from Apr 21 to Apr 22

 

2) Current HC - i have to exclude the mobility case for the month based on start date (this is seperate column) on the same file... [terminated already taken care per the measure you haveshared]

Mobility Mobility Start
Transfer - Long Term5-Apr-2021
Short Term 
- 
Intercity6-Jun-21

This works perfectly (thank you!) when I only want to count the number of staff.

 

Unfortunately, I cannot modify it to SUM their availability to create a Full Time Equivalent count. I have the "Availability" column in my staff data where, for instance, a full time employee has a value of 1 and an employee who only works half of the time has a value of 0.5, but adding this up is beyond me!

 

I'd be grateful for any suggestions.

 

 

Chris

Thanks a LOT!

 

The only problem I'm currently having is being able to view by Yr-Qtr-Mon-Date. 

 

I have a very comprehansive DATE table that I use that includes various attributes including Yr-Week that I'm trying to incorporate.

 

Unfortunately your measure is based on Yr-Mon.

 

Any suggestions?

 

Thanking you in advance...

 

(Also - THANKS A LOT!)

How would I count the amount of employees with certain contract type (Full Time and Part Time) within a time period?

 

@Phoenix35 

 

As long as you have a date based filter on the report page, you can use a measure based on this one. 

This one counts male employees, but the principle applies for Full Time (assume you have a column with that data). 

the 'trick' is the DatesBetween filter of the measure.  Since the page has a filter for May 2022, it will limit the rows in the pays table to those between 01/05/2022 a d 31/05/2022

 

PaidMales = CALCULATE(DISTINCTCOUNT(HRPayLines[myPayPerson]),HRPerson[gender] = {"Male"}, DATESBETWEEN(Calendar1[DATE], MIN(CalendarPeriod[YearStart]), Max(Calendar1[DATE])))

How do you keep track of (for example) contract history per employee in this data model?

The graph shows the trend of employees with the *actual* values for contract type, but employees can switch type over time.
I am curious if there is a way to track history with this data model, because the model is really lean.

At the moment we use a quite large model, but its possible to track employee history and all data can be combined (-/+ 100 variables). For us, the "real" history is essential for HR analytics.

This is so great

Hi @amitchandak 

 

To count the Current Employee, i have used the dax suggested by you. But i am not getting proper output. I have created date table with Financial Year Calendar. Pls help.

 

Current Employees = CALCULATE(COUNTx(FILTER(Sheet1,Sheet1[Joining Date] <= max('FY'[Date]) && (ISBLANK(Sheet1[Left Date]) || Sheet1[Left Date] >max('FY'[Date]))), (Sheet1[Personnel No.])),CROSSFILTER(Sheet1[Joining Date],'FY'[Date],None))
 
BhaveshSavla_0-1668445438197.png

 

hi @BhaveshSavla , I'm not sure if the FY is causing this, try changing it to max('Date'[Date]) instead.

Hello,

Thank you so much for this. Really helpful. Question. How should I edit  "current employee" if I want to count only number of  current employ that has been employeed for more than 200 days in each each month? Like a rolling total of employees with the company for more than 200 days.

Hi @amitchandak , 

 

This article is great, very helpful. 

 

I'm trying to use it for calculation of open cases in given perion. average in month. 

the only problem I have is that in my project case can be solved or closed so I have 3 columns with date:

Start date

Resolved date 

Closed date (case wanst resolved but closed) 

 

Any ideas how to work with such scenario? 

 

Thank you in advance 

Irek

@Irek , All three dates will join with the date table there will two inactive. And then you can create measures. If there is some specific measure you want to provide. please share some details

Polls
What is your favorite Power BI feature release for November 2022?