Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hello everyone,
I need to add an index column based on consumers ID and date.
Data:
ID | Date |
AAA | 1/1/23 |
AAA | 3/7/23 |
AAA | 4/18/23 |
BBB | 12/19/22 |
BBB | 4/5/23 |
CCC | 7/9/23 |
CCC | 9/1/23 |
What i'm looking for:
ID | Date | Index |
AAA | 1/1/23 | 1 |
AAA | 3/7/23 | 2 |
AAA | 4/18/23 | 3 |
BBB | 12/1/22 | 1 |
BBB | 4/5/23 | 2 |
CCC | 7/9/23 | 1 |
CCC | 9/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!
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:
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 !!! |
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:
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"
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.
Hi @clim2f88j ,
Please try like:
Index =
RANKX (
FILTER (
ALL ( 'Table'[ID], 'Table'[Date] ),
'Table'[ID] = EARLIER ( 'Table'[ID] )
),
'Table'[Date],
,
ASC,
Dense
)
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.
Hi @Sammyben ,
Please try sort by [ID] and [Date] first in ascending order in PowerQuery first:
Then group them by [ID] and add an Index column.
Expand columns and the output:
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
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
13 | |
13 | |
10 | |
8 | |
7 |
User | Count |
---|---|
17 | |
10 | |
7 | |
7 | |
6 |