March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi All
I need to calculate the retention rate of staff (12 months of Terminated/Current staff total).
I can get the filters to show the information on separate pages, Terminated by month (Because I've created groups) and the total current employees (Because of the filter "Before"), but I'm unable to make this work on the single page for retention rate.
I presume I have to make a DAX Equation. CALCULATE()....
1) Where the terminated 12-month would be based on the MAX date with 12 months prior as a range.
2) And another for the current employees, (which is Hired-Terminated) ignoring all dates/filters except the MAX date.
Would you be able to help?
I have:
Hired Date
Terminated Date or Blank
Employee No.
Date table
Data via this link:
https://docs.google.com/spreadsheets/d/114xZ57xFR8PgI1Vzqd2hkiscjv695D4MDMn4u97venQ/edit?usp=sharing
Solved! Go to Solution.
Hi James,
Here's my solution:
1. unpivot your data table in Query Editor to look like this:
2. Connect the table to your 'Calendar' table
3. Create a couple of basic DAX measures:
count hired =
CALCULATE(
COUNT(Table1[Employee No]),
Table1[Attribute]="Hired Date")
count terminated =
CALCULATE(
COUNT(Table1[Employee No]),
Table1[Attribute]="Terminated Date")
cumulative hired = CALCULATE([count hired],
FILTER(ALLSELECTED('Calendar'[Date]),
'Calendar'[Date]<MAX('Calendar'[Date])))
cumulative terminated = CALCULATE([count terminated],
FILTER(ALLSELECTED('Calendar'[Date]),
'Calendar'[Date]<MAX(Calendar[Date])))
Current Staff = [cumulative hired]-[cumulative terminated]
redemption rate = DIVIDE([count terminated],[Current Staff],0)
(tipp: you can use VAR to condense everything to 1-2 measures)
4. Put on matrix
hope it helps,
Pawel
James,
1. Unpivot is a step in Query Editor, you do it once, then it occurs automaticaly every time you refresh. Simply mark the two columns 'Hired Date' and 'Terminated Date' and unpivot them. No need to change anything in your dataset.
2. The table may include other fields (Gender, Type, etc). that will sum up to total see attached pbix
Pawel
Hi James,
Here's my solution:
1. unpivot your data table in Query Editor to look like this:
2. Connect the table to your 'Calendar' table
3. Create a couple of basic DAX measures:
count hired =
CALCULATE(
COUNT(Table1[Employee No]),
Table1[Attribute]="Hired Date")
count terminated =
CALCULATE(
COUNT(Table1[Employee No]),
Table1[Attribute]="Terminated Date")
cumulative hired = CALCULATE([count hired],
FILTER(ALLSELECTED('Calendar'[Date]),
'Calendar'[Date]<MAX('Calendar'[Date])))
cumulative terminated = CALCULATE([count terminated],
FILTER(ALLSELECTED('Calendar'[Date]),
'Calendar'[Date]<MAX(Calendar[Date])))
Current Staff = [cumulative hired]-[cumulative terminated]
redemption rate = DIVIDE([count terminated],[Current Staff],0)
(tipp: you can use VAR to condense everything to 1-2 measures)
4. Put on matrix
hope it helps,
Pawel
If you unpivot the data, wouldn't that disrupt other analysis or are you making a copy of the data table and then unpivoting?
Wow, thank you, Pawel!
Is it possible to be completed the analysis without unpivoting the data? Or will unpivot occur automatically every time the data is updated?
Secondly, how would I create:
Gender Profile (Female: Male ratio) and;
Employee Count (FT, PT, CAS)
Both should be summed so that they match the current staff. Example if current staff = 451 then F= 51, M=400 and same with FT, PT and CAS.
I’ve added the additional information to the data set.
Thanks
James,
1. Unpivot is a step in Query Editor, you do it once, then it occurs automaticaly every time you refresh. Simply mark the two columns 'Hired Date' and 'Terminated Date' and unpivot them. No need to change anything in your dataset.
2. The table may include other fields (Gender, Type, etc). that will sum up to total see attached pbix
Pawel
Hi,
Based on the Table that you have shaed in the Speadsheet, please show the exact expected result and the calculation logic. I would like to compare my answer with yours.
Hi Ashish
Great thanks. I've attached a "retention rate by year" for comparison.
Thanks,
James
I do not understand. I'll request someone else to help you.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
119 | |
88 | |
74 | |
67 | |
49 |
User | Count |
---|---|
206 | |
143 | |
97 | |
79 | |
68 |