Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
In this article, we will cover the following HR Analytics calculations.
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:
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.
We can also have both relations inactive. There is an advantage to calculate Active employees if both are inactive.
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:
And Dashboard with new Ribbon and using new ribbon theme looks like this:
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.
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.