cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
DeepDive
Helper IV
Helper IV

Dynamic Top N Categories and Top N Sub Categories and Top N Brand

Hi All, Am using below Curbal's concept for Top N Categories, but under Categories I have Sub-Categories and under Sub-Categories, I have Brands also. At individual level, all is working fine but when I drill down or expand categories it shows me correct for Sub-categories but for Categories it gives me all categories.

 

Curbal's Video link  :   https://www.youtube.com/watch?v=SsZseKOgrWQ

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

Hi, @DeepDive 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

 

Table:

c1.png

 

You may create a hat-if parameter as below.

c2.png

 

Here are the calculated columns and measures:

Calculated column:
Level2 = [Category]&"-"&[Sub Category]
Level3 = [Category]&"-"&[Sub Category]&"-"&[Brand]

Measure:
Visual Control = 
var _categorytopn = 
SELECTCOLUMNS(
    TOPN(
        SELECTEDVALUE(Parameter[Parameter]),
        SUMMARIZE(
        ALL('Table'),
        'Table'[Category],
        "Sales",SUM('Table'[Sales])
        ),
        [Sales]
    ),
    "Category",
    [Category]
)
var _subcategorytopn = 
SELECTCOLUMNS(
    TOPN(
        SELECTEDVALUE(Parameter[Parameter]), 
        SUMMARIZE(
            FILTER(
               ALL('Table'),
               'Table'[Category]=SELECTEDVALUE('Table'[Category])
            ),
            'Table'[Category],
            'Table'[Sub Category],
            "Sales",SUM('Table'[Sales])
        ),
        [Sales]
    ),
    "Level2",
    [Category]&"-"&[Sub Category]
)
var _brandtopn = 
SELECTCOLUMNS(
    TOPN(
        SELECTEDVALUE(Parameter[Parameter]),
            SUMMARIZE(
                FILTER(
                    ALL('Table'),
                    'Table'[Category]=SELECTEDVALUE('Table'[Category])&&
                    'Table'[Sub Category]=SELECTEDVALUE('Table'[Sub Category])
                ),
                'Table'[Category],
                'Table'[Sub Category],
                'Table'[Brand],
                "Sales",SUM('Table'[Sales])
            ),     
        [Sales]
    ),
    "Level3",
    [Category]&"-"&[Sub Category]&"-"&[Brand]
)

return
IF(
    ISINSCOPE('Table'[Category])&&NOT(ISINSCOPE('Table'[Sub Category]))&&NOT(ISINSCOPE('Table'[Brand])),
    IF(
        SELECTEDVALUE('Table'[Category]) in _categorytopn,
        1,0
    ),
    IF(
        ISINSCOPE('Table'[Sub Category])&&NOT(ISINSCOPE('Table'[Brand])),
        IF(      
            SELECTEDVALUE('Table'[Category]) in _categorytopn&&
            SELECTEDVALUE('Table'[Level2]) in _subcategorytopn,
            1,0
        ),
        IF(
            ISINSCOPE('Table'[Brand]),
            IF(
                SELECTEDVALUE('Table'[Category]) in _categorytopn&&
                SELECTEDVALUE('Table'[Level2]) in _subcategorytopn&&
                SELECTEDVALUE('Table'[Level3]) in _brandtopn,
                1,0
            )
        )
    )
)

 

Finally you may put the measure in the visual level filter and use the parameter to filter the topn result. Because the maximum count for 'Brand' is 2, there are only two brand in 'Brand' level even though the slicer is set as 3. It depends on your data.

c3.png

 

c4.png

 

c5.png

 

Best Regards

Allan

 

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-alq-msft
Community Support
Community Support

Hi, @DeepDive 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

 

Table:

c1.png

 

You may create a hat-if parameter as below.

c2.png

 

Here are the calculated columns and measures:

Calculated column:
Level2 = [Category]&"-"&[Sub Category]
Level3 = [Category]&"-"&[Sub Category]&"-"&[Brand]

Measure:
Visual Control = 
var _categorytopn = 
SELECTCOLUMNS(
    TOPN(
        SELECTEDVALUE(Parameter[Parameter]),
        SUMMARIZE(
        ALL('Table'),
        'Table'[Category],
        "Sales",SUM('Table'[Sales])
        ),
        [Sales]
    ),
    "Category",
    [Category]
)
var _subcategorytopn = 
SELECTCOLUMNS(
    TOPN(
        SELECTEDVALUE(Parameter[Parameter]), 
        SUMMARIZE(
            FILTER(
               ALL('Table'),
               'Table'[Category]=SELECTEDVALUE('Table'[Category])
            ),
            'Table'[Category],
            'Table'[Sub Category],
            "Sales",SUM('Table'[Sales])
        ),
        [Sales]
    ),
    "Level2",
    [Category]&"-"&[Sub Category]
)
var _brandtopn = 
SELECTCOLUMNS(
    TOPN(
        SELECTEDVALUE(Parameter[Parameter]),
            SUMMARIZE(
                FILTER(
                    ALL('Table'),
                    'Table'[Category]=SELECTEDVALUE('Table'[Category])&&
                    'Table'[Sub Category]=SELECTEDVALUE('Table'[Sub Category])
                ),
                'Table'[Category],
                'Table'[Sub Category],
                'Table'[Brand],
                "Sales",SUM('Table'[Sales])
            ),     
        [Sales]
    ),
    "Level3",
    [Category]&"-"&[Sub Category]&"-"&[Brand]
)

return
IF(
    ISINSCOPE('Table'[Category])&&NOT(ISINSCOPE('Table'[Sub Category]))&&NOT(ISINSCOPE('Table'[Brand])),
    IF(
        SELECTEDVALUE('Table'[Category]) in _categorytopn,
        1,0
    ),
    IF(
        ISINSCOPE('Table'[Sub Category])&&NOT(ISINSCOPE('Table'[Brand])),
        IF(      
            SELECTEDVALUE('Table'[Category]) in _categorytopn&&
            SELECTEDVALUE('Table'[Level2]) in _subcategorytopn,
            1,0
        ),
        IF(
            ISINSCOPE('Table'[Brand]),
            IF(
                SELECTEDVALUE('Table'[Category]) in _categorytopn&&
                SELECTEDVALUE('Table'[Level2]) in _subcategorytopn&&
                SELECTEDVALUE('Table'[Level3]) in _brandtopn,
                1,0
            )
        )
    )
)

 

Finally you may put the measure in the visual level filter and use the parameter to filter the topn result. Because the maximum count for 'Brand' is 2, there are only two brand in 'Brand' level even though the slicer is set as 3. It depends on your data.

c3.png

 

c4.png

 

c5.png

 

Best Regards

Allan

 

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

 

Hi @v-alq-msft , Thanks a lot.

Hi Amit, thanks for your reply.

 

My requirement is to show YTD at all levels only for selected top N using one slicer only....

Helpful resources

Announcements
Microsoft Build 768x460.png

Microsoft Build is May 24-26. Have you registered yet?

Come together to explore latest innovations in code and application development—and gain insights from experts from around the world.

charticulator_carousel_with_text (1).png

Charticulator Design Challenge

Put your data visualization and design skills to the test! This exciting challenge is happening now through May 31st!

May UG Leader Call Carousel 768x460.png

What difference can a User Group make for you?

At the monthly call, connect with other leaders and find out how community makes your experience even better.

Power BI Release May 2022 768x460.png

Check it out!

Click here to read more about the May 2022 updates!