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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

Calculating Intervals Between Separate Rows of Data

Hi everyone! Really new to PowerBI (when I say new, I just started fiddling with it a week ago)

and I'm having a problem working on this with DAX. I found a similar thread but it doesn't deal with two columns and filtering for more than 4 hours. Feel free to point me in the right direction otherwise.

 

We need to calculate the total interval between the END and START (of next entry) for each person, while ignoring intervals more than 4 hours.

 

  STARTEND
Person 1  5/1/22 15:00  5/1/22 15:30 
Person 1  5/1/22 20:10  5/1/22 20:30 
Person 1  5/1/22 20:40 5/1/22 21:00
Person 2  5/1/22 20:40 5/1/22 21:45
Person 1  5/1/22 21:30 5/1/22 21:40
Person 2  5/1/22 21:50 5/1/22 22:00
Person 3  5/1/22 22:00 5/1/22 23:00
Person 3  5/2/22 3:005/2/22 5:00
Person 3  5/2/22 5:20 5/2/22 5:30

 

- In this case, the interval between END 1 and START 2 will not be added to the computation because it is more than 4 hours

 

The expected output will be as follows :

Person 1 : 0:40 (0:10 + 0:30)

Person 2 : 0:05

Person 3 : 4:20 (4:00 + 0:20)

 

Hope anyone can help me with this as I'm still struggling to combine expressions/measures. Also hope I explained the problem clearly... Thanks in advance, MVPs!

1 ACCEPTED SOLUTION
lbendlin
Super User
Super User

Does it have to be DAX?  This can be solved quicker in Power Query.

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hdAxCsMwDAXQqxjPgVhfVtr6FNlNxq4ttPeHOKoFcYjTzV/o8YVz9uT84Ofn5/t+OX07GWkEHEkK4TDgMliG7NFDCInCYWCIL1BUZJlKs5K4I/hDoiiRbgvpJQ35tUzdFkrSENhhtx3hhqD+mmU2cj8h2FZ0YwOaxPYfvX1JqA01cgHLCg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Person = _t, START = _t, END = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"START", type datetime}, {"END", type datetime}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Person"}, {{"Rows", each _, type table [Index=nullable number, Person=nullable text, START=nullable datetime, END=nullable datetime]}}),
    idx = (tbl)=>Table.AddIndexColumn(tbl, "Index", 0, 1, Int64.Type),
    #"Added Index" = Table.AddColumn(#"Grouped Rows","Rows2",each idx([Rows])),
    diff = (tbl)=> Table.AddColumn(tbl, "Difference", each if [Index]=0 then null else if [START]- tbl{[Index]-1}[END] <= #duration(0,4,0,0) then [START]- tbl{[Index]-1}[END] else null),
    #"Added Custom" = Table.AddColumn(#"Added Index","Rows3",each diff([Rows2])),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Rows3"}),
    #"Expanded Rows3" = Table.ExpandTableColumn(#"Removed Other Columns", "Rows3", {"ID", "Person", "START", "END","Difference"}, {"ID", "Person", "START", "END", "Difference"})

in
    #"Expanded Rows3"

 

How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done".

 

View solution in original post

1 REPLY 1
lbendlin
Super User
Super User

Does it have to be DAX?  This can be solved quicker in Power Query.

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hdAxCsMwDAXQqxjPgVhfVtr6FNlNxq4ttPeHOKoFcYjTzV/o8YVz9uT84Ofn5/t+OX07GWkEHEkK4TDgMliG7NFDCInCYWCIL1BUZJlKs5K4I/hDoiiRbgvpJQ35tUzdFkrSENhhtx3hhqD+mmU2cj8h2FZ0YwOaxPYfvX1JqA01cgHLCg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Person = _t, START = _t, END = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"START", type datetime}, {"END", type datetime}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Person"}, {{"Rows", each _, type table [Index=nullable number, Person=nullable text, START=nullable datetime, END=nullable datetime]}}),
    idx = (tbl)=>Table.AddIndexColumn(tbl, "Index", 0, 1, Int64.Type),
    #"Added Index" = Table.AddColumn(#"Grouped Rows","Rows2",each idx([Rows])),
    diff = (tbl)=> Table.AddColumn(tbl, "Difference", each if [Index]=0 then null else if [START]- tbl{[Index]-1}[END] <= #duration(0,4,0,0) then [START]- tbl{[Index]-1}[END] else null),
    #"Added Custom" = Table.AddColumn(#"Added Index","Rows3",each diff([Rows2])),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Rows3"}),
    #"Expanded Rows3" = Table.ExpandTableColumn(#"Removed Other Columns", "Rows3", {"ID", "Person", "START", "END","Difference"}, {"ID", "Person", "START", "END", "Difference"})

in
    #"Expanded Rows3"

 

How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done".

 

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.