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

To celebrate FabCon Vienna, we are offering 50% off select exams. Ends October 3rd. Request your discount now.

Reply
affanalvi
Regular Visitor

Sum Total Time Spent on Activity

Dear All, 

I'm working on a report and I have different users performing same activity throughout the day. Each line item is considered as one transaction and I have date and time stamp for each transaction.  

Also, some users are running a batch for the said activity hence there will be different line items / transactions at the same second.

With this data, I am trying to calculate how much time in a day, each user spent on the said activity. Below is example of how the data looks like.  Any idea how can I do this in Power Query. 

 

UserActivityDateTime
BABC1-Mar-2110:44:26 AM
BABC1-Mar-2110:44:26 AM
BABC1-Mar-2110:44:27 AM
BABC1-Mar-2110:44:27 AM
BABC1-Mar-2110:44:28 AM
BABC1-Mar-2110:44:29 AM
BABC1-Mar-2110:44:29 AM
BABC1-Mar-2110:44:29 AM
BABC1-Mar-2110:44:30 AM
BABC1-Mar-2110:44:31 AM
BABC1-Mar-2110:44:31 AM
BABC1-Mar-2110:44:32 AM
CABC2-Mar-2112:00:35 AM
CABC2-Mar-213:30:09 AM
CABC2-Mar-213:30:10 AM
CABC2-Mar-213:30:11 AM
CABC2-Mar-213:30:14 AM
CABC2-Mar-214:00:14 AM
CABC2-Mar-214:00:14 AM
CABC2-Mar-214:00:15 AM
CABC2-Mar-214:00:15 AM
ABC2-Mar-2110:44:26 AM
ABC2-Mar-2110:44:27 AM
ABC2-Mar-2110:44:28 AM
ABC2-Mar-2110:44:29 AM
ABC2-Mar-2110:44:30 AM
ABC2-Mar-2110:44:30 AM
ABC2-Mar-2110:44:31 AM
ABC2-Mar-2110:44:31 AM
ABC2-Mar-2110:44:32 AM
ABC2-Mar-2110:44:32 AM
ABC2-Mar-2110:44:32 AM
ABC2-Mar-2110:44:32 AM
ABC2-Mar-2110:44:33 AM

 

1 ACCEPTED SOLUTION
ChrisMendoza
Resident Rockstar
Resident Rockstar

@affanalvi -

Here's a possibility:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("zdI7CoAwDAbgq0hnhSStj2arzp5AHLyC9x98gA+K1AxBXEKGb/gT/mEwrclNaLt1YtFPc0G4rcDOMVVZ6M2YK6BaDTUS5D9FFiQI1RAdqDsR3RAxANsyiewamsG/GwSBQYFxSeO2zGomfXtkQvb4xajcSVWLVCNSXqKuxikoVFT0U2V3NS4=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [User = _t, Activity = _t, Date = _t, Time = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"User", type text}, {"Activity", type text}, {"Date", type date}, {"Time", type time}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Activity", "User", "Date"}, {{"Grouped", each _, type table [User=nullable text, Activity=nullable text, Date=nullable date, Time=nullable time]}, {"Min", each List.Min([Time]), type nullable time}, {"Max", each List.Max([Time]), type nullable time}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Duration", each DateTime.From([Date]&[Max]) - DateTime.From([Date]&[Min])),
    #"Changed Type1" = Table.TransformColumnTypes(#"Added Custom",{{"Duration", type duration}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"Grouped", "Min", "Max"})
in
    #"Removed Columns"

ChrisMendoza_0-1620406420909.png

Measure = FORMAT(SUM(TableName[Duration]),"hh:mm:ss")





Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

Proud to be a Super User!



View solution in original post

1 REPLY 1
ChrisMendoza
Resident Rockstar
Resident Rockstar

@affanalvi -

Here's a possibility:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("zdI7CoAwDAbgq0hnhSStj2arzp5AHLyC9x98gA+K1AxBXEKGb/gT/mEwrclNaLt1YtFPc0G4rcDOMVVZ6M2YK6BaDTUS5D9FFiQI1RAdqDsR3RAxANsyiewamsG/GwSBQYFxSeO2zGomfXtkQvb4xajcSVWLVCNSXqKuxikoVFT0U2V3NS4=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [User = _t, Activity = _t, Date = _t, Time = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"User", type text}, {"Activity", type text}, {"Date", type date}, {"Time", type time}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Activity", "User", "Date"}, {{"Grouped", each _, type table [User=nullable text, Activity=nullable text, Date=nullable date, Time=nullable time]}, {"Min", each List.Min([Time]), type nullable time}, {"Max", each List.Max([Time]), type nullable time}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Duration", each DateTime.From([Date]&[Max]) - DateTime.From([Date]&[Min])),
    #"Changed Type1" = Table.TransformColumnTypes(#"Added Custom",{{"Duration", type duration}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"Grouped", "Min", "Max"})
in
    #"Removed Columns"

ChrisMendoza_0-1620406420909.png

Measure = FORMAT(SUM(TableName[Duration]),"hh:mm:ss")





Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

Proud to be a Super User!



Helpful resources

Announcements
September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors