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
Tevon713
Helper IV
Helper IV

RankX to show category and not ranking

Hi.

I can't seem to find an answer, simple question how would I show ranking of category over select period.

 

Right now, for the excerise I have it as follow:

Ranking Fruits = RANKX(ALL(Master[FruitName]),[Sum Value],,DESC,Dense)

RankFruitNameSum Value
1Apple500
2Pear439
3Banana350
4Oranges299
5Kiwi100


I want to be able to show the ranking in matrix with ranking in 1st column, the time period as column and for each time period it to display the category and not the ranking. Something like the below. Thanks.

RankJan-21Feb-21Mar-21
1AppleBananaPear
2PearAppleOranges
3BananaPearKiwi
4OrangesOrangesApple
5KiwiKiwiBanana
1 ACCEPTED SOLUTION
Greg_Deckler
Super User
Super User

@Tevon713 OK, I did this with a disconnected Rankings table (just 1 - 5 in a single column called Rank) and then a "FruitsBasket" table. The measure is:

Fruit Rank = 
    VAR __Rank = MAX('Rankings'[Rank])
    VAR __Table = 
        SUMMARIZE(
            'FruitsBasket',
            [FruitName],
            "__Value",SUM([Value])
        )
    VAR __RankTable = 
        ADDCOLUMNS(
            __Table,
            "__Rank",RANKX(__Table,[__Value],,DESC)
        )
RETURN
    MAXX(FILTER(__RankTable,[__Rank] = __Rank),[FruitName])

This was my FruitsBasket table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WciwoyElV0lHySszTNTIEMkwNDJRidRASbqlJEAkTNAnfxCKIhBFUIiA1sQjZJBNUcbhBxqjicHNgNjsl5gEhsknG6DJwszD0wE0zhMr4FyXmpacWIxtnhCEFNw9TCm4gzDvemeWZyKYZoorDjUITh5sD9kwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [FruitName = _t, Month = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"FruitName", type text}, {"Month", type date}, {"Value", Int64.Type}})
in
    #"Changed Type"

Rankings table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlSK1YlWMgKTxmDSBEyaKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Rank = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Rank", Int64.Type}})
in
    #"Changed Type"

Greg_Deckler_0-1630538250425.png

 

 


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

4 REPLIES 4
Ashish_Mathur
Super User
Super User

Hi,

I am not sure of how much i can help, but i would like to try.  Share the link from where i can download your PBI file.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
Greg_Deckler
Super User
Super User

@Tevon713 OK, I did this with a disconnected Rankings table (just 1 - 5 in a single column called Rank) and then a "FruitsBasket" table. The measure is:

Fruit Rank = 
    VAR __Rank = MAX('Rankings'[Rank])
    VAR __Table = 
        SUMMARIZE(
            'FruitsBasket',
            [FruitName],
            "__Value",SUM([Value])
        )
    VAR __RankTable = 
        ADDCOLUMNS(
            __Table,
            "__Rank",RANKX(__Table,[__Value],,DESC)
        )
RETURN
    MAXX(FILTER(__RankTable,[__Rank] = __Rank),[FruitName])

This was my FruitsBasket table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WciwoyElV0lHySszTNTIEMkwNDJRidRASbqlJEAkTNAnfxCKIhBFUIiA1sQjZJBNUcbhBxqjicHNgNjsl5gEhsknG6DJwszD0wE0zhMr4FyXmpacWIxtnhCEFNw9TCm4gzDvemeWZyKYZoorDjUITh5sD9kwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [FruitName = _t, Month = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"FruitName", type text}, {"Month", type date}, {"Value", Int64.Type}})
in
    #"Changed Type"

Rankings table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlSK1YlWMgKTxmDSBEyaKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Rank = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Rank", Int64.Type}})
in
    #"Changed Type"

Greg_Deckler_0-1630538250425.png

 

 


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

@Greg_DecklerThank you very much, this will work for the time being.

Just enlighted by some PQ guru the other day, I came up with a verbose method to calculate rank instead of sorting,

Rank = List.Count( List.PositionOf( list, value, Occurrence.All, each _>=value ) )

 Just for fun, here's a PQ solution based on your hearty FruitBasket. Cheers!

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WciwoyElV0lHySszTNTIEMkwNDJRidRASbqlJEAkTNAnfxCKIhBFUIiA1sQjZJBNUcbhBxqjicHNgNjsl5gEhsknG6DJwszD0wE0zhMr4FyXmpacWIxtnhCEFNw9TCm4gzDvemeWZyKYZoorDjUITh5sD9kwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [FruitName = _t, Month = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"FruitName", type text}, {"Month", type date}, {"Value", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "YYYYMM", each Date.ToText([Month], "MMM yyyy")),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"YYYYMM"}, {{"ar", each _, type table [FruitName=nullable text, Month=nullable date, Value=nullable number, YYYYMM=text]}}),
    #"Added Rank" = Table.TransformColumns(#"Grouped Rows", {"ar", (t) => Table.AddColumn(t, "Rank", (r) => List.Count(List.PositionOf(t[Value], r[Value], Occurrence.All, each _ >= r[Value])))}),
    #"Expanded ar" = Table.ExpandTableColumn(#"Added Rank", "ar", {"FruitName", "Rank"}, {"FruitName", "Rank"}),
    #"Pivoted Column" = Table.Pivot(#"Expanded ar", List.Distinct(#"Expanded ar"[YYYYMM]), "YYYYMM", "FruitName")
in
    #"Pivoted Column"

 Screenshot 2021-09-02 042905.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

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.