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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
AlvaVelazquez
New Member

Employee Tenure as of the Date Selected in the Slicer

I need help adjusting the measure below. I have a tenure calculated column for all employees based on Today's date or Term Date. I need to change the measure to calculate tenure based on the date selected in the Date Slicer not on Today's date.  Example: If I selected January I would get the assocaites tenure as of January not Today's Month. 

Tenure Calculated Column =
VAR _TermDate =
    IF ( ISBLANK ( 'Associate Data'[Termination Date] ), Today(), 'Associate Data'[Termination Date] )
VAR _totalmonths =
    DATEDIFF ( 'Associate Data'[Last Hire Date], _TermDate, MONTH )
VAR _years =
    INT (
        (
            ( DAY ( 'Associate Data'[Last Hire Date] ) > DAY ( _TermDate ) ) * -1 + _totalmonths
        ) / 12
    )
VAR _tempmonths =
    (
        (
            (
                ( DAY ( 'Associate Data'[Last Hire Date] ) > DAY ( _TermDate ) ) * -1 + _totalmonths
            ) / 12
        )
            - INT (
                (
                    ( DAY ( 'Associate Data'[Last Hire Date] ) > DAY ( _TermDate ) ) * -1 + _totalmonths
                ) / 12
            )
    ) * 12
VAR _months =
    ROUND ( _tempmonths, 0 )
RETURN
    _years & " year(s) " & _months & " month(s)"
1 ACCEPTED SOLUTION
daXtreme
Solution Sage
Solution Sage

 

[Tenure] =  // measure, not a calc column
// Make sure only one employee is visible
// in the current context. If there are many,
// it makes no sense to calculate tenure.
var ShoudCalculate = HASONEVALUE( 'Associate Data'[EmployeeID] )
var Result =
    if ( ShouldCalculate,
        // Grab the last date that's in context from the slicer
        // and treat this date as today in your code.
        // Slicer should not be connected to anything and you
        // should make sure in the slicer UI that only one date
        // can be selected.
        VAR TermDate = MAX( 'Date Slicer'[Date] )
        VAR LastHireDate = SELECTEDVALUE( 'Associate Data'[Last Hire Date] )
        VAR TotalMonths = DATEDIFF ( LastHireDate, TermDate, MONTH )
        VAR DayCondition = INT( DAY ( LastHireDate ) > DAY ( TermDate ) )
        VAR YearsFractional = ( TotalMonths - DayCondition ) / 12
        VAR Years = INT ( YearsFractional )
        VAR TempMonths = ( YearsFractional - Years ) * 12
        VAR Months = ROUND ( TempMonths, 0 )
        RETURN
            Years & " year(s) " & Months & " month(s)"
    )
return
    Result

 

View solution in original post

5 REPLIES 5
AlvaVelazquez
New Member

Is this a measure and not a column? How can I turn it into a column? 

Tenure column =
var ShoudCalculate = HASONEVALUE( 'Associate Data'[Associate ID] )
var Result =
    if (
        VAR TermDate = MAX( '!Calendar'[Date] )
        VAR LastHireDate = SELECTEDVALUE( 'Associate Data'[Last Hire Date] )
        VAR TotalMonths = DATEDIFF ( LastHireDate, TermDate, MONTH )
        VAR DayCondition = INT( DAY ( LastHireDate ) > DAY ( TermDate ) )
        VAR YearsFractional = ( TotalMonths - DayCondition ) / 12
        VAR Years = INT ( YearsFractional )
        VAR TempMonths = ( YearsFractional - Years ) * 12
        VAR Months = ROUND ( TempMonths, 0 )
        RETURN
            Years & " year(s) " & Months & " month(s)"
    )
return
    Result
daXtreme
Solution Sage
Solution Sage

@AlvaVelazquez 

 

If the formula I gave you is OK, please mark my answer as the solution so that the status is visible to others. Thanks.

Tenure measure is coming in blank

Is this a measure? I need a column in order to add slicers to tenure less than 1 year.

daXtreme
Solution Sage
Solution Sage

 

[Tenure] =  // measure, not a calc column
// Make sure only one employee is visible
// in the current context. If there are many,
// it makes no sense to calculate tenure.
var ShoudCalculate = HASONEVALUE( 'Associate Data'[EmployeeID] )
var Result =
    if ( ShouldCalculate,
        // Grab the last date that's in context from the slicer
        // and treat this date as today in your code.
        // Slicer should not be connected to anything and you
        // should make sure in the slicer UI that only one date
        // can be selected.
        VAR TermDate = MAX( 'Date Slicer'[Date] )
        VAR LastHireDate = SELECTEDVALUE( 'Associate Data'[Last Hire Date] )
        VAR TotalMonths = DATEDIFF ( LastHireDate, TermDate, MONTH )
        VAR DayCondition = INT( DAY ( LastHireDate ) > DAY ( TermDate ) )
        VAR YearsFractional = ( TotalMonths - DayCondition ) / 12
        VAR Years = INT ( YearsFractional )
        VAR TempMonths = ( YearsFractional - Years ) * 12
        VAR Months = ROUND ( TempMonths, 0 )
        RETURN
            Years & " year(s) " & Months & " month(s)"
    )
return
    Result

 

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors