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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
clim2f88j
Frequent Visitor

Index Column Based on ID and Date

Hello everyone,

 

I need to add an index column based on consumers ID and date.

 

Data:

IDDate
AAA1/1/23
AAA3/7/23
AAA4/18/23
BBB12/19/22
BBB4/5/23
CCC7/9/23
CCC9/1/23

 

What i'm looking for:

IDDateIndex
AAA1/1/23 1
AAA3/7/23 2
AAA4/18/23 3
BBB12/1/22 1
BBB4/5/23 2
CCC7/9/23 1
CCC9/1/23 2

 

The index column would tell me how many cases we have for that ID and then give it a value based on the date. So the oldest date would get a 1 and the next date a 2, and so on. But i need it to restart when it gets to the next ID.

 

Thank you all!

7 REPLIES 7
Anand24
Super User
Super User

Hi @clim2f88j ,
Create a calculated measure with below DAX:

Index =
RANKX (
    ALLEXCEPT('Table', 'Table'[ID]),
    CALCULATE ( MAX ( 'Table'[Date] ) ),
    ,
    ASC,
    DENSE
) - 1

Here's the result:

Anand24_1-1698354957598.png

 

PBI_SuperUser_Rank@1x.png  

Give a Thumbs Up if this post helped you in any way and Mark This Post as Solution if it solved your query !!!

Proud To Be a Super User !!!
LinkedIn

I have same question but I need to create by id then category and then by date. Hiw can I add also the category?

Hi @Sammyben, something like this? (if no provide sample data and expected result please)

 

Result:

dufoq3_0-1709210507158.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcnR0VNJRcjYEEob6hvpGBkbGSrE6KOLG+uYY4kY4xEHqTfQNLRASTk5OcAuM9A0tQTJG6DIm+qYYOoxQxGMB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Category = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Date", type date}}, "en-US"),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"ID", Order.Ascending}, {"Date", Order.Ascending}}),
    #"Grouped Rows" = Table.Group(#"Sorted Rows", {"ID", "Category"}, {{"Data", each Table.AddIndexColumn(_, "Index", 1, 1, Int64.Type), type table}}),
    #"Combined Tables" = Table.Combine(#"Grouped Rows"[Data])
in
    #"Combined Tables"

Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

Thank you! That worked for the most part, but something i didn't account for is what if the dates are the same? 

Right now if the dates are the same for the same ID then they are getting the same index number. My dates don't have a timestamp.

 

If they have the same date/ID then i don't care which one gets the lower/higher index.

Anonymous
Not applicable

Hi @clim2f88j ,

Please try like:

Index = 
RANKX (
    FILTER (
        ALL ( 'Table'[ID], 'Table'[Date] ),
        'Table'[ID] = EARLIER ( 'Table'[ID] )
    ),
    'Table'[Date],
    ,
    ASC,
    Dense
)

vcgaomsft_0-1698656500929.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

Thank you for helping me out but i get the following error with that DAX: EARLIER/EARLIEST refers to an earlier row context which doesn't exist.

 

In your example, the AAA ID with the 3/7/2023 date have the same index. I need them to be different.

Anonymous
Not applicable

Hi @Sammyben ,

Please try sort by [ID] and [Date] first in ascending order in PowerQuery first:

vcgaomsft_0-1709097329301.png
Then group them by [ID] and add an Index column.

vcgaomsft_1-1709097460674.png

Expand columns and the output:

vcgaomsft_2-1709097560599.png

Advanced editor:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcnR0VNJRMtQ31DcyMDJWitWBCRnrmxMhZKJvaIEQc3JyAhlmpG9oCRI0QhI00TdFV4cQigUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Date", type date}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"ID", Order.Ascending}, {"Date", Order.Ascending}}),
    #"Grouped Rows" = Table.Group(#"Sorted Rows", {"ID"}, {{"Data", each Table.AddIndexColumn(_, "Index", 1, 1, Int64.Type)}}),
    #"Expanded Data" = Table.ExpandTableColumn(#"Grouped Rows", "Data", {"Date", "Index"}, {"Date", "Index"})
in
    #"Expanded Data"

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

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

July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.