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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
seb_BMW
New Member

compute time difference between two lines in table

I have the following table:

 

Nr      position       time

1            in              12:23:10

2            in              12:25:19

1            out            12:28:59

3            in              13:00:00

2            out            13:02:10

 

and want to compute the time difference between in and out of each number, so that i have in this example:

 

Nr          diff

1            00:05:49

2            00:06:51

3            null     (or another text like "in")

 

how can i do this ? 

thank you very much

 

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

You're looking for the Pivot function.

 

  • Pivot on Position (Value is Time, and be sure not to aggregate)
  • Use M to subtract the resulting in/out column values
  • Convert datatype to the Duration type

Screenshots:

PBIDesktop_2017-07-14_09-33-46.png2017-07-14_09-35-14.pngPBIDesktop_2017-07-14_09-37-26.png

 

The line of M:

#"Added Difference" = Table.AddColumn(#"Pivoted Column", "Diff", each [out] - [in]),

View solution in original post

v-yulgu-msft
Employee
Employee

Hi @seb_BMW,

 

Alternatively, you can achieve this in DAX.

 

Create a calculated table based on below formula.

new table =
SUMMARIZE (
    'time difference',
    'time difference'[Nr],
    "time diff", DATEDIFF (
        MIN ( 'time difference'[time] ),
        MAX ( 'time difference'[time] ),
        SECOND
    )
)

Add a calculated column in order to format the time difference.

Column =
IF (
    'new table'[time diff] = 0,
    BLANK (),
    INT ( 'new table'[time diff] / 3600 )
        & ":"
        & INT ( MOD ( 'new table'[time diff], 3600 ) / 60 )
        & ":"
        & MOD ( MOD ( 'new table'[time diff], 3600 )60 )
)
Community Support Team _ Yuliana Gu
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

3 REPLIES 3
v-yulgu-msft
Employee
Employee

Hi @seb_BMW,

 

Have you worked it out? If so, would you please mark the corresponding reply as an answer? If you still have any concern, please feel free to ask.

 

Regards,
Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
v-yulgu-msft
Employee
Employee

Hi @seb_BMW,

 

Alternatively, you can achieve this in DAX.

 

Create a calculated table based on below formula.

new table =
SUMMARIZE (
    'time difference',
    'time difference'[Nr],
    "time diff", DATEDIFF (
        MIN ( 'time difference'[time] ),
        MAX ( 'time difference'[time] ),
        SECOND
    )
)

Add a calculated column in order to format the time difference.

Column =
IF (
    'new table'[time diff] = 0,
    BLANK (),
    INT ( 'new table'[time diff] / 3600 )
        & ":"
        & INT ( MOD ( 'new table'[time diff], 3600 ) / 60 )
        & ":"
        & MOD ( MOD ( 'new table'[time diff], 3600 )60 )
)
Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Anonymous
Not applicable

You're looking for the Pivot function.

 

  • Pivot on Position (Value is Time, and be sure not to aggregate)
  • Use M to subtract the resulting in/out column values
  • Convert datatype to the Duration type

Screenshots:

PBIDesktop_2017-07-14_09-33-46.png2017-07-14_09-35-14.pngPBIDesktop_2017-07-14_09-37-26.png

 

The line of M:

#"Added Difference" = Table.AddColumn(#"Pivoted Column", "Diff", each [out] - [in]),

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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