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
Anonymous
Not applicable

take a value base on the maximum value of another column and based on duplicate value or not

Hi,

I need to do some data manipulation for the following dataset: Column A, B, and C

21654756ClosedAug 30, 2020 11:32 PM
21654747ClosedAug 30, 2020 11:17 PM
21654745ClosedAug 30, 2020 11:13 PM
21654745OpenAug 30, 2020 11:16 PM
21654652EscalatedAug 30, 2020, 2:00 AM
21654652FixedAug 31, 2020 1:02 AM

Column A has duplicate values and unique values.

When Column A is unique, Column B and Column C remains the same;

When Column A is duplicate, then I would like to take the value in Column B based on the latest time of Column C.

So here is the result table I want to see:

21654756ClosedAug 30, 2020 11:32 PM
21654747ClosedAug 30, 2020 11:17 PM
21654745OpenAug 30, 2020 11:16 PM
21654652FixedAug 31, 2020 1:02 AM

I am a beginner of PowerQuery. Can someone guide me on how to achieve the result I would like to have?

2 ACCEPTED SOLUTIONS
edhans
Super User
Super User

Hi @Anonymous , see if this works. It turns this:

edhans_0-1599233664467.png

into this:

edhans_1-1599233686614.png

THe code is as follows:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjI0MzUxNzVT0lFyzskvTk0BMhxL0xWMDXQUjAyMDBQMDa2MjRQCfJVidWCqTczxqTY0R1Ntile1MRbV/gWpedjUmqGoNTM1AipyLU5OzEkswTAcSFoZGCg4Ymhwy6xAKDaEmW5lYARWGwsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column3", type datetime}}),
    #"Grouped Rows" = 
        Table.Group(
            #"Changed Type", 
            {"Column1"}, 
            {
                {"Column2",
                    each
                        let
                            varMaxDate = List.Max(_[Column3])
                        in
                    Table.SelectRows(_, each [Column3] = varMaxDate)[Column2]{0}, type text
                },
                {"Column3", each List.Max(_[Column3]), type datetime}
                
            }
        )
in
    #"Grouped Rows"

 

How to use M code provided in a blank query:
1) In Power Query, select New Source, then Blank Query
2) On the Home ribbon, select "Advanced Editor" button
3) Remove everything you see, then paste the M code I've given you in that box.
4) Press Done
5) See this article if you need help using this M code in your model.

 

I actually wrote a blog post on this a month or so ago that goes into more detail about what I did here.

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

View solution in original post

Icey
Community Support
Community Support

Hi @Anonymous ,

 

You can also just try this:

max.gif

 

 

Best Regards,

Icey

 

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

5 REPLIES 5
Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

you can do a Table.Sort surrounded by a Table Buffer. Sort it in a way that the first row is showing what you want. Then use a Table.Distinct where you input "ColumnA" as second parameter. Here the complete code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjI0MzUxNzVT0lFyzskvTk0BMhxL0xWMDXQUjAyMDBQMDa2MjRQCfJVidWCqTczxqTY0R1Ntile1MRbV/gWpedjUmqGoNTM1AipyLU5OzEkswTAcSFoZGCg4Ymhwy6xAKDaEmW5lYARWGwsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Column A" = _t, #"Column B" = _t, #"Column B.1" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column A", Int64.Type}, {"Column B", type text}, {"Column B.1", type datetime}}),
    #"Sorted Rows" = Table.Buffer(Table.Sort(#"Changed Type",{{"Column A", Order.Descending},{"Column B.1", Order.Descending}})),
    #"Removed Duplicates" = Table.Distinct(#"Sorted Rows", {"Column A"})
in
    #"Removed Duplicates"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

Icey
Community Support
Community Support

Hi @Anonymous ,

 

You can also just try this:

max.gif

 

 

Best Regards,

Icey

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

edhans
Super User
Super User

Hi @Anonymous , see if this works. It turns this:

edhans_0-1599233664467.png

into this:

edhans_1-1599233686614.png

THe code is as follows:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjI0MzUxNzVT0lFyzskvTk0BMhxL0xWMDXQUjAyMDBQMDa2MjRQCfJVidWCqTczxqTY0R1Ntile1MRbV/gWpedjUmqGoNTM1AipyLU5OzEkswTAcSFoZGCg4Ymhwy6xAKDaEmW5lYARWGwsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column3", type datetime}}),
    #"Grouped Rows" = 
        Table.Group(
            #"Changed Type", 
            {"Column1"}, 
            {
                {"Column2",
                    each
                        let
                            varMaxDate = List.Max(_[Column3])
                        in
                    Table.SelectRows(_, each [Column3] = varMaxDate)[Column2]{0}, type text
                },
                {"Column3", each List.Max(_[Column3]), type datetime}
                
            }
        )
in
    #"Grouped Rows"

 

How to use M code provided in a blank query:
1) In Power Query, select New Source, then Blank Query
2) On the Home ribbon, select "Advanced Editor" button
3) Remove everything you see, then paste the M code I've given you in that box.
4) Press Done
5) See this article if you need help using this M code in your model.

 

I actually wrote a blog post on this a month or so ago that goes into more detail about what I did here.

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting
Greg_Deckler
Super User
Super User

@Anonymous - @ImkeF , @edhans 

 

In DAX this would be Lookup Min/Max - https://community.powerbi.com/t5/Quick-Measures-Gallery/Lookup-Min-Max/m-p/985814#M434


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
Anonymous
Not applicable

check if is this what you want:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjI0MzUxNzVT0lFyzskvTk0BMhxL0xWMDXQUjAyMDBQMDa2MjRQCfJVidWCqTczxqTY0R1Ntile1MRbV/gWpedjUmqGoNTM1AipyLU5OzEkswTAcSFoZGCg4Ymhwy6xAKDaEmW5lYARWGwsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", Int64.Type}, {"Column2", type text}, {"Column3", type datetime}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Column1"}, {{"last", each Table.Max(_,"Column3")}}),
    #"Expanded last" = Table.ExpandRecordColumn(#"Grouped Rows", "last", {"Column2", "Column3"}, {"last.Column2", "last.Column3"})
in
    #"Expanded last"

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