March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi,
I have the below tables in my data model - With the current RANKX expression I am able to Rank product sales across all cities but my desired output is to calculate sales of my products across different countries which is my dimension table and Rank sales based on product and across countries. Since I cannot use ALL(ProductID,Country) I am not sure how to get around this. Please help!
Thanks
1) Fact Sales
ProductID | City | Sales |
1 | London | 100 |
2 | Paris | 300 |
1 | Paris | 300 |
3 | London | 250 |
2 | Milan | 350 |
1 | Milan | 150 |
2) Dim Country
City | Country |
London | UK |
Paris | France |
Milan | Italy |
Existing Measure - Calculate(RANKX(All('Fact Sales'[ProductID]), SUM(Sales),,DESC,),Removefilter('Dim Country'[Country]))
ProductID | Country | Sales | Rank |
1 | UK | 100 | 2 |
1 | France | 300 | 2 |
1 | Italy | 150 | 2 |
2 | France | 300 | 1 |
2 | Italy | 350 | 1 |
3 | UK | 250 | 3 |
Expected Output
ProductID | Country | Sales | Rank |
1 | UK | 100 | 5 |
1 | France | 300 | 2 |
1 | Italy | 150 | 4 |
2 | France | 300 | 2 |
2 | Italy | 350 | 1 |
3 | UK | 250 | 3 |
Solved! Go to Solution.
@2366 , Try Rank like
RANKX(Summarize(All('Fact Sales'),'Fact Sales'[ProductID],'Dim Country'[Country] ), SUM(Sales),,DESC,)
Power BI Rank Across dimension tables: https://youtu.be/X59qp5gfQoA
Hi,
In this case, auto-exist will not apply and so you need to be careful to avoid ending up with a visual which contains additional entries due to the cross-join between the two tables. So I would try something like:
Measure =
VAR T1 =
ADDCOLUMNS(
ADDCOLUMNS(
'Fact Sales',
"Country", RELATED( 'Dim Country'[Country] )
),
"MyRank",
RANKX(
ALL( 'Fact Sales' ),
'Fact Sales'[Sales],
,
,
DENSE
)
)
RETURN
MINX(
T1,
[MyRank]
)
Regards
@2366 , Try Rank like
RANKX(Summarize(All('Fact Sales'),'Fact Sales'[ProductID],'Dim Country'[Country] ), SUM(Sales),,DESC,)
Power BI Rank Across dimension tables: https://youtu.be/X59qp5gfQoA
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
25 | |
18 | |
15 | |
9 | |
8 |
User | Count |
---|---|
37 | |
32 | |
16 | |
16 | |
12 |