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
Johnsnowlife
Helper III
Helper III

Ranking a measure without filters and displaying it with filters.

I'm trying to display the Top and Bottom 5 Advisors by Cumulative Flows. There is an AllClients fact table with [Net Flows] in it and all the relevant lookup tables in star schema including AdvisorFirmInfo2 and FundInfo2. 

 

My Ranking formulas are below. 

Rank (Asc) of Cumul Flows = 
IF (
    HASONEVALUE ( AdvisorFirmInfo2[Advisor Firm] ),
    RANKX (
        ALLSELECTED ( AdvisorFirmInfo2 ),
        CALCULATE ( SUMX ( AllClients, [Cumulative Flows])),
        ,
        ASC,
        DENSE
    )
)
Top and Bottom 10 by Cumul Flows = if(OR([Rank (Asc) of Cumul Flows] <='TopN'[TopN Value],[Rank (Desc) of Cumul Flows]<='TopN'[TopN Value]),1,0)

And I get part of the desired result below. 

Top and Bottom Advisors.JPG

Which let's me make this chart. 

 

 

Top and Bottom Advisors Chart.JPG

But all the Advisors are invested via one of several funds and I want to add the Fund to the legend of the chart. When I do, I get the following chart which has far more advisors than I want.  

Top and Bottom Advisors by Fund Chart.JPG

Converting it back to a table to analyse it I get this.

Top and Bottom Advisors by Fund.JPG

How can I change my Ranking formulae to let me rank on the Cumulative Flows across all funds per Advisor and then display only the Top and Bottom N Advisors while showing the split by Fund? 

 

7 REPLIES 7
Johnsnowlife
Helper III
Helper III

My Cumulative Flows measure is as follows:

Cumulative Flows = 
CALCULATE (
    SUM ( AllClients[Net Flows] )
	,  Values(ClientInfo2[Client Name]), Values(AdvisorFirmInfo2[Advisor Firm]), VALUES(FundInfo[Fund])
)

Hi @Johnsnowlife,

 

Could you try the formula below to see if it works? Smiley Happy

Rank (Asc) of Cumul Flows =
IF (
    HASONEVALUE ( AdvisorFirmInfo2[Advisor Firm] ),
    RANKX (
        ALLSELECTED ( AdvisorFirmInfo2 ),
        CALCULATE (
            SUMX ( AllClients, AllClients[Net Flows] ),
            ALLEXCEPT ( AdvisorFirmInfo2, AdvisorFirmInfo2[Advisor Firm] )
        ),
        ,
        ASC,
        DENSE
    )
)

 

Regards

That didn't work. It gives me a similar result - far more advisors than there should be. 

Hi @Johnsnowlife,

 

Could you post your table structures(including the relationships) with some sample/mock data which can help us reproduce this issue, so that we can do some tests to better assist on it? It's even better to share a sample pbix file(with just some mock data) which can reproduce the issue. You can upload it to OneDrive or Dropbox and post the link here. Do mask sensitive data before uploadingSmiley Happy

 

Regards

Please check out the Excel here and the pbix here. The relationships look like this.

Top and Bottom Advisors - Relationships diagram.JPG

 

Hi @Johnsnowlife,

 

Based on my test, the formulas below should work in your scenario.

Rank (Asc) of Cumul Flows = 
IF (
    HASONEVALUE ( AdvisorFirmInfo2[Public Name] ),
    RANKX (
        ALL(AdvisorFirmInfo2[Public Name]),
        CALCULATE ( SUM ( AllClients[Net Flows] ),ALL(FundInfo[Fund]),ALLEXCEPT(AdvisorFirmInfo2,AdvisorFirmInfo2[Public Name])),
        ,
        ASC,
        DENSE
    )
)
Rank (Desc) of Cumul Flows = 
IF (
    HASONEVALUE ( AdvisorFirmInfo2[Public Name] ),
    RANKX (
        ALL(AdvisorFirmInfo2[Public Name]),
        CALCULATE ( SUM ( AllClients[Net Flows] ),ALL(FundInfo[Fund]),ALLEXCEPT(AdvisorFirmInfo2,AdvisorFirmInfo2[Public Name])),
        ,
        DESC,
        DENSE
    )
)

r1.PNG

 

Here is the modified pbix file for your reference. Smiley Happy

 

Regards

Fantastic! I understand why you can change SUMX to SUM. But can you explain why passing the ALL(Funds) function helps? 

 

To simplify it, I can also take out the "ALLEXCEPT" function like this. Or will there be unintended consequences like this? 

Rank (Desc) of Cumul Flows = 
IF (
    HASONEVALUE ( AdvisorFirmInfo2[Advisor Firm] ),
    RANKX (
        ALLSELECTED ( AdvisorFirmInfo2 ),
        CALCULATE (SUM (AllClients[Net Flows]), 
        ALL(FundInfo[Fund])
        ),
        ,
        DESC,
        DENSE
    )
)

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.