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
M_Potts
Frequent Visitor

How to sort a table by two columns using date and a number

I am writing up a dashboard for my company. I am trying to sort by two things:

 

Firstly, I want to sort by date in descending order (to get the latest date)

 

Secondly I want to sort by a number. This is because there are multiple numbers for each date, but I want to sort them from largest to smallest.

 

E.g. I want

 

11/12/2017     5

11/12/2017     4

11/12/2017     3

10/12/2017     4

10/12/2017     2

10/12/2017     1

09/12/2017     6

09/12/2017     5

 

I have tried the solution offered at https://community.powerbi.com/t5/Desktop/How-to-Rank-a-list-based-on-2-values-double-rankX/m-p/44076...

 

So my code looks like this:

 

 

Final Rank = 
RANKX (
    ALL ( 'Table'),
    RANKX ( ALL ( 'Table' ), 'Table'[Date],, DESC )
        + DIVIDE (
            RANKX ( ALL ( 'Table' ), 'Table'[Number],, DESC ),
            ( COUNTROWS ( ALL ( 'Table' ) ) + 1 )
        )
)

Unfortunately, with this I get the following message: "A single value for column 'Date' in table 'Table' cannot be determined. This can happen when a measure formula refers to a column that contains many values without specifying an aggregation such as min, max, count, or sum to get a single result."

 

Furthermore, if I attempt to do the following (in accordance with the recommended RANKX format [measure], (order), (tie) I get the message: Special flag is not allowed as an argument number 3 of function 'RANKX'. 

Final Rank = 
RANKX (
    ALL ( 'Table'),
    RANKX ( ALL ( 'Table' ), 'Table'[Date], DESC, DESC )
        + DIVIDE (
            RANKX ( ALL ( 'Table' ), 'Table'[Number], DESC, DESC ),
            ( COUNTROWS ( ALL ( 'Table' ) ) + 1 )
        )
)

Would anyone know how to get around this? 

 

The format of the date can take a 'date' as well as a time and a quarter, but I want to only use the format date (d/mm/year), which I have specified in modelling -> format. 

 

Any help would be much appreciated. 

1 ACCEPTED SOLUTION
v-yulgu-msft
Employee
Employee

Hi @M_Potts,

 

As mentioned in above link you provided, the highlighted part should measures rather than original table columns.

1.PNG

 

In your scenario, please create two extra measures:

primary measure = MAX('Table'[Date])
secondary measure = MAX('Table'[Number])

Then, modify your final rank measure to:

Final Rank = 
RANKX (
    ALL ( 'Table'),
    RANKX ( ALL ( 'Table' ), [primary measure],, DESC )
        + DIVIDE (
            RANKX ( ALL ( 'Table' ), [secondary measure],, DESC ),
            ( COUNTROWS ( ALL ( 'Table' ) ) + 1 )
        )
)

2.PNG

 

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
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

2 REPLIES 2
v-yulgu-msft
Employee
Employee

Hi @M_Potts,

 

As mentioned in above link you provided, the highlighted part should measures rather than original table columns.

1.PNG

 

In your scenario, please create two extra measures:

primary measure = MAX('Table'[Date])
secondary measure = MAX('Table'[Number])

Then, modify your final rank measure to:

Final Rank = 
RANKX (
    ALL ( 'Table'),
    RANKX ( ALL ( 'Table' ), [primary measure],, DESC )
        + DIVIDE (
            RANKX ( ALL ( 'Table' ), [secondary measure],, DESC ),
            ( COUNTROWS ( ALL ( 'Table' ) ) + 1 )
        )
)

2.PNG

 

Best regards,

Yuliana Gu

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

Hi @v-yulgu-msft!

 

Thank you, this worked perfectly!

 

For anyone who is a bit of a noob like me, once you've done the above solution, remember to search for the new column 'Final Rank' in your table so that you can order it according to your specs (as in the picture provided in the above post).

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.