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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
reinholz
Frequent Visitor

Rank within double grouping - possible?

Hey,

 

I'm trying to add a rank column to a fact table that ranks based on two groupings.

My table basically contains records for user activities with user id, created date and a column with the product id for which the activity happend.

 

It looks like this:

Screen Shot 2016-10-18 at 12.31.04.png  

 

What I now want to do is to create a column that ranks the activities by created date, based on user AND product.

How can I do this?

 

Thanks!

 

 

1 ACCEPTED SOLUTION
OwenAuger
Super User
Super User

Hi @reinholz

 

If I've understood you correctly, you want a calculated column that gives you the current row's [created at] rank, among all rows with the same [user id] and [product id].

 

With DAX, you can do that with an expression like this (you may want to change ASC to DESC):

 

Rank =
RANKX (
    CALCULATETABLE (
        FactTable,
        ALLEXCEPT ( FactTable, FactTable[user id], FactTable[product id] )
    ),
    FactTable[created at],
    ,
    ASC
)

Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

3 REPLIES 3
OwenAuger
Super User
Super User

Hi @reinholz

 

If I've understood you correctly, you want a calculated column that gives you the current row's [created at] rank, among all rows with the same [user id] and [product id].

 

With DAX, you can do that with an expression like this (you may want to change ASC to DESC):

 

Rank =
RANKX (
    CALCULATETABLE (
        FactTable,
        ALLEXCEPT ( FactTable, FactTable[user id], FactTable[product id] )
    ),
    FactTable[created at],
    ,
    ASC
)

Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn
Anonymous
Not applicable

Hi @aowen,

 

The solution works great  for static content.

 

However,  I cannot use Calculated Columns as there are 4 other fileds and a calendar field that are used for filtering data (dynamic filters) on the report.

 

Also, I need exactly 10 entries per group.

 

For example, in the above scenario

for PRODUCT 1, there shall be 10 customers ordered by Sales Amount,

for PRODUCT 2, there shall be 10 Customers ..etc

 

I tried with the below DAX expressions along with another field like country ..etc in a matrix and applied.

 

But as in snapshot, I m seeing incorrect values

The rank values are coming up from 2 instead of 1

 

What am I doing wrong?

Table.PNG

 

//Rank decimal values

Rank over Rank of Customers = IF (HASONEVALUE( FACT_Mail[Sender]),
RANKX(ALL(FACT_Mail[Sender]), [Rank of Customers by Request Received], ,DESC,DENSE) , BLANK())

 

//Measure to generate decimal value by taking into account Primary and Secondary Measure to avoid ties

Rank of Customers by Request Received =

IF (HASONEVALUE(FACT_Mail[Sender]),

RANKX(ALL(FACT_Mail[Sender]), [Total Received Requests], ,DESC,DENSE)
+ DIVIDE (
RANKX ( ALL ( FACT_Mail ), [Total Mail Size]+0,, DESC, Dense ),
( COUNTROWS ( ALL ( FACT_Mail ) ) + 1 )),
BLANK())

 

//Primary Measure

Total Received Requests = CALCULATE(COUNT(FACT_Mail[RowId]), USERELATIONSHIP(DIM_DateTable[DateKey], FACT_Mail[DateKey_DateTimeReceived]) )

 

//Secondary Measure

Total Mail Size = DIVIDE(CALCULATE(SUM(FACT_Mail[Size]), USERELATIONSHIP(DIM_DateTable[DateKey], FACT_Mail[DateKey_DateTimeReceived]) ), 1024, 0)

 

 

Thanks,

Mannu

 

Thank you! Works exactly as expected!

Helpful resources

Announcements
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!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.