Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hello.
I've been trying to solve this for weeks now so I'm asking for some help!
Basically, I have a list of items that can be in several sprints and for each sprint they are in I want to keep the record of the first date IN THE SPRINT and the last date IN THE SPRINT. I tried this in PowerQuery but it gives me the min date accross all sprints, not by sprint :
= Table.Group(#"Source", {"Work Item Id", "Iteration Path"}, {{"DateMin", each Table.Min(_, "Date")}})
Here is my sample data :
SAMPLE DATA | |||
Item ID | Iteration path | State | Date |
100 | Sprint 1 | Open | 1/1/2023 |
100 | Sprint 1 | Open | 2/1/2023 |
100 | Sprint 1 | Open | 3/1/2023 |
100 | Sprint 1 | Closed | 4/1/2023 |
100 | Sprint 2 | Closed | 5/1/2023 |
100 | Sprint 2 | Closed | 6/1/2023 |
200 | Sprint 1 | Open | 3/1/2023 |
200 | Sprint 1 | Closed | 4/1/2023 |
And the result I'm trying to get using power query :
EXPECTED RESULT | |||||
Item ID | Iteration path | State | Date | Comment (not needed in result) | |
100 | Sprint 1 | Open | 1/1/2023 | Min date in sprint 1 for item 100 | |
100 | Sprint 1 | Closed | 4/1/2023 | Max date in sprint 1 for item 100 | |
100 | Sprint 2 | Closed | 5/1/2023 | Min date in sprint 2 for item 100 | |
100 | Sprint 2 | Closed | 6/1/2023 | Max date in sprint 2 for item 100 | |
200 | Sprint 1 | Open | 3/1/2023 | Min date in sprint 1 for item 200 | |
200 | Sprint 1 | Closed | 4/1/2023 | Max date in sprint 1 for item 200 |
I don't see how I can upload my sample data file but I copied/pasted the tables above.
Thanks in advance for your help !
Solved! Go to Solution.
Hi @ilamoureuse,
You must have been so close, you were on the right track...
Here's a fully user interface driven solution.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwUNJRCi4oyswrUTAEMv0LUvOAlIGhLhAZGSvF6uBRZESMImN8ipxz8otTU0DKTHApM0JRZkqcMjMkZUbEuAxDERaXxQIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Item ID" = _t, #"Iteration path" = _t, State = _t, Date = _t]),
ChType = Table.TransformColumnTypes(Source,{{"Date", type date}}),
GroupRows = Table.Group(ChType, {"Item ID", "Iteration path"}, {{"Min Date", each List.Min([Date]), type nullable date}, {"Max Date", each List.Max([Date]), type nullable date}}),
UnpivotOthers = Table.UnpivotOtherColumns(GroupRows, {"Item ID", "Iteration path"}, "Attribute", "Value"),
SelfMerge = Table.NestedJoin(UnpivotOthers, {"Item ID", "Iteration path", "Value"}, ChType, {"Item ID", "Iteration path", "Date"}, "UnpivotOthers", JoinKind.LeftOuter),
GetState = Table.ExpandTableColumn(SelfMerge, "UnpivotOthers", {"State"}, {"State"})
in
GetState
The Group by returns this
Selecting both columns "Item ID" and "Iteration path" and unpivoting others
Note you can rename both new "Attribute" and "Value" columns here directly inside the formula bar
And finally do a self merge to get the State
Ps. If this helps solve your query please mark this post as Solution, thanks!
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwUNJRCi4oyswrUTAEMv0LUvOAlKG+gaG+kYGRsVKsDm5VRkSpMsavyjknvzg1Bcgwwa3OCFmdKZHqzFDUGRHlOgxV2FwXCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Item ID" = _t, #"Iteration path" = _t, State = _t, Date = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Item ID", Int64.Type}, {"Iteration path", type text}, {"State", type text}, {"Date", type date}}),
Grouped = Table.Group(#"Changed Type", {"Item ID","Iteration path"}, {"Grp", each Table.FromRecords({Table.First(_), Table.Last(_)})}, 0),
#"Expanded Grp" = Table.ExpandTableColumn(Grouped, "Grp", {"State", "Date"}, {"State", "Date"})
in
#"Expanded Grp"
Expertise = List.Accumulate( {Days as from Today}, {Skills and Knowledge}, (Current, Everyday) => Current & Day.LearnAndPractise(Everyday) ) |
Hi @ilamoureuse,
You must have been so close, you were on the right track...
Here's a fully user interface driven solution.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwUNJRCi4oyswrUTAEMv0LUvOAlIGhLhAZGSvF6uBRZESMImN8ipxz8otTU0DKTHApM0JRZkqcMjMkZUbEuAxDERaXxQIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Item ID" = _t, #"Iteration path" = _t, State = _t, Date = _t]),
ChType = Table.TransformColumnTypes(Source,{{"Date", type date}}),
GroupRows = Table.Group(ChType, {"Item ID", "Iteration path"}, {{"Min Date", each List.Min([Date]), type nullable date}, {"Max Date", each List.Max([Date]), type nullable date}}),
UnpivotOthers = Table.UnpivotOtherColumns(GroupRows, {"Item ID", "Iteration path"}, "Attribute", "Value"),
SelfMerge = Table.NestedJoin(UnpivotOthers, {"Item ID", "Iteration path", "Value"}, ChType, {"Item ID", "Iteration path", "Date"}, "UnpivotOthers", JoinKind.LeftOuter),
GetState = Table.ExpandTableColumn(SelfMerge, "UnpivotOthers", {"State"}, {"State"})
in
GetState
The Group by returns this
Selecting both columns "Item ID" and "Iteration path" and unpivoting others
Note you can rename both new "Attribute" and "Value" columns here directly inside the formula bar
And finally do a self merge to get the State
Ps. If this helps solve your query please mark this post as Solution, thanks!
Check out the July 2025 Power BI update to learn about new features.