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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
2366
Helper I
Helper I

RANKX across multiple tables

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 

ProductIDCitySales
1London100
2Paris300
1Paris300
3London250
2Milan350
1Milan150

 

2) Dim Country

CityCountry
LondonUK
ParisFrance
MilanItaly

 

Existing Measure - Calculate(RANKX(All('Fact Sales'[ProductID]), SUM(Sales),,DESC,),Removefilter('Dim Country'[Country]))

 

ProductIDCountrySalesRank
1UK1002
1France3002
1Italy1502
2France3001
2Italy3501
3UK2503

 

Expected Output

 

ProductIDCountrySalesRank
1UK1005
1France3002
1Italy1504
2France3002
2Italy3501
3UK2503

 

1 ACCEPTED SOLUTION
amitchandak
Super User
Super User

@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

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

View solution in original post

2 REPLIES 2
Jos_Woolley
Solution Sage
Solution Sage

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

amitchandak
Super User
Super User

@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

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 2025 Power BI update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.