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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
mg01
Helper I
Helper I

Need Rank based on summarized value instead of Don't Summarize.

Hi Community,

I'm creating a table visual, having columns Unique_id, date, Sales, Quantity, UOM and a measure Unit Price.

Unit Price=  Divide(sum(Sales),sum(quantity))

Now I want to create a Rank Value based on Unit Price Measure, using below measure:

Rank= rankx(allselected('Table',[Unit Price], ,ASC)

When I pull this measure not getting correct value of rank.

When I do, don't summarize for Sales and Quantity in Values Pane , the value comes correct, but I need rank based summarization of Sales and Quantity. How to correct this Rank Value...

Please find the file link attached with this email:
https://drive.google.com/file/d/16huH-TAWp5T0etocUFMOfackCBeGpmce/view?usp=sharing

1 ACCEPTED SOLUTION

Hi @mg01 ,

I updated your sample pbix file(see the attachment), please check whether that is what you want.

1. Update the formula of measure [Unit Price] as below

Unit Price = 
VAR _seluid =
    SELECTEDVALUE ( 'Table'[Unique_id] )
VAR _seluom =
    SELECTEDVALUE ( 'Table'[UOM] )
VAR _seldate =
    SELECTEDVALUE ( 'Table'[date] )
VAR _sumsales =
    CALCULATE (
        SUM ( 'Table'[Sales] ),
        FILTER (
            ALLSELECTED ( 'Table' ),
            'Table'[Unique_id] = _seluid
                && 'Table'[UOM] = _seluom
                && 'Table'[date] = _seldate
        )
    )
VAR _sumqty =
    CALCULATE (
        SUM ( 'Table'[Quantity] ),
        FILTER (
            ALLSELECTED ( 'Table' ),
            'Table'[Unique_id] = _seluid
                && 'Table'[UOM] = _seluom
                && 'Table'[date] = _seldate
        )
    )
RETURN
    DIVIDE ( _sumsales, _sumqty, 0 ) //DIVIDE(sum('Table'[Sales]),sum('Table'[Quantity]))

2. Update the formula of measure [] as below

Rank = RANKX ( ALLSELECTED ( 'Table' ), [Unit Price],, ASC, DENSE )

yingyinr_0-1654221278392.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
Ashish_Mathur
Super User
Super User

Hi,

This measure works.  Download the PBI file from here.

 

Rank 2 = if(isblank([Unit Price]),blank(),RANKX(filter(generate(all('Calendar'[Date]),generate(ALL('Table'[Unique_id]),all('Table'[UOM]))),[Total quantity]<>blank()),[Unit Price],,ASC))

 

Hope this helps.

Untitled.png


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

@mg01 , Rank can change based on context

Lowset level of table

 

Rank= rankx(allselected('Table') ,[Unit Price], ,ASC)

 

for product, any other column will give rank of product inside that column

Rank= rankx(allselected('Table'[Product]) ,[Unit Price], ,ASC)

 

Two columns

Rank= rankx(allselected('Table'[Product], 'Table'[Cagegory]) ,[Unit Price], ,ASC)

 

 

For Rank Refer these links
https://radacad.com/how-to-use-rankx-in-dax-part-2-of-3-calculated-measures
https://radacad.com/how-to-use-rankx-in-dax-part-1-of-3-calculated-columns

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Only single column can be passed under allselected, I tried all option you shared. Can you please tried with shared file and any suggestion at top of it.

Hi @mg01 ,

I updated your sample pbix file(see the attachment), please check whether that is what you want.

1. Update the formula of measure [Unit Price] as below

Unit Price = 
VAR _seluid =
    SELECTEDVALUE ( 'Table'[Unique_id] )
VAR _seluom =
    SELECTEDVALUE ( 'Table'[UOM] )
VAR _seldate =
    SELECTEDVALUE ( 'Table'[date] )
VAR _sumsales =
    CALCULATE (
        SUM ( 'Table'[Sales] ),
        FILTER (
            ALLSELECTED ( 'Table' ),
            'Table'[Unique_id] = _seluid
                && 'Table'[UOM] = _seluom
                && 'Table'[date] = _seldate
        )
    )
VAR _sumqty =
    CALCULATE (
        SUM ( 'Table'[Quantity] ),
        FILTER (
            ALLSELECTED ( 'Table' ),
            'Table'[Unique_id] = _seluid
                && 'Table'[UOM] = _seluom
                && 'Table'[date] = _seldate
        )
    )
RETURN
    DIVIDE ( _sumsales, _sumqty, 0 ) //DIVIDE(sum('Table'[Sales]),sum('Table'[Quantity]))

2. Update the formula of measure [] as below

Rank = RANKX ( ALLSELECTED ( 'Table' ), [Unit Price],, ASC, DENSE )

yingyinr_0-1654221278392.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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