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
kendrickp87
Frequent Visitor

Employee Grade level YTD Comparison

Hi,
I am trying to highlight new employees and promotions in a matrix table. I am able to show Current Month vs. Prior but wanted to give my customers the opportunity to pivot between MTD (Current Roster - Prior Mo Grade) & YTD (Current Roster - Jan Grade) with a slicer. The YTD Section of my dynamic formula (show January grade levels) needs some help.

 

I would like it to show Jan Employee grade levels in the same line as the current month (the report has a month & year filter). Any help would greatly be appreciated!

 

 

Prev Grade Dynamic = 
SWITCH(MAX('Fiscal Period'[Grade Scenario]),
        "MTD",
VAR _prevDate =
    CALCULATE(
            MAX(CORPX_ROSTER_V[MonthNo]),
            FILTER(
                ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),
                CORPX_ROSTER_V[Date] < MAX(CORPX_ROSTER_V[Date])
                )
    )
Return
    CALCULATE(MAX(CORPX_ROSTER_V[Job Code to Grade.Grade Equivalent]),
    ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),CORPX_ROSTER_V[MonthNo] = _prevDate),
       
        "YTD",
VAR _JanDate =
    CALCULATE(
            MAX(CORPX_ROSTER_V[MonthNo]),
            FILTER(
                ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),
                CORPX_ROSTER_V[BOOKMO] = "201901")
                )
Return
    CALCULATE(MAX(CORPX_ROSTER_V[Job Code to Grade.Grade Equivalent]),
    ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),CORPX_ROSTER_V[MonthNo] = _JanDate)
)

 

 

Image 1) MTD & works properly
Image 2) YTD & Does not work

MTD.jpgYTD.jpg

2 ACCEPTED SOLUTIONS
v-juanli-msft
Community Support
Community Support

Hi @kendrickp87 

MTD (Current Roster - Prior Mo Grade) & YTD (Current Roster - Jan Grade)

Create measures

 

mtd =
IF (
    DATEDIFF ( MAX ( Sheet2[date] ), TODAY (), MONTH ) <= 1,
    CALCULATE (
        SUM ( Sheet2[value] ),
        FILTER (
            ALLEXCEPT ( Sheet2, Sheet2[pin] ),
            DATEDIFF ( Sheet2[date], TODAY (), MONTH ) <= 1
        )
    )
)

ytd = TOTALYTD(SUM(Sheet2[value]),'date'[Date],FILTER(ALLEXCEPT(Sheet2,Sheet2[pin]),Sheet2[date]<=TODAY()),"12/31")

Measure = SWITCH(MAX(slicer[selection]),"MTD",[mtd],"YTD",[ytd])

Capture2.JPG

 

Capture3.JPGCapture4.JPG

 

Best Regards
Maggie
Community Support Team _ Maggie Li
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

Thank you Maggie, that worked for me!

 

I was also able to solve my own question using the MIN BookMonth #, to get January's roster/ employee grade on the same row as current month's values. 

 

Prev Grade Dynamic = 
SWITCH(MAX('Fiscal Period'[Grade Scenario]),
        "MTD",
VAR _prevDate =
    CALCULATE(
            MAX(CORPX_ROSTER_V[MonthNo]),
            FILTER(
                ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),
                CORPX_ROSTER_V[Date] < MAX(CORPX_ROSTER_V[Date])
                )
    )
Return
    CALCULATE(MAX(CORPX_ROSTER_V[Grade Equivalent]),
    ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),CORPX_ROSTER_V[MonthNo] = _prevDate),
       
        "YTD",
VAR _JanDate =
    CALCULATE(
            MIN(CORPX_ROSTER_V[MonthNo]),
            FILTER(
                ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),
                CORPX_ROSTER_V[Date] < MAX(CORPX_ROSTER_V[Date])
                )
    )
Return
    CALCULATE(MAX(CORPX_ROSTER_V[Grade Equivalent]),
    ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),CORPX_ROSTER_V[MonthNo] = _JanDate)
)

 

View solution in original post

4 REPLIES 4
v-juanli-msft
Community Support
Community Support

Hi @kendrickp87 

Is this problem sloved? 
If it is sloved, could you kindly accept it as a solution to close this case?
If not, please let me know.
 
Best Regards
Maggie
kendrickp87
Frequent Visitor

Hi,
I am trying to highlight new employees and promotions in a matrix table. I am able to show Current Month vs. Prior but wanted to give my customers the opportunity to pivot between MTD (Current Roster - Prior Mo Grade) & YTD (Current Roster - Jan Grade) with a slicer. The YTD Section of my dynamic formula (show January grade levels) needs some help.

 

I would like it to show Jan Employee grade levels in the same line as the current month (the report has a month & year filter). Any help would greatly be appreciated!

 

Thank you,

Kendrick

 

 

 

Prev Grade Dynamic = 
SWITCH(MAX('Fiscal Period'[Grade Scenario]),
        "MTD",
VAR _prevDate =
    CALCULATE(
            MAX(CORPX_ROSTER_V[MonthNo]),
            FILTER(
                ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),
                CORPX_ROSTER_V[Date] < MAX(CORPX_ROSTER_V[Date])
                )
    )
Return
    CALCULATE(MAX(CORPX_ROSTER_V[Job Code to Grade.Grade Equivalent]),
    ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),CORPX_ROSTER_V[MonthNo] = _prevDate),
       
        "YTD",
VAR _JanDate =
    CALCULATE(
            MAX(CORPX_ROSTER_V[MonthNo]),
            FILTER(
                ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),
                CORPX_ROSTER_V[BOOKMO] = "201901")
                )
Return
    CALCULATE(MAX(CORPX_ROSTER_V[Job Code to Grade.Grade Equivalent]),
    ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),CORPX_ROSTER_V[MonthNo] = _JanDate)
)

 

 

For added Context:

Grade = TOTALMTD(
                        SUM(CORPX_ROSTER_V[Job Code to Grade.Grade Equivalent]),
                        'Calendar'[Date])
Grade Var = [Grade] - [Prev Grade Dynamic]
Grade Change Description = IF([Grade Var] > 0 && [Grade Var] < [Grade], "Promotion",
                            IF([Grade Var] > 0 && [Grade Var] = [Grade], "New Hire/ Transfer",
                            IF([Grade Var] < 0, "Recalibration", "")))

Image 1) MTD & works properly
Image 2) YTD & Does not work

MTD.jpgYTD.jpg

v-juanli-msft
Community Support
Community Support

Hi @kendrickp87 

MTD (Current Roster - Prior Mo Grade) & YTD (Current Roster - Jan Grade)

Create measures

 

mtd =
IF (
    DATEDIFF ( MAX ( Sheet2[date] ), TODAY (), MONTH ) <= 1,
    CALCULATE (
        SUM ( Sheet2[value] ),
        FILTER (
            ALLEXCEPT ( Sheet2, Sheet2[pin] ),
            DATEDIFF ( Sheet2[date], TODAY (), MONTH ) <= 1
        )
    )
)

ytd = TOTALYTD(SUM(Sheet2[value]),'date'[Date],FILTER(ALLEXCEPT(Sheet2,Sheet2[pin]),Sheet2[date]<=TODAY()),"12/31")

Measure = SWITCH(MAX(slicer[selection]),"MTD",[mtd],"YTD",[ytd])

Capture2.JPG

 

Capture3.JPGCapture4.JPG

 

Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

Thank you Maggie, that worked for me!

 

I was also able to solve my own question using the MIN BookMonth #, to get January's roster/ employee grade on the same row as current month's values. 

 

Prev Grade Dynamic = 
SWITCH(MAX('Fiscal Period'[Grade Scenario]),
        "MTD",
VAR _prevDate =
    CALCULATE(
            MAX(CORPX_ROSTER_V[MonthNo]),
            FILTER(
                ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),
                CORPX_ROSTER_V[Date] < MAX(CORPX_ROSTER_V[Date])
                )
    )
Return
    CALCULATE(MAX(CORPX_ROSTER_V[Grade Equivalent]),
    ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),CORPX_ROSTER_V[MonthNo] = _prevDate),
       
        "YTD",
VAR _JanDate =
    CALCULATE(
            MIN(CORPX_ROSTER_V[MonthNo]),
            FILTER(
                ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),
                CORPX_ROSTER_V[Date] < MAX(CORPX_ROSTER_V[Date])
                )
    )
Return
    CALCULATE(MAX(CORPX_ROSTER_V[Grade Equivalent]),
    ALLEXCEPT(CORPX_ROSTER_V, CORPX_ROSTER_V[PIN]),CORPX_ROSTER_V[MonthNo] = _JanDate)
)

 

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.