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

Sum workload per maximum Timestamp per caseID

 

I need to calculate Sumworkload, per ID, for the maximum timestamp per day, per assignment group. Sum workload is the result I would like to have.

 

IDTimestampAssignment GroupWorkloadActivitySumworkload
a21-1-2020 21:00abce1open-2
a21-1-2020 21:01abce0in progress-2
a21-1-2020 21:01abde-1reassigned-2
a21-1-2020 21:01abce-1reassigned-2
b22-1-2020 00:00abvn1assigned1
a22-1-2020 09:00abcd1assigned1
2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

split the time_stamp column in two columns "day" and "stamp" then try this:

 

rr = Table.Group(youTab, {"id", "day"}, {{"sum", (s)=> List.Sum(Table.SelectRows(s, each [stamp]=List.Max(s[stamp]))[work])},{"cols", each _}}),
te= Table.ExpandTableColumn(yourTab, "cols", {"stamp", "group", "work"}, {"stamp", "group", "work"})
in
te

View solution in original post

v-juanli-msft
Community Support
Community Support

Hi @Anonymous 

As tested, Rocco_sprmnt21's answer works.

To add "per assignment group" in your conditions, please modify the query as below and paste in your Advanced editor.

Capture4.JPG

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jdDBCoAgDADQXwnPCdtu9SviQXNIFxWFvj+Fyg5FHcbG2GNsSgkjRkEoURIQDIQzQO0Yu3BNWCMmDjVJEnp8Gsc+3uQahpSjz1zKt3JNyVZnNqWsPrD7uetV2aboVADnQVs4DroR7Hu6mK4XuEehdw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Timestamp = _t, #"Assignment Group" = _t, Workload = _t, Activity = _t, Sumworkload = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Timestamp", type text}, {"Assignment Group", type text}, {"Workload", Int64.Type}, {"Activity", type text}, {"Sumworkload", Int64.Type}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Timestamp", Splitter.SplitTextByDelimiter(" ", QuoteStyle.Csv), {"day", "stamp"}),
    rr = Table.Group(#"Split Column by Delimiter", {"ID", "day","Assignment Group"}, {{"sum", (s)=> List.Sum(Table.SelectRows(s, each [stamp]=List.Max(s[stamp]))[Workload])},{"cols", each _}}),
    #"Grouped Rows" = Table.Group(rr, {"ID", "day"}, {{"sum2", each List.Sum([sum]), type number}, {"all", each _, type table [ID=text, day=text, Assignment Group=text, sum=number, cols=table]}}),
    #"Expanded all" = Table.ExpandTableColumn(#"Grouped Rows", "all", {"cols"}, {"all.cols"}),
    #"Expanded all.cols" = Table.ExpandTableColumn(#"Expanded all", "all.cols", {"stamp", "Assignment Group", "Workload", "Activity"}, {"all.cols.stamp", "all.cols.Assignment Group", "all.cols.Workload", "all.cols.Activity"})
in
    #"Expanded all.cols"

 

Best Regards
Maggie
Community Support Team _ Maggie Li
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

2 REPLIES 2
v-juanli-msft
Community Support
Community Support

Hi @Anonymous 

As tested, Rocco_sprmnt21's answer works.

To add "per assignment group" in your conditions, please modify the query as below and paste in your Advanced editor.

Capture4.JPG

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jdDBCoAgDADQXwnPCdtu9SviQXNIFxWFvj+Fyg5FHcbG2GNsSgkjRkEoURIQDIQzQO0Yu3BNWCMmDjVJEnp8Gsc+3uQahpSjz1zKt3JNyVZnNqWsPrD7uetV2aboVADnQVs4DroR7Hu6mK4XuEehdw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Timestamp = _t, #"Assignment Group" = _t, Workload = _t, Activity = _t, Sumworkload = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Timestamp", type text}, {"Assignment Group", type text}, {"Workload", Int64.Type}, {"Activity", type text}, {"Sumworkload", Int64.Type}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Timestamp", Splitter.SplitTextByDelimiter(" ", QuoteStyle.Csv), {"day", "stamp"}),
    rr = Table.Group(#"Split Column by Delimiter", {"ID", "day","Assignment Group"}, {{"sum", (s)=> List.Sum(Table.SelectRows(s, each [stamp]=List.Max(s[stamp]))[Workload])},{"cols", each _}}),
    #"Grouped Rows" = Table.Group(rr, {"ID", "day"}, {{"sum2", each List.Sum([sum]), type number}, {"all", each _, type table [ID=text, day=text, Assignment Group=text, sum=number, cols=table]}}),
    #"Expanded all" = Table.ExpandTableColumn(#"Grouped Rows", "all", {"cols"}, {"all.cols"}),
    #"Expanded all.cols" = Table.ExpandTableColumn(#"Expanded all", "all.cols", {"stamp", "Assignment Group", "Workload", "Activity"}, {"all.cols.stamp", "all.cols.Assignment Group", "all.cols.Workload", "all.cols.Activity"})
in
    #"Expanded all.cols"

 

Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

split the time_stamp column in two columns "day" and "stamp" then try this:

 

rr = Table.Group(youTab, {"id", "day"}, {{"sum", (s)=> List.Sum(Table.SelectRows(s, each [stamp]=List.Max(s[stamp]))[work])},{"cols", each _}}),
te= Table.ExpandTableColumn(yourTab, "cols", {"stamp", "group", "work"}, {"stamp", "group", "work"})
in
te

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.

Top Solution Authors