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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
czaldumbide
Helper I
Helper I

Add Ranking Column with filters

Hi Everyone,

 

I need some help creating an index column using DAX.  I have a table named ACCOUNTEXCEPTION with columns [ID] , [Key] and [Status]. I first want to create a ranking column, that sorts records in ascending order based on [ID] grouped by [Key]. 
 

To achieve this I can use the following code which works perfectly. 

Order by key =
VAR CurrentKey =  'ACCOUNTEXCEPTION'[Key]
VAR CurrentID =  'ACCOUNTEXCEPTION'[ID]

RETURN
CALCULATE
(
    COUNTROWS('ACCOUNTEXCEPTION'),
    FILTER
    (
     ALL('ACCOUNTEXCEPTION'),
     'ACCOUNTEXCEPTION'[Key] = CurrentKey
        && 'ACCOUNTEXCEPTION'[ID] <= CurrentID
    )
)

Now the issue I can't seem to solve is how to apply this ranking to only certain keys that meet a criteria. If the first ID within a key has the status = 'Research', then I want to go ahead with the ranking, otherwise I want to leave it blank. Below is how the final table should look like:
 
KeyIDStatusOrder by Key
A

1

Research1
A2In progress2
A3Completed3
B1Initiated 
B2In progress 
C1Research1
C2Completed2

 

Any help would be appreciated!
Thanks

1 ACCEPTED SOLUTION

Hi,

Please check the below picture and the attached pbix file.

 

Jihwan_Kim_0-1708488982280.png

 

 

Order by key CC = 
VAR _firstid =
    MINX (
        FILTER (
            ACCOUNTEXCEPTION,
            ACCOUNTEXCEPTION[Key] = EARLIER ( ACCOUNTEXCEPTION[Key] )
        ),
        ACCOUNTEXCEPTION[ID]
    )
VAR _condition =
    COUNTROWS (
        FILTER (
            ACCOUNTEXCEPTION,
            ACCOUNTEXCEPTION[Key] = EARLIER ( ACCOUNTEXCEPTION[Key] )
                && ACCOUNTEXCEPTION[ID] = _firstid
                && ACCOUNTEXCEPTION[Status] = "Research"
        )
    ) = 1
RETURN
    IF (
        _condition,
        SUMX (
            FILTER (
                ACCOUNTEXCEPTION,
                ACCOUNTEXCEPTION[Key] = EARLIER ( ACCOUNTEXCEPTION[Key] )
                    && ACCOUNTEXCEPTION[ID] <= EARLIER ( ACCOUNTEXCEPTION[ID] )
            ),
            1
        )
    )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


View solution in original post

4 REPLIES 4
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

It is for creating a new column.

 

Jihwan_Kim_0-1708282826319.png

 

RANK function (DAX) - DAX | Microsoft Learn

 

Order by key CC =
VAR _condition =
    COUNTROWS (
        FILTER (
            ACCOUNTEXCEPTION,
            ACCOUNTEXCEPTION[Key] = EARLIER ( ACCOUNTEXCEPTION[Key] )
                && ACCOUNTEXCEPTION[ID] = 1
                && ACCOUNTEXCEPTION[Status] = "Research"
        )
    ) = 1
RETURN
    IF (
        _condition,
        RANK (
            SKIP,
            ACCOUNTEXCEPTION,
            ORDERBY ( ACCOUNTEXCEPTION[ID], ASC ),
            ,
            PARTITIONBY ( ACCOUNTEXCEPTION[Key] ),
            MATCHBY ( ACCOUNTEXCEPTION[Key], ACCOUNTEXCEPTION[ID] )
        )
    )

 

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Thanks for the code @Jihwan_kin. I need to modify slightly the way my ID column works since it doesnt't always start with a 1 per each key. Please see below the updated example and let me know how we could modify the ranking column. I appreciate your help. 

 

KeyIDStatusRanking

A

24Research1
A28In Progress2
A29Completed3
B231Initiated 
B236Completed 
C72Research1
C73In Progress2
C77Completed3

Hi,

Please check the below picture and the attached pbix file.

 

Jihwan_Kim_0-1708488982280.png

 

 

Order by key CC = 
VAR _firstid =
    MINX (
        FILTER (
            ACCOUNTEXCEPTION,
            ACCOUNTEXCEPTION[Key] = EARLIER ( ACCOUNTEXCEPTION[Key] )
        ),
        ACCOUNTEXCEPTION[ID]
    )
VAR _condition =
    COUNTROWS (
        FILTER (
            ACCOUNTEXCEPTION,
            ACCOUNTEXCEPTION[Key] = EARLIER ( ACCOUNTEXCEPTION[Key] )
                && ACCOUNTEXCEPTION[ID] = _firstid
                && ACCOUNTEXCEPTION[Status] = "Research"
        )
    ) = 1
RETURN
    IF (
        _condition,
        SUMX (
            FILTER (
                ACCOUNTEXCEPTION,
                ACCOUNTEXCEPTION[Key] = EARLIER ( ACCOUNTEXCEPTION[Key] )
                    && ACCOUNTEXCEPTION[ID] <= EARLIER ( ACCOUNTEXCEPTION[ID] )
            ),
            1
        )
    )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Thanks for the solution. This worked perfectly.

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

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

Top Kudoed Authors