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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
ANB_13
Helper I
Helper I

Calculate the difference in minutes between lines

Good morning,
I need your help,

 

I am working on a dataset with a [Date] column in Date & Time format. as following :

ANB_13_0-1706709715395.png

 

I want to create a new column which calculates the difference for successive rows. The result of the 5 new lines should be:
5. How can i do ?

 

Thank you very much 

Regards

1 ACCEPTED SOLUTION
amustafa
Super User
Super User

Hi, create a blank query and paste the following code to see how you can create a calulated column for minutes lapsed between rows.

 

let
StartDateTime = #datetime(2024, 1, 1, 0, 0, 0),
EndDateTime = #datetime(2024, 1, 2, 0, 0, 0),
DurationInMinutes = 5,
Source = List.Generate(
() => StartDateTime,
(DateTime) => DateTime < EndDateTime,
(DateTime) => DateTime + #duration(0, 0, DurationInMinutes, 0)
),
TableFromList = Table.FromList(Source, Splitter.SplitByNothing(), {"DateTime"}),
ChangedType = Table.TransformColumnTypes(TableFromList, {{"DateTime", type datetime}}),
SortedTable = Table.Sort(ChangedType, {{"DateTime", Order.Ascending}}),
AddIndex = Table.AddIndexColumn(SortedTable, "Index", 0, 1, Int64.Type),
AddMinutesLapsed = Table.AddColumn(AddIndex, "Minutes Lapsed", each if [Index] = 0 then 0 else Duration.TotalMinutes([DateTime] - (AddIndex{[Index]-1}[DateTime])), type number)
in
AddMinutesLapsed

 

If I answered your question, please mark this thread as accepted and Thums Up!
Follow me on LinkedIn:
https://www.linkedin.com/in/mustafa-ali-70133451/





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

5 REPLIES 5
amustafa
Super User
Super User

Watch this video to learn Power Query Advance Editor where you paste the code.

Best Practice Tips For Using The Advanced Editor In Power BI [2022 Update] (youtube.com)





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




AlienSx
Super User
Super User

@dufoq3 this must be accompanied by v3 with list shift 😁

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjDSNzDUNzIwMlYwtzIwVYrVQRMzNMQUMzJDF7O0MjZSio0FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t]),
    dt = Table.TransformColumnTypes(Source,{{"Date", type datetime}}),
    diff_lst = List.Buffer(List.Zip({dt[Date], {List.First(dt[Date])} & List.RemoveLastN(dt[Date], 1)})),
    diff_col = List.Transform(diff_lst, (x) => Duration.Minutes(x{0} - x{1})),
    tbl = Table.FromColumns(Table.ToColumns(dt) & {diff_col}, Table.ColumnNames(dt) & {"diff"})
in
    tbl

 

dufoq3
Super User
Super User

Hi @ANB_13,

dufoq3_0-1706723508361.png

 

You can find 2 versions of code here:

//Calculate the difference in minutes between lines
//https://community.fabric.microsoft.com/t5/Power-Query/Calculate-the-difference-in-minutes-between-lines/m-p/3670461#M120753

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjDSNzDUNzIwMlYwtzIwVYrVQRMzNMQUMzJDF7O0MjZSio0FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type datetime}}),
    v1_Slower_AddedIndex = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    v1_Slower_Difference = Table.RemoveColumns(Table.AddColumn(v1_Slower_AddedIndex, "Difference d:hh:mm:ss", each try [Date] - v1_Slower_AddedIndex{[Index]-1}?[Date] otherwise null, type duration), {"Index"}),
    v2_Faster_Difference = 
        Table.RenameColumns(
            Table.FromRecords(
                [timesList = List.Buffer(#"Changed Type"[Date]),
                lg = 
                    List.Generate(
                        ()=>  [ x = 0, DateTime = timesList{0}, Difference = null ],
                        each  [x] < List.Count(timesList),
                        each  [ x = [x]+1, DateTime = timesList{x}, Difference = DateTime - [DateTime] ],
                        each  [ [DateTime], [Difference] ]
                    )
                ][lg],
                type table[DateTime = datetime, Difference = duration]
            ),
            {{"DateTime", "Date Time"}, {"Difference", "Difference d:hh:mm:ss"}}
        )
in
    v2_Faster_Difference

 


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

Good morning, 

 

Where do i use this code ? 

 

Thank you 

amustafa
Super User
Super User

Hi, create a blank query and paste the following code to see how you can create a calulated column for minutes lapsed between rows.

 

let
StartDateTime = #datetime(2024, 1, 1, 0, 0, 0),
EndDateTime = #datetime(2024, 1, 2, 0, 0, 0),
DurationInMinutes = 5,
Source = List.Generate(
() => StartDateTime,
(DateTime) => DateTime < EndDateTime,
(DateTime) => DateTime + #duration(0, 0, DurationInMinutes, 0)
),
TableFromList = Table.FromList(Source, Splitter.SplitByNothing(), {"DateTime"}),
ChangedType = Table.TransformColumnTypes(TableFromList, {{"DateTime", type datetime}}),
SortedTable = Table.Sort(ChangedType, {{"DateTime", Order.Ascending}}),
AddIndex = Table.AddIndexColumn(SortedTable, "Index", 0, 1, Int64.Type),
AddMinutesLapsed = Table.AddColumn(AddIndex, "Minutes Lapsed", each if [Index] = 0 then 0 else Duration.TotalMinutes([DateTime] - (AddIndex{[Index]-1}[DateTime])), type number)
in
AddMinutesLapsed

 

If I answered your question, please mark this thread as accepted and Thums Up!
Follow me on LinkedIn:
https://www.linkedin.com/in/mustafa-ali-70133451/





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Power BI Monthly Update - May 2024

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

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

Top Solution Authors
Top Kudoed Authors