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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Calculated Column: TIme difference to next rowset

Hello:

 I am writing to ask if it is possible to create a calculated column which calculates the time difference ( Duration ) between the next rowset ( timestamp ) ? Please see example below. Thank you for your time.

 

error numerror textcategory numcategory texttimestamptime no millisIndexshort nameLine NameIndexAllDuration (Minutes)
3030S010 MACHINE IS RUNNING7MACHINE RUNNING3/3/2021 16:203/3/2021 16:20368CX482 S010CX482 BASELINE ONE3687
3000S010 MACHINE IS IDLE2MACHINE IDLE3/3/2021 16:273/3/2021 16:27369CX482 S010CX482 BASELINE ONE3693
3030S010 MACHINE IS RUNNING7MACHINE RUNNING3/3/2021 16:303/3/2021 16:30370CX482 S010CX482 BASELINE ONE37013
3000S010 MACHINE IS IDLE2MACHINE IDLE3/3/2021 16:433/3/2021 16:43371CX482 S010CX482 BASELINE ONE3710
3030S010 MACHINE IS RUNNING7MACHINE RUNNING3/3/2021 16:433/3/2021 16:43372CX482 S010CX482 BASELINE ONE37240
3000S010 MACHINE IS IDLE2MACHINE IDLE3/3/2021 17:233/3/2021 17:23373CX482 S010CX482 BASELINE ONE3739
3030S010 MACHINE IS RUNNING7MACHINE RUNNING3/3/2021 17:323/3/2021 17:32374CX482 S010CX482 BASELINE ONE37418
549+S011 ERROR FIXTURE 1 CYLINDER 17.3 NOT REVERSE1MACHINE ERRORS3/3/2021 17:503/3/2021 17:50375CX482 S010CX482 BASELINE ONE375 
1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

if you need a solution in Power Query then you can add a custom column with this formula. You have to replace the "PreviousStep" with the name of your previous step. Be aware that i use your index column for referencing the "next" step. Here the formula

 

try Duration.TotalMinutes(Table.SelectRows(PreviousStep, (sel)=> sel[Index] = [Index]+1)[timestamp]{0} - [timestamp]) otherwise null

 

here a complete code example to understand it better

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("rZLRagIxEEV/ZdjXik5msju6b7qmNWCzkGixyP7/b5jYbbUSIbA+JJCTmcnhkvO5YmSsZlVAhfC57nbWGbAB/NE56z7ijcT1e3GjvOAFISlQTUuYBc0y7t1JLwnS9L/DZh3MPk3rnRnrhlkSwZyI3e5TFd1ZjOjfi5IFzapQYTUqTM6CH7P4AYJlIrFuchaas0BUoYJ6VRbPRKhQhKZmIS1xFggXKvBrspCWKQtEF4roq0it04d+i6UKjPe9h3d7Ohy9AQXdd2zYGh+HzxlcfwBvvowPqV/d+V37woNNjVkgdaFeXQ3DBQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"rror num" = _t, #"error text" = _t, #"category num" = _t, #"category text" = _t, timestamp = _t, #"time no millis" = _t, Index = _t, #"short name" = _t, #"Line Name" = _t, IndexAll = _t]),
    PreviousStep = Table.TransformColumnTypes(Source,{{"rror num", Int64.Type}, {"error text", type text}, {"category num", Int64.Type}, {"category text", type text}, {"timestamp", type datetime}, {"time no millis", type datetime}, {"Index", Int64.Type}, {"short name", type text}, {"Line Name", type text}, {"IndexAll", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(PreviousStep, "Custom", each try Duration.TotalMinutes(Table.SelectRows(PreviousStep, (sel)=> sel[Index] = [Index]+1)[timestamp]{0} - [timestamp]) otherwise null)
in
    #"Added Custom"

 

output

Jimmy801_0-1614927302680.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

3 REPLIES 3
Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

if you need a solution in Power Query then you can add a custom column with this formula. You have to replace the "PreviousStep" with the name of your previous step. Be aware that i use your index column for referencing the "next" step. Here the formula

 

try Duration.TotalMinutes(Table.SelectRows(PreviousStep, (sel)=> sel[Index] = [Index]+1)[timestamp]{0} - [timestamp]) otherwise null

 

here a complete code example to understand it better

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("rZLRagIxEEV/ZdjXik5msju6b7qmNWCzkGixyP7/b5jYbbUSIbA+JJCTmcnhkvO5YmSsZlVAhfC57nbWGbAB/NE56z7ijcT1e3GjvOAFISlQTUuYBc0y7t1JLwnS9L/DZh3MPk3rnRnrhlkSwZyI3e5TFd1ZjOjfi5IFzapQYTUqTM6CH7P4AYJlIrFuchaas0BUoYJ6VRbPRKhQhKZmIS1xFggXKvBrspCWKQtEF4roq0it04d+i6UKjPe9h3d7Ohy9AQXdd2zYGh+HzxlcfwBvvowPqV/d+V37woNNjVkgdaFeXQ3DBQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"rror num" = _t, #"error text" = _t, #"category num" = _t, #"category text" = _t, timestamp = _t, #"time no millis" = _t, Index = _t, #"short name" = _t, #"Line Name" = _t, IndexAll = _t]),
    PreviousStep = Table.TransformColumnTypes(Source,{{"rror num", Int64.Type}, {"error text", type text}, {"category num", Int64.Type}, {"category text", type text}, {"timestamp", type datetime}, {"time no millis", type datetime}, {"Index", Int64.Type}, {"short name", type text}, {"Line Name", type text}, {"IndexAll", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(PreviousStep, "Custom", each try Duration.TotalMinutes(Table.SelectRows(PreviousStep, (sel)=> sel[Index] = [Index]+1)[timestamp]{0} - [timestamp]) otherwise null)
in
    #"Added Custom"

 

output

Jimmy801_0-1614927302680.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

Anonymous
Not applicable

Jimmy: Thank you very much for the help

PC2790
Community Champion
Community Champion

Hey

 

Try using this DAX in your calculate column:

DifferenceColumn = var nextIndex = SampleTable[Index] + 1
var nextdate = CALCULATE(VALUES(SampleTable[timestamp]),FILTER(All(SampleTable),SampleTable[Index]=nextIndex))
return DATEDIFF(SampleTable[timestamp],nextdate,MINUTE)

It gives you the diiference column as expected:

PC2790_0-1614907430979.png

Refer this thread for more ways to do it:

https://community.powerbi.com/t5/Desktop/Difference-between-two-rows/m-p/291588

 

Thanks

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors