Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!To celebrate FabCon Vienna, we are offering 50% off select exams. Ends October 3rd. Request your discount now.
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.
User | Activity | Date | Time |
B | ABC | 1-Mar-21 | 10:44:26 AM |
B | ABC | 1-Mar-21 | 10:44:26 AM |
B | ABC | 1-Mar-21 | 10:44:27 AM |
B | ABC | 1-Mar-21 | 10:44:27 AM |
B | ABC | 1-Mar-21 | 10:44:28 AM |
B | ABC | 1-Mar-21 | 10:44:29 AM |
B | ABC | 1-Mar-21 | 10:44:29 AM |
B | ABC | 1-Mar-21 | 10:44:29 AM |
B | ABC | 1-Mar-21 | 10:44:30 AM |
B | ABC | 1-Mar-21 | 10:44:31 AM |
B | ABC | 1-Mar-21 | 10:44:31 AM |
B | ABC | 1-Mar-21 | 10:44:32 AM |
C | ABC | 2-Mar-21 | 12:00:35 AM |
C | ABC | 2-Mar-21 | 3:30:09 AM |
C | ABC | 2-Mar-21 | 3:30:10 AM |
C | ABC | 2-Mar-21 | 3:30:11 AM |
C | ABC | 2-Mar-21 | 3:30:14 AM |
C | ABC | 2-Mar-21 | 4:00:14 AM |
C | ABC | 2-Mar-21 | 4:00:14 AM |
C | ABC | 2-Mar-21 | 4:00:15 AM |
C | ABC | 2-Mar-21 | 4:00:15 AM |
A | ABC | 2-Mar-21 | 10:44:26 AM |
A | ABC | 2-Mar-21 | 10:44:27 AM |
A | ABC | 2-Mar-21 | 10:44:28 AM |
A | ABC | 2-Mar-21 | 10:44:29 AM |
A | ABC | 2-Mar-21 | 10:44:30 AM |
A | ABC | 2-Mar-21 | 10:44:30 AM |
A | ABC | 2-Mar-21 | 10:44:31 AM |
A | ABC | 2-Mar-21 | 10:44:31 AM |
A | ABC | 2-Mar-21 | 10:44:32 AM |
A | ABC | 2-Mar-21 | 10:44:32 AM |
A | ABC | 2-Mar-21 | 10:44:32 AM |
A | ABC | 2-Mar-21 | 10:44:32 AM |
A | ABC | 2-Mar-21 | 10:44:33 AM |
Solved! Go to Solution.
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"
Measure = FORMAT(SUM(TableName[Duration]),"hh:mm:ss")
Proud to be a Super User!
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"
Measure = FORMAT(SUM(TableName[Duration]),"hh:mm:ss")
Proud to be a Super User!