Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Vote for your favorite vizzies from the Power BI Dataviz World Championship submissions. Vote now!
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.
| Key | ID | Status | Order by Key |
| A | 1 | Research | 1 |
| A | 2 | In progress | 2 |
| A | 3 | Completed | 3 |
| B | 1 | Initiated | |
| B | 2 | In progress | |
| C | 1 | Research | 1 |
| C | 2 | Completed | 2 |
Any help would be appreciated!
Thanks
Solved! Go to Solution.
Hi,
Please check the below picture and the attached pbix file.
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
)
)
Hi,
Please check the below picture and the attached pbix file.
It is for creating a new column.
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] )
)
)
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.
| Key | ID | Status | Ranking |
A | 24 | Research | 1 |
| A | 28 | In Progress | 2 |
| A | 29 | Completed | 3 |
| B | 231 | Initiated | |
| B | 236 | Completed | |
| C | 72 | Research | 1 |
| C | 73 | In Progress | 2 |
| C | 77 | Completed | 3 |
Hi,
Please check the below picture and the attached pbix file.
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
)
)
Thanks for the solution. This worked perfectly.
Vote for your favorite vizzies from the Power BI World Championship submissions!
If you love stickers, then you will definitely want to check out our Community Sticker Challenge!
Check out the January 2026 Power BI update to learn about new features.
| User | Count |
|---|---|
| 7 | |
| 5 | |
| 4 | |
| 3 | |
| 3 |
| User | Count |
|---|---|
| 17 | |
| 10 | |
| 6 | |
| 5 | |
| 5 |