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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
garynorcrossmmc
Advocate II
Advocate II

Days Since Change in Different Field

Hi all,

Our team has been asked to calculate the days since Grade change for employees.  Here is a sample set of data we're working with:

garynorcrossmmc_0-1725560682666.png

 

This particular employee went through a grade change (from F to G) on April 1, 2024 - so we want to capture the number of days in between today and the date the grade value changed for this employee.  

 

How do we build this in DAX?  

1 ACCEPTED SOLUTION

Hi @garynorcrossmmc 

 

I think I understand your needs, please follow the steps below:

1. Create three separate tables to record grade information.

 

StartGrade = SELECTCOLUMNS(DISTINCT('DataTable'[Compensation Grade]), "Initial selection", 'DataTable'[Compensation Grade])
EndGrade = SELECTCOLUMNS(DISTINCT('DataTable'[Compensation Grade]), "Final selection", 'DataTable'[Compensation Grade])
GradeSlicer = SELECTCOLUMNS(DISTINCT('DataTable'[Compensation Grade]), "Grade selection", 'DataTable'[Compensation Grade])

 

 

2. Create a slicer for each of the three new table fields, and a slicer for the “PRSN_ID” field in the main data table.

 

3. Calculate the number of days between grades using the following DAX creation measure:

 

DaysBetweenGrades = 
VAR InitialSelection = 
CALCULATE(
    MAX('DataTable'[EFFF_FROM_DT]),
    FILTER(
        'DataTable',
        'DataTable'[PRSN_ID] = SELECTEDVALUE('DataTable'[PRSN_ID]) &&
        'DataTable'[Compensation Grade] = SELECTEDVALUE('StartGrade'[Initial selection])
    )
)

VAR FinalSelection =
CALCULATE(
    MIN('DataTable'[EFFF_FROM_DT]),
    FILTER(
        'DataTable',
        'DataTable'[PRSN_ID] = SELECTEDVALUE('DataTable'[PRSN_ID]) &&
        'DataTable'[Compensation Grade] = SELECTEDVALUE('EndGrade'[Final selection])
    )
)

RETURN
DATEDIFF(
    InitialSelection,
    FinalSelection,
    DAY
)

 

 

4. Use the following DAX creation measure to calculate the number of days between the change of a grade for a particular employee and today:

 

DaysSinceGradeChange = 
VAR GradeSection = 
CALCULATE(
    MIN('DataTable'[EFFF_FROM_DT]),
    FILTER(
        'DataTable',
        'DataTable'[PRSN_ID] = SELECTEDVALUE('DataTable'[PRSN_ID]) &&
        'DataTable'[Compensation Grade] = SELECTEDVALUE('GradeSlicer'[Grade selection])
    )
)

RETURN
DATEDIFF(
    GradeSection,
    TODAY(),
    DAY
)

 

 

5. Here is final output, hope it can meet your requirement.

vxianjtanmsft_1-1725871653988.png

 

 

Best Regards,
Jarvis Tang
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

4 REPLIES 4
v-xianjtan-msft
Community Support
Community Support

Hi @garynorcrossmmc 

 

Agree with Shravan133. The DATEDIFF function can be used to calculate the interval between dates. Refer to DATEDIFF function (DAX) - DAX | Microsoft Learn.

 

Furthermore, I would like to add that when multiple employees need to be calculated, it is recommended to create a measure that dynamically calculates the grade change date.

GradeChangeDate = 
CALCULATE(
    MIN('DataTable'[EFFF_FROM_DT]),
    FILTER(
        'DataTable',
        'DataTable'[PRSN_ID] = MAX('DataTable'[PRSN_ID]) &&
        'DataTable'[Compensation Grade] = "G"
    )
)

Then, use this measure in the DATEDIFF function.

DaysSinceGradeChange = 
DATEDIFF(
    [GradeChangeDate],
    TODAY(),
    DAY
)

 

vxianjtanmsft_0-1725602191606.png

 

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

 

Hi @v-xianjtan-msft , thank you for your response - but how do I make this measure dynamic by grade?  This will vary by an employee's grade (A through J), so an employee can make a change from A to B, C to D, sometimes a jump by 2 grades, etc.  

Hi @garynorcrossmmc 

 

I think I understand your needs, please follow the steps below:

1. Create three separate tables to record grade information.

 

StartGrade = SELECTCOLUMNS(DISTINCT('DataTable'[Compensation Grade]), "Initial selection", 'DataTable'[Compensation Grade])
EndGrade = SELECTCOLUMNS(DISTINCT('DataTable'[Compensation Grade]), "Final selection", 'DataTable'[Compensation Grade])
GradeSlicer = SELECTCOLUMNS(DISTINCT('DataTable'[Compensation Grade]), "Grade selection", 'DataTable'[Compensation Grade])

 

 

2. Create a slicer for each of the three new table fields, and a slicer for the “PRSN_ID” field in the main data table.

 

3. Calculate the number of days between grades using the following DAX creation measure:

 

DaysBetweenGrades = 
VAR InitialSelection = 
CALCULATE(
    MAX('DataTable'[EFFF_FROM_DT]),
    FILTER(
        'DataTable',
        'DataTable'[PRSN_ID] = SELECTEDVALUE('DataTable'[PRSN_ID]) &&
        'DataTable'[Compensation Grade] = SELECTEDVALUE('StartGrade'[Initial selection])
    )
)

VAR FinalSelection =
CALCULATE(
    MIN('DataTable'[EFFF_FROM_DT]),
    FILTER(
        'DataTable',
        'DataTable'[PRSN_ID] = SELECTEDVALUE('DataTable'[PRSN_ID]) &&
        'DataTable'[Compensation Grade] = SELECTEDVALUE('EndGrade'[Final selection])
    )
)

RETURN
DATEDIFF(
    InitialSelection,
    FinalSelection,
    DAY
)

 

 

4. Use the following DAX creation measure to calculate the number of days between the change of a grade for a particular employee and today:

 

DaysSinceGradeChange = 
VAR GradeSection = 
CALCULATE(
    MIN('DataTable'[EFFF_FROM_DT]),
    FILTER(
        'DataTable',
        'DataTable'[PRSN_ID] = SELECTEDVALUE('DataTable'[PRSN_ID]) &&
        'DataTable'[Compensation Grade] = SELECTEDVALUE('GradeSlicer'[Grade selection])
    )
)

RETURN
DATEDIFF(
    GradeSection,
    TODAY(),
    DAY
)

 

 

5. Here is final output, hope it can meet your requirement.

vxianjtanmsft_1-1725871653988.png

 

 

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

Shravan133
Solution Sage
Solution Sage

use datediff()

For example: DaysSinceGradeChange =
VAR GradeChangeDate = DATE(2024, 4, 1) -- Replace this with the actual column that holds the grade change date
RETURN
DATEDIFF(GradeChangeDate, TODAY(), DAY)-- returns number of days

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

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