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
filarap
Helper III
Helper III

Power Query - Ordinal row number based on unique id and date/time?

Hi all, I was wondering if it is possible to do one thing in power query: I have a table with interaction ids that can appear in multiple rows with different time stamp. Repetition happens when interaction is opened again and again. I would like to create custom column with ordinal number for each interaction in a data table. This would look something similar to below: 

 

Interaction IDDate/timeOrdinal Number
1234/4/2019 13:001
3454/5/2019 15:001
5674/6/2019 19:001
1234/7/2019 18:002
1234/8/2019 13:303
5674/9/2019 16:152
3454/10/2019 12:002
1234/11/2019 11:004
3454/12/2019 13:003

 

Is this possible outside of DAX

Regards

Filarap

 

4 ACCEPTED SOLUTIONS
parry2k
Super User
Super User

@filarap here is sample power query, change it as per your need.

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Xc/LCUAhDETRVh5ZC2YS468Vsf82BIkPdH3gTjIGQZQCpZiiMNoH7cw0wyBNtsEc7IDlsiE7tAMnVRzqC/Xf0DvVHHKHXeNgF3lbgAvegyHXK3MB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"Interaction ID" = _t, Date = _t]),
    #"Grouped Rows" = Table.Group(Source, {"Interaction ID"}, {{"Count", each Table.RowCount(_), type number}, {"AllRows", each _, type table [Interaction ID=text, Date=text]}}),
    #"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Index", 1, 1),
    #"Removed Columns" = Table.RemoveColumns(#"Added Index",{"Count"}),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Removed Columns", "AllRows", {"Date"}, {"Date"})
in
    #"Expanded AllRows"


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

View solution in original post

@filarap try this

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Xc/LCUAhDETRVh5ZC2YS468Vsf82BIkPdH3gTjIGQZQCpZiiMNoH7cw0wyBNtsEc7IDlsiE7tAMnVRzqC/Xf0DvVHHKHXeNgF3lbgAvegyHXK3MB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"Interaction ID" = _t, Date = _t]),
    #"Grouped Rows" = Table.Group(Source, {"Interaction ID"}, {{"Rank", each Table.AddIndexColumn(_, "Rank", 1)}}),
    #"Expanded Rank1" = Table.ExpandTableColumn(#"Grouped Rows", "Rank", {"Date", "Rank"}, {"Date", "Rank"})
in
    #"Expanded Rank1"


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

View solution in original post

v-danhe-msft
Microsoft Employee
Microsoft Employee

Hi @filarap ,

You could refer to below code:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Zc5BCoAgEIXhq8SsAx11LF276QziQsJFm4Lw/hQyBdny8fHDixGWvZYzr3U79mEJMELItUAaI6DS9zTCCCXRDai9lB+YGOYe5rfQX0BkwSfRhpoQA/WAkkX9RPXHyE5NLIPrwTFYjwQpXQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"(blank)" = _t, #"(blank).1" = _t]),
    #"Promoted Headers" = Table.PromoteHeaders(Source, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Interaction ID", Int64.Type}, {"Date", type datetime}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Interaction ID"}, {{"A", each Table.AddIndexColumn(_,"Index",1,1), type table }}),
    #"Expanded A" = Table.ExpandTableColumn(#"Grouped Rows", "A", {"Date", "Index"}, {"A.Date", "A.Index"})
in
    #"Expanded A"

Result:

1.PNG

You could also download the pbix file to have a view.

 

Regards,

Daniel He

Community Support Team _ Daniel He
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

Hi,

This M code works

let
    Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Interaction ID", Int64.Type}, {"Date", type datetime}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"Interaction ID", Order.Ascending}, {"Date", Order.Ascending}}),
    Partition = Table.Group(#"Sorted Rows", {"Interaction ID"}, {{"Partition", each Table.AddIndexColumn(_, "Index",1,1), type table}}),
    #"Expanded Partition" = Table.ExpandTableColumn(Partition, "Partition", {"Date", "Index"}, {"Date", "Index"})
in
    #"Expanded Partition"

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

7 REPLIES 7
v-danhe-msft
Microsoft Employee
Microsoft Employee

Hi @filarap ,

You could refer to below code:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Zc5BCoAgEIXhq8SsAx11LF276QziQsJFm4Lw/hQyBdny8fHDixGWvZYzr3U79mEJMELItUAaI6DS9zTCCCXRDai9lB+YGOYe5rfQX0BkwSfRhpoQA/WAkkX9RPXHyE5NLIPrwTFYjwQpXQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"(blank)" = _t, #"(blank).1" = _t]),
    #"Promoted Headers" = Table.PromoteHeaders(Source, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Interaction ID", Int64.Type}, {"Date", type datetime}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Interaction ID"}, {{"A", each Table.AddIndexColumn(_,"Index",1,1), type table }}),
    #"Expanded A" = Table.ExpandTableColumn(#"Grouped Rows", "A", {"Date", "Index"}, {"A.Date", "A.Index"})
in
    #"Expanded A"

Result:

1.PNG

You could also download the pbix file to have a view.

 

Regards,

Daniel He

Community Support Team _ Daniel He
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
parry2k
Super User
Super User

@filarap here is sample power query, change it as per your need.

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Xc/LCUAhDETRVh5ZC2YS468Vsf82BIkPdH3gTjIGQZQCpZiiMNoH7cw0wyBNtsEc7IDlsiE7tAMnVRzqC/Xf0DvVHHKHXeNgF3lbgAvegyHXK3MB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"Interaction ID" = _t, Date = _t]),
    #"Grouped Rows" = Table.Group(Source, {"Interaction ID"}, {{"Count", each Table.RowCount(_), type number}, {"AllRows", each _, type table [Interaction ID=text, Date=text]}}),
    #"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Index", 1, 1),
    #"Removed Columns" = Table.RemoveColumns(#"Added Index",{"Count"}),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Removed Columns", "AllRows", {"Date"}, {"Date"})
in
    #"Expanded AllRows"


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Thank you parry2K,

 

With this query i was able to get

Interaction IDDateIndex

1234/4/2019 13:001
1234/7/2019 18:001
1234/8/2019 13:301
1234/11/2019 11:001
3454/5/2019 15:002
3454/10/2019 12:002
3454/12/2019 13:002
5674/6/2019 19:003
5674/9/2019 16:153

 

But i am trying to achieve ordinal numbers based on ID sorted by date/time (Earliest would be number 1)

 

Interaction IDDateIndex
1234/4/2019 13:001
1234/7/2019 18:002
1234/8/2019 13:303
1234/11/2019 11:004
3454/5/2019 15:001
3454/10/2019 12:002
3454/12/2019 13:003
5674/6/2019 19:001
5674/9/2019 16:152

 

Is this possible?

Filarap

Hi,

This M code works

let
    Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Interaction ID", Int64.Type}, {"Date", type datetime}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"Interaction ID", Order.Ascending}, {"Date", Order.Ascending}}),
    Partition = Table.Group(#"Sorted Rows", {"Interaction ID"}, {{"Partition", each Table.AddIndexColumn(_, "Index",1,1), type table}}),
    #"Expanded Partition" = Table.ExpandTableColumn(Partition, "Partition", {"Date", "Index"}, {"Date", "Index"})
in
    #"Expanded Partition"

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Thank you all,

 

Several working solution for me to try.

Much apreciated.

 

Regards

Filarap

You are welcome.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

@filarap try this

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Xc/LCUAhDETRVh5ZC2YS468Vsf82BIkPdH3gTjIGQZQCpZiiMNoH7cw0wyBNtsEc7IDlsiE7tAMnVRzqC/Xf0DvVHHKHXeNgF3lbgAvegyHXK3MB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"Interaction ID" = _t, Date = _t]),
    #"Grouped Rows" = Table.Group(Source, {"Interaction ID"}, {{"Rank", each Table.AddIndexColumn(_, "Rank", 1)}}),
    #"Expanded Rank1" = Table.ExpandTableColumn(#"Grouped Rows", "Rank", {"Date", "Rank"}, {"Date", "Rank"})
in
    #"Expanded Rank1"


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

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.

Top Solution Authors