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.
Hello! I need help in making a column similar to the results using RANK.AVG in Excel. I have table where there are values that are the same. And when I try to rank them, the results is like this:
Value | Rank
5 | 2
10 | 5
5 | 2
5 | 2
1 | 1
First, I want those values that are the same to have continuous rankings. Then those with same rankings get their continuous ranks averaged. Example below:
Value | Rank | Rank.Avg
5 | 2 | 3
10 | 5 | 5
5 | 3 | 3
5 | 4 | 3
1 | 1 | 1
Hope someone can help me with this! Thank you!
Solved! Go to Solution.
Hi @robibanadera ,
The measure would be like this:
Measure =
VAR t1 =
ADDCOLUMNS ( ALL('Table'), "New", ROUND ( [Value] + RAND () / 100.0, 4 ) )
VAR t2 =
ADDCOLUMNS ( t1, "Rank", RANKX ( t1, [New],, ASC, DENSE ) )
RETURN
AVERAGEX ( FILTER ( t2, [Value] = MAX('Table'[Value]) ), [Rank] )
Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@robibanadera , for the rank avg
Try a new column
Rankx(Table, Table[Value],,asc,skip)
For the second column - Rank try like
Rankx(Table, Table[Value]+rand()/100,,asc,skip)
Hi, thanks for your reply!
I tried the first formula you gave but it's still skipping ranks. What I would like is to have continuous ranking regardless if the values are the same. So for example:
Value | Rank
1 | 1
5 | 2
5 | 3
5 | 4
7 | 5
@robibanadera , That was the second formula. But works better if you create a new column
Oooh nice. This works! My only problem now would be on how to average rankings having the same values. In your screenshot, the rows having same value of 5 has rankings 2, 4, and 3. Can we get a ranking like the computation in Excel function Rank.Avg where the ranking having same values are averaged, in this case it would look like this instead
Value | Rank. Avg
1 | 1
5 | 3
5 | 3
5 | 3
7 | 5
Their ranks would all be 3 because 2+3+4/3 is 3. Rankings were averaged.
Hi @robibanadera ,
You can create a column like this:
Rank.Avg =
VAR t1 =
ADDCOLUMNS ( 'Table', "New", ROUND ( [Value] + RAND () / 100.0, 4 ) )
VAR t2 =
ADDCOLUMNS ( t1, "Rank", RANKX ( t1, [New],, ASC, DENSE ) )
RETURN
AVERAGEX ( FILTER ( t2, [Value] = EARLIER ( 'Table'[Value] ) ), [Rank] )
Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, can you give me the last formula as a measure?
Hi @robibanadera ,
The measure would be like this:
Measure =
VAR t1 =
ADDCOLUMNS ( ALL('Table'), "New", ROUND ( [Value] + RAND () / 100.0, 4 ) )
VAR t2 =
ADDCOLUMNS ( t1, "Rank", RANKX ( t1, [New],, ASC, DENSE ) )
RETURN
AVERAGEX ( FILTER ( t2, [Value] = MAX('Table'[Value]) ), [Rank] )
Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thank you so much! This worked!
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
21 | |
15 | |
14 | |
11 | |
7 |
User | Count |
---|---|
25 | |
24 | |
12 | |
11 | |
11 |