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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
ilamoureuse
Regular Visitor

Min and max date rows for item in each category

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 IDIteration pathStateDate
100Sprint 1Open1/1/2023
100Sprint 1Open2/1/2023
100Sprint 1Open3/1/2023
100Sprint 1Closed4/1/2023
100Sprint 2Closed5/1/2023
100Sprint 2Closed6/1/2023
200Sprint 1Open3/1/2023
200Sprint 1Closed4/1/2023

 

And the result I'm trying to get using power query :

EXPECTED RESULT     
Item IDIteration pathStateDate Comment (not needed in result)
100Sprint 1Open1/1/2023 Min date in sprint 1 for item 100
100Sprint 1Closed4/1/2023 Max date in sprint 1 for item 100
100Sprint 2Closed5/1/2023 Min date in sprint 2 for item 100
100Sprint 2Closed6/1/2023 Max date in sprint 2 for item 100
200Sprint 1Open3/1/2023 Min date in sprint 1 for item 200
200Sprint 1Closed4/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 !

1 ACCEPTED SOLUTION
m_dekorte
Super User
Super User

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

m_dekorte_0-1682699623912.png

 

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

m_dekorte_1-1682699655578.png

 

And finally do a self merge to get the State

m_dekorte_2-1682700154300.png

 

Ps. If this helps solve your query please mark this post as Solution, thanks!

View solution in original post

3 REPLIES 3
ilamoureuse
Regular Visitor

Thank you so much @m_dekorte !

ThxAlot
Super User
Super User

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"

ThxAlot_0-1682704333569.png



Expertise = List.Accumulate(


        {Days as from Today},


        {Skills and Knowledge},


        (Current, Everyday) => Current & Day.LeanAndPractise(Everyday)


)



m_dekorte
Super User
Super User

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

m_dekorte_0-1682699623912.png

 

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

m_dekorte_1-1682699655578.png

 

And finally do a self merge to get the State

m_dekorte_2-1682700154300.png

 

Ps. If this helps solve your query please mark this post as Solution, thanks!

Helpful resources

Announcements
September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Top Solution Authors