Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Calculate Retention & Turnover %

Hey there,

 

Can someone help me calculate the following in Power BI : 

 

Retention - % calculated with = 1 - Number of employees that left the company and that were hired in the previous 12 months / Number of hires in the previous 12 months

Turnover - % calculated with = Number of employees that left in the previous 12 months / (Total Employees in the previous 12 months + Number of employees that left in the previous 12 months)

 

The column 'date of resignment' tells me if an employee left.

1 ACCEPTED SOLUTION
v-rzhou-msft
Community Support
Community Support

Hi @Anonymous 

Due to I don't know your data model, I build a sample to have a test.

My Sample:

1.png

Build a Date table by dax code.

Date =
VAR _T =
    ADDCOLUMNS (
        CALENDARAUTO (),
        "Year", YEAR ( [Date] ),
        "Month", MONTH ( [Date] ),
        "YearMonth",
            YEAR ( [Date] ) * 100
                + MONTH ( [Date] ),
        "MonthName", FORMAT ( [Date], "MMMM" )
    )
VAR _T2 =
    ADDCOLUMNS ( _T, "Rank", RANKX ( _T, [YearMonth],, ASC, DENSE ) )
RETURN
    _T2

Measures:

Retention - % calculated with = 
VAR _Previous12START =
    EOMONTH ( MAX ( 'Date'[Date] ), -13 ) + 1
VAR _Previous12END =
    EOMONTH ( MAX ( 'Date'[Date] ), -1 )
VAR _LEFT =
    CALCULATE (
        COUNT ( 'Sample'[Employee] ),
        FILTER (
            ALL ( 'Sample' ),
            'Sample'[Check in Date] >= _Previous12START
                && 'Sample'[Check in Date] <= _Previous12END
                && 'Sample'[Date of Resignment] >= _Previous12START
                && 'Sample'[Date of Resignment] <= _Previous12END
        )
    ) + 0
VAR _Total =
    CALCULATE (
        COUNT ( 'Sample'[Employee] ),
        FILTER (
            ALL ( 'Sample' ),
            'Sample'[Check in Date] <= _Previous12END
                && OR (
                    'Sample'[Date of Resignment] >= _Previous12START,
                    'Sample'[Date of Resignment] = BLANK ()
                )
        )
    )
RETURN
    1 - DIVIDE ( _LEFT, _Total )
Turnover - % calculated with = 
//Number of employees that left in the previous 12 months / (Total Employees in the previous 12 months + Number of employees that left in the previous 12 months)
VAR _Previous12START =
    EOMONTH ( MAX ( 'Date'[Date] ), -13 ) + 1
VAR _Previous12END =
    EOMONTH ( MAX ( 'Date'[Date] ), -1 )
VAR _LEFT =
    CALCULATE (
        COUNT ( 'Sample'[Employee] ),
        FILTER (
            ALL ( 'Sample' ),
            'Sample'[Date of Resignment] >= _Previous12START
                && 'Sample'[Date of Resignment] <= _Previous12END
        )
    )
VAR _TOTAL =
    CALCULATE (
        COUNT ( 'Sample'[Employee] ),
        FILTER (
            ALL ( 'Sample' ),
            'Sample'[Check in Date] <= _Previous12END
                && OR (
                    'Sample'[Date of Resignment] >= _Previous12START,
                    'Sample'[Date of Resignment] = BLANK ()
                )
        )
    )
RETURN
    DIVIDE ( _LEFT, _TOTAL )

If this reply still couldn't help you solve your problem, please share a sample with me by your Onedrive for Business. And show me more details about your calculate logic. You can show me the result you want by screenshot as well.

 

Best Regards,
Rico Zhou

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-rzhou-msft
Community Support
Community Support

Hi @Anonymous 

Due to I don't know your data model, I build a sample to have a test.

My Sample:

1.png

Build a Date table by dax code.

Date =
VAR _T =
    ADDCOLUMNS (
        CALENDARAUTO (),
        "Year", YEAR ( [Date] ),
        "Month", MONTH ( [Date] ),
        "YearMonth",
            YEAR ( [Date] ) * 100
                + MONTH ( [Date] ),
        "MonthName", FORMAT ( [Date], "MMMM" )
    )
VAR _T2 =
    ADDCOLUMNS ( _T, "Rank", RANKX ( _T, [YearMonth],, ASC, DENSE ) )
RETURN
    _T2

Measures:

Retention - % calculated with = 
VAR _Previous12START =
    EOMONTH ( MAX ( 'Date'[Date] ), -13 ) + 1
VAR _Previous12END =
    EOMONTH ( MAX ( 'Date'[Date] ), -1 )
VAR _LEFT =
    CALCULATE (
        COUNT ( 'Sample'[Employee] ),
        FILTER (
            ALL ( 'Sample' ),
            'Sample'[Check in Date] >= _Previous12START
                && 'Sample'[Check in Date] <= _Previous12END
                && 'Sample'[Date of Resignment] >= _Previous12START
                && 'Sample'[Date of Resignment] <= _Previous12END
        )
    ) + 0
VAR _Total =
    CALCULATE (
        COUNT ( 'Sample'[Employee] ),
        FILTER (
            ALL ( 'Sample' ),
            'Sample'[Check in Date] <= _Previous12END
                && OR (
                    'Sample'[Date of Resignment] >= _Previous12START,
                    'Sample'[Date of Resignment] = BLANK ()
                )
        )
    )
RETURN
    1 - DIVIDE ( _LEFT, _Total )
Turnover - % calculated with = 
//Number of employees that left in the previous 12 months / (Total Employees in the previous 12 months + Number of employees that left in the previous 12 months)
VAR _Previous12START =
    EOMONTH ( MAX ( 'Date'[Date] ), -13 ) + 1
VAR _Previous12END =
    EOMONTH ( MAX ( 'Date'[Date] ), -1 )
VAR _LEFT =
    CALCULATE (
        COUNT ( 'Sample'[Employee] ),
        FILTER (
            ALL ( 'Sample' ),
            'Sample'[Date of Resignment] >= _Previous12START
                && 'Sample'[Date of Resignment] <= _Previous12END
        )
    )
VAR _TOTAL =
    CALCULATE (
        COUNT ( 'Sample'[Employee] ),
        FILTER (
            ALL ( 'Sample' ),
            'Sample'[Check in Date] <= _Previous12END
                && OR (
                    'Sample'[Date of Resignment] >= _Previous12START,
                    'Sample'[Date of Resignment] = BLANK ()
                )
        )
    )
RETURN
    DIVIDE ( _LEFT, _TOTAL )

If this reply still couldn't help you solve your problem, please share a sample with me by your Onedrive for Business. And show me more details about your calculate logic. You can show me the result you want by screenshot as well.

 

Best Regards,
Rico Zhou

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi @v-rzhou-msft ,

Thank you for this solution! It works like magic.
I would like to drill down further to see retention % based on job titles and business units. How can i achieve this? Do I need to add an additional 'filter' function in the above dax?

If so what can that look like?

Thanks a lot for your support!

amitchandak
Super User
Super User

@Anonymous , need to know data model and table columns.

 

But you can create hire and terminated employee like give in blog. and then can try this for the last 12 months

https://community.powerbi.com/t5/Community-Blog/HR-Analytics-Active-Employee-Hire-and-Termination-trend/ba-p/882970

 

example

Rolling 12 = CALCULATE([hire],DATESINPERIOD('Date'[Date ],MAX('Date'[Date ]),-12,MONTH))

 

Rolling 12 = CALCULATE([terminated],DATESINPERIOD('Date'[Date ],MAX('Date'[Date ]),-12,MONTH))

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.