Reply
avatar user
Anonymous
Not applicable
Partially syndicated - Outbound

Create DAX measure using output from another DAX measure to determine an overall status

I have created a DAX measure called 'Risk Ratio' that outputs a risk ratio for each school and school year.  My challenge is to create a new DAX measure using the multi-year Risk Ratio measure to determine an overall status.  I have provided a sample report that has the data and Risk Ratio measure if someone wants to try building the new measure to produce an overall status for each school.  Any help would be greatly appreciated. 

 

Example Report 

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

Syndicated - Outbound

Hi @Anonymous ,

 

Please try:

First turn on the column subtotal and change its name to "Status":

vjianbolimsft_0-1685587716617.png

Then apply the measure to the matrix visual:

Measure =
VAR _a =
    SUMMARIZE ( 'RDS DimLeas', 'RDS DimLeas'[LEA Name] )
VAR _b =
    DISTINCT ( 'Year'[Year] )
VAR _c =
    ADDCOLUMNS ( CROSSJOIN ( _a, _b ), "Risk Ratio", [Risk Ratio] )
VAR _d =
    SELECTEDVALUE ( 'State Set Threshold'[State Threshold] )
VAR _e =
    COUNTROWS ( FILTER ( _c, [Risk Ratio] >= _d ) )
VAR _f =
    ADDCOLUMNS (
        _c,
        "Flag",
            IF (
                RANKX ( _c, VALUE ( MID ( [Year], FIND ( "(", [Year] ) + 1, 4 ) ),, ASC, DENSE )
                    = RANKX ( _c, [Risk Ratio],, DESC, DENSE ),
                1,
                0
            )
    )
RETURN
    SWITCH (
        TRUE (),
        ISINSCOPE ( 'Year'[Year] ), [Risk Ratio],
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 0
            && SUMX ( _c, [Risk Ratio] ) <> BLANK (), "Not sig dispro at all",
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 1, "At-risk year 1",
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 2, "At-risk year 2",
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 3
            && SUMX ( _f, [Flag] ) = 3, "Reasonable progress",
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 3
            && SUMX ( _f, [Flag] ) <> 3, "Significantly disproportionate"
    )

 Final output:

vjianbolimsft_1-1685587752765.png

Best Regards,

Jianbo 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

4 REPLIES 4
v-jianboli-msft
Community Support
Community Support

Syndicated - Outbound

Hi @Anonymous ,

 

Please try:

First turn on the column subtotal and change its name to "Status":

vjianbolimsft_0-1685587716617.png

Then apply the measure to the matrix visual:

Measure =
VAR _a =
    SUMMARIZE ( 'RDS DimLeas', 'RDS DimLeas'[LEA Name] )
VAR _b =
    DISTINCT ( 'Year'[Year] )
VAR _c =
    ADDCOLUMNS ( CROSSJOIN ( _a, _b ), "Risk Ratio", [Risk Ratio] )
VAR _d =
    SELECTEDVALUE ( 'State Set Threshold'[State Threshold] )
VAR _e =
    COUNTROWS ( FILTER ( _c, [Risk Ratio] >= _d ) )
VAR _f =
    ADDCOLUMNS (
        _c,
        "Flag",
            IF (
                RANKX ( _c, VALUE ( MID ( [Year], FIND ( "(", [Year] ) + 1, 4 ) ),, ASC, DENSE )
                    = RANKX ( _c, [Risk Ratio],, DESC, DENSE ),
                1,
                0
            )
    )
RETURN
    SWITCH (
        TRUE (),
        ISINSCOPE ( 'Year'[Year] ), [Risk Ratio],
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 0
            && SUMX ( _c, [Risk Ratio] ) <> BLANK (), "Not sig dispro at all",
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 1, "At-risk year 1",
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 2, "At-risk year 2",
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 3
            && SUMX ( _f, [Flag] ) = 3, "Reasonable progress",
        NOT ( ISINSCOPE ( 'Year'[Year] ) )
            && _e = 3
            && SUMX ( _f, [Flag] ) <> 3, "Significantly disproportionate"
    )

 Final output:

vjianbolimsft_1-1685587752765.png

Best Regards,

Jianbo Li

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

avatar user
Anonymous
Not applicable

Syndicated - Outbound

This is incredibly helpful, thank you Jianbo!  Is there a way to make charts to show the Status similar to the one below?  I need to create visuals using the count of schools (LEAs) by Status.

 

Sample created in Excel...

Screenshot 2023-06-01 093510.jpg

Syndicated - Outbound

Hi @Anonymous ,

 

I'm sorry this question is beyond the original topic of this thread, in order to make the thread more relevant, please consider marking the reply that helped you and creating a new thread for the new question, so that more users can participate and better help others with similar questions.

 

Best Regards,

Jianbo Li

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

avatar user
Anonymous
Not applicable

Syndicated - Outbound

Understand, I'll send a new request. Thanks for your help! 

avatar user

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

FebPBI_Carousel

Power BI Monthly Update - February 2025

Check out the February 2025 Power BI update to learn about new features.

Feb2025 NL Carousel

Fabric Community Update - February 2025

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

Top Solution Authors (Last Month)
Top Kudoed Authors (Last Month)