cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
jama1234 Frequent Visitor
Frequent Visitor

Group by date and keep all columns

Hi everyone, 

 

I am rather new to Power Bi and i have a question someone might be able to answer.

I have a set of entries for the same ID. I only want to keep the tuple with the most recent Changed Date of each ID. I have found the List.Max function but so far all other columns have been removed except for the one I am grouping by but I need to keep all for this specific date.

 

ID       Changed Date   State     Previous State

207.09.2019ReadyCreated
110.09.2019In WorkImplemented
214.09.2019In WorkImplemented
108.09.2019ReadyCreated
116.09.2019ImplementedDone
209.09.2019CreatedIn Work
110.09.2019CreatedIn Work

 

The output should then be:

 

116.09.2019ImplementedDone
214.09.2019In WorkImplemented

 

Any ideas on how to solve that?

 

Thanks a lot and kind regards!

1 ACCEPTED SOLUTION

Accepted Solutions
Community Support Team
Community Support Team

Re: Group by date and keep all columns

Hi jama1234

You could try below M query

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlLSUTIw1zOw1DMyMLQEcoJSE1MqgbRzUWpiSWqKUqxOtJIhkG9ogKTIM08hPL8oG8TKLchJzU3NgykFmWdoQpRSkKkGFsRYbYZsHpIpOkou+XmpcHuBihDqYIYgXIDVJ1iUxQIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, #"Changed Date" = _t, State = _t, Create = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Changed Date", type text}, {"State", type text}, {"Create", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"max", each List.Max([Changed Date]), type text}, {"all", each _, type table [ID=number, Changed Date=text, State=text, Create=text]}}),
    #"Expanded all" = Table.ExpandTableColumn(#"Grouped Rows", "all", {"Changed Date", "State", "Create"}, {"all.Changed Date", "all.State", "all.Create"}),
    #"selectrow"=Table.SelectRows(#"Expanded all",each [max]=[all.Changed Date]),
    #"Removed Columns" = Table.RemoveColumns(selectrow,{"all.Changed Date"})
in
    #"Removed Columns"

Best Regards,
Zoe Zhi

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
SethuPower Frequent Visitor
Frequent Visitor

Re: Group by date and keep all columns

Please use Group By in Edit Queries using Advanced Option, Group by column as ID and MAX of Changed Date, and All rows with Column name as "AllRows". Click ok. Now the table will have ID, Date, AllRows columns. Click AllRows column, expand and remove other columns that are not required. Plese try and let know if this works.

Community Support Team
Community Support Team

Re: Group by date and keep all columns

Hi jama1234

You could try below M query

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlLSUTIw1zOw1DMyMLQEcoJSE1MqgbRzUWpiSWqKUqxOtJIhkG9ogKTIM08hPL8oG8TKLchJzU3NgykFmWdoQpRSkKkGFsRYbYZsHpIpOkou+XmpcHuBihDqYIYgXIDVJ1iUxQIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, #"Changed Date" = _t, State = _t, Create = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Changed Date", type text}, {"State", type text}, {"Create", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"max", each List.Max([Changed Date]), type text}, {"all", each _, type table [ID=number, Changed Date=text, State=text, Create=text]}}),
    #"Expanded all" = Table.ExpandTableColumn(#"Grouped Rows", "all", {"Changed Date", "State", "Create"}, {"all.Changed Date", "all.State", "all.Create"}),
    #"selectrow"=Table.SelectRows(#"Expanded all",each [max]=[all.Changed Date]),
    #"Removed Columns" = Table.RemoveColumns(selectrow,{"all.Changed Date"})
in
    #"Removed Columns"

Best Regards,
Zoe Zhi

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

Helpful resources

Announcements
Coming Soon: T-Shirt Design Contest

Coming Soon: T-Shirt Design Contest

Keep your eyes open for our upcoming T-shirt design contest!

Meet the 2020 Season 1 Power BI Super Users!

Meet the 2020 Season 1 Power BI Super Users!

It’s the start of a new Super User season! Learn all about the new Super Users and brand-new tiered recognition system.

Super User Challenge: Can You Solve These?

Super User Challenge: Can You Solve These?

We're celebrating the start of the New Super User season with our first ever Super User 'Can You Solve These?' challenge.

Power BI Desktop Update - February 2020

Power BI Desktop Update - February 2020

We are super excited for our update this month, as we are releasing two of our top community requests!

Power Platform Online Conference

Power Platform Online Conference

Join us for the first ever Power Platform Online Conference!

Top Solution Authors
Top Kudoed Authors