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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Rollup Averages and Median

Hi,

 

I need to compute for summary stats - Median, Max, Min, 10th percentile and 90th percentile per plan. Here is how the data works:

 

Data:

CustPlan VariantPlan Desc
1AA.1
1AA.1
1AA.2
1BB.1
2BB.2
2CC.1

 

Customer can have multiple plan variant. A plan variant can have multiple plan description.

 

Goal:

I want to be able to compute for averages, medians, etc. for every plan description filter. But if I want to not select only any plan description, it will show the summary stats of the plan variant.

 

jdalfonso_0-1669720687168.png

 

 

 

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

Hi @Anonymous ,

Please create a new table first:

Table 2 = DISTINCT('Table'[Plan Desc])

and use this field to the slicer. Then please create measures like:

Measure = 
VAR _slicer = SELECTEDVALUE('Table 2'[Plan Desc])
VAR _filter = IF(MAX('Table'[Plan Desc])=_slicer||_slicer=BLANK(),1)
RETURN
_filter
Average of ARPU = 
IF(
    ISFILTERED('Table 2'[Plan Desc]),
        CALCULATE(
            AVERAGE('Table'[ARPU]),
            ALLEXCEPT('Table','Table'[Plan Desc])
        ),
        CALCULATE(
            AVERAGE('Table'[ARPU]),
            ALLEXCEPT('Table','Table'[Plan Variant])
        )
)
Median of ARPU = 
IF(
    ISFILTERED('Table 2'[Plan Desc]),
        CALCULATE(
            MEDIAN('Table'[ARPU]),
            ALLEXCEPT('Table','Table'[Plan Desc])
        ),
        CALCULATE(
            MEDIAN('Table'[ARPU]),
            ALLEXCEPT('Table','Table'[Plan Variant])
        )
)

Result:

vcgaomsft_0-1669777621659.png

vcgaomsft_1-1669777643343.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly -- How to provide sample data

View solution in original post

1 REPLY 1
v-cgao-msft
Community Support
Community Support

Hi @Anonymous ,

Please create a new table first:

Table 2 = DISTINCT('Table'[Plan Desc])

and use this field to the slicer. Then please create measures like:

Measure = 
VAR _slicer = SELECTEDVALUE('Table 2'[Plan Desc])
VAR _filter = IF(MAX('Table'[Plan Desc])=_slicer||_slicer=BLANK(),1)
RETURN
_filter
Average of ARPU = 
IF(
    ISFILTERED('Table 2'[Plan Desc]),
        CALCULATE(
            AVERAGE('Table'[ARPU]),
            ALLEXCEPT('Table','Table'[Plan Desc])
        ),
        CALCULATE(
            AVERAGE('Table'[ARPU]),
            ALLEXCEPT('Table','Table'[Plan Variant])
        )
)
Median of ARPU = 
IF(
    ISFILTERED('Table 2'[Plan Desc]),
        CALCULATE(
            MEDIAN('Table'[ARPU]),
            ALLEXCEPT('Table','Table'[Plan Desc])
        ),
        CALCULATE(
            MEDIAN('Table'[ARPU]),
            ALLEXCEPT('Table','Table'[Plan Variant])
        )
)

Result:

vcgaomsft_0-1669777621659.png

vcgaomsft_1-1669777643343.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly -- How to provide sample data

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

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.