Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
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
Solved! Go to Solution.
Hi, @DeepDive
Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.
Table:
You may create a hat-if parameter as below.
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.
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, @DeepDive
Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.
Table:
You may create a hat-if parameter as below.
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.
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@DeepDive , refer if this can help
https://www.sqlbi.com/articles/filtering-the-top-3-products-for-each-category-in-power-bi/
For Rank Refer these links
https://radacad.com/how-to-use-rankx-in-dax-part-2-of-3-calculated-measures
https://radacad.com/how-to-use-rankx-in-dax-part-1-of-3-calculated-columns
https://radacad.com/how-to-use-rankx-in-dax-part-3-of-3-the-finale
https://community.powerbi.com/t5/Community-Blog/Dynamic-TopN-made-easy-with-What-If-Parameter/ba-p/3...
Hi Amit, thanks for your reply.
My requirement is to show YTD at all levels only for selected top N using one slicer only....
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
124 | |
79 | |
50 | |
38 | |
38 |
User | Count |
---|---|
195 | |
80 | |
70 | |
51 | |
42 |