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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
joshua1990
Post Prodigy
Post Prodigy

GROUP with MIN and MAX

Hi experts!

I would like to pivot / group a huge table that has this structure:

Order Nr Status Date
451 A 01.01.2022
451 A 02.01.2022
451 B 05.01.2022
452 A 05.01.2022
452 C 08.01.2022

 

Now I would like to get for each Order Nr

  • The MIN for Status A
  • And the MAX for Status B & C

In the end it should look like that:

Order NR MIN MAX
451 01.01.2022 05.01.2022
452 05.01.2022 08.01.2022

 

How is this possible in Power Query?

1 ACCEPTED SOLUTION
v-jingzhang
Community Support
Community Support

Hi @joshua1990 

 

This is my solution. 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjE1VNJRcgRiA0M9IDIyMDJSitVBkTDCIuEEkjBFkzCC6cAm4QySsEBIxAIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Order Nr" = _t, Status = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Order Nr", Int64.Type}, {"Status", type text}, {"Date", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "new Status", each if [Status] = "A" then "A" else "B & C"),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Order Nr", "new Status"}, {{"All Data", each _, type table [Order Nr=nullable number, Status=nullable text, Date=nullable date, new Status=text]}}),
    #"Added Custom1" = Table.AddColumn(#"Grouped Rows", "MIN Date", each List.Min([All Data][Date])),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "MAX Date", each List.Max([All Data][Date])),
    #"Added Custom3" = Table.AddColumn(#"Added Custom2", "MIN", each if [new Status] = "A" then [MIN Date] else null),
    #"Added Custom4" = Table.AddColumn(#"Added Custom3", "MAX", each if [new Status] = "B & C" then [MAX Date] else null),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom4",{"Order Nr", "MIN", "MAX"}),
    #"Grouped Rows1" = Table.Group(#"Removed Other Columns", {"Order Nr"}, {{"MIN", each List.Max([MIN]), type nullable date}, {"MAX", each List.Max([MAX]), type nullable date}})
in
    #"Grouped Rows1"

vjingzhang_0-1661940723569.png

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

2 REPLIES 2
v-jingzhang
Community Support
Community Support

Hi @joshua1990 

 

This is my solution. 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjE1VNJRcgRiA0M9IDIyMDJSitVBkTDCIuEEkjBFkzCC6cAm4QySsEBIxAIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Order Nr" = _t, Status = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Order Nr", Int64.Type}, {"Status", type text}, {"Date", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "new Status", each if [Status] = "A" then "A" else "B & C"),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Order Nr", "new Status"}, {{"All Data", each _, type table [Order Nr=nullable number, Status=nullable text, Date=nullable date, new Status=text]}}),
    #"Added Custom1" = Table.AddColumn(#"Grouped Rows", "MIN Date", each List.Min([All Data][Date])),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "MAX Date", each List.Max([All Data][Date])),
    #"Added Custom3" = Table.AddColumn(#"Added Custom2", "MIN", each if [new Status] = "A" then [MIN Date] else null),
    #"Added Custom4" = Table.AddColumn(#"Added Custom3", "MAX", each if [new Status] = "B & C" then [MAX Date] else null),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom4",{"Order Nr", "MIN", "MAX"}),
    #"Grouped Rows1" = Table.Group(#"Removed Other Columns", {"Order Nr"}, {{"MIN", each List.Max([MIN]), type nullable date}, {"MAX", each List.Max([MAX]), type nullable date}})
in
    #"Grouped Rows1"

vjingzhang_0-1661940723569.png

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

Migasuke
Super User
Super User

Hi @joshua1990 ,

In your case only simple group by based on Order Nr would be sufficient.

Migasuke_0-1661582042845.png

Migasuke_1-1661582275411.png

 


Can you give a better example with Status A and B,C?

 



If my answer was helpful please give me a Kudos or even accept as a Solution.

Let's connect on LinkedIn!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors