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

Top N / Rank for a specific month and return the last 12 month value for those Top N

Hi folks, 

 

I need to build a line chart where I need to 1. find the top 10 brands (legend) of the brand share (Y axis) for the current month. 2. Return the last 12 months (X axis) brand share for those top 10 brands identified in step 1. 

 

(Don't worry about the last 12 months, I can use filter to mannually select the 12 months)

 

I have no clue what function I should use. Rank or Related or others?

 

For now, I'm able to build the chart using top N as a filter for the legend. However this approach returned the top 10 brands based on the average brand share for the last 12 months, not the current month's brand share. 

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

Hi @thisiskl ,

 

Here I create a sample to show you how to achieve your goal. If you want to get dynamic Top N, you can create a what if parameter for slicer.

My Data model:

RicoZhou_0-1675320341639.png

Then create a measure as below.

Top N Brand Value =
VAR _TopN =
    SELECTEDVALUE ( 'Top N'[Top N] )
VAR _SUMMARIZE =
    SUMMARIZE (
        ALL ( 'Table' ),
        [Brands],
        "CurrentMonth",
            CALCULATE (
                SUM ( 'Table'[Value] ),
                FILTER (
                    'Calendar',
                    YEAR ( [Date] ) * 100
                        + MONTH ( [Date] )
                        = YEAR ( TODAY () ) * 100
                            + MONTH ( TODAY () )
                )
            )
    )
VAR _ADDRANK =
    ADDCOLUMNS (
        _SUMMARIZE,
        "Rank", RANKX ( _SUMMARIZE, [CurrentMonth],, DESC, DENSE )
    )
VAR _RANK =
    SUMX ( FILTER ( _ADDRANK, [Brands] = MAX ( 'Table'[Brands] ) ), [Rank] )
RETURN
    CALCULATE ( SUM ( 'Table'[Value] ), FILTER ( 'Table', _RANK <= _TopN ) )

To show last 12 months data, you can use relative data function in filter field. Result is as below.

RicoZhou_1-1675320367318.png

 

Best Regards,
Rico Zhou

 

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

3 REPLIES 3
thisiskl
Frequent Visitor

This solution is awesome!

It works perfect for my case. I have a few filters, so I changed TODAY() to MAX(calendar[dt]) , ALL() to ALLSELECTED(). 

v-rzhou-msft
Community Support
Community Support

Hi @thisiskl ,

 

Here I create a sample to show you how to achieve your goal. If you want to get dynamic Top N, you can create a what if parameter for slicer.

My Data model:

RicoZhou_0-1675320341639.png

Then create a measure as below.

Top N Brand Value =
VAR _TopN =
    SELECTEDVALUE ( 'Top N'[Top N] )
VAR _SUMMARIZE =
    SUMMARIZE (
        ALL ( 'Table' ),
        [Brands],
        "CurrentMonth",
            CALCULATE (
                SUM ( 'Table'[Value] ),
                FILTER (
                    'Calendar',
                    YEAR ( [Date] ) * 100
                        + MONTH ( [Date] )
                        = YEAR ( TODAY () ) * 100
                            + MONTH ( TODAY () )
                )
            )
    )
VAR _ADDRANK =
    ADDCOLUMNS (
        _SUMMARIZE,
        "Rank", RANKX ( _SUMMARIZE, [CurrentMonth],, DESC, DENSE )
    )
VAR _RANK =
    SUMX ( FILTER ( _ADDRANK, [Brands] = MAX ( 'Table'[Brands] ) ), [Rank] )
RETURN
    CALCULATE ( SUM ( 'Table'[Value] ), FILTER ( 'Table', _RANK <= _TopN ) )

To show last 12 months data, you can use relative data function in filter field. Result is as below.

RicoZhou_1-1675320367318.png

 

Best Regards,
Rico Zhou

 

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

 

 

 

Thank you so much @v-rzhou-msft !!!

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.

Top Solution Authors