cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
kelvin-lkh
New Member

Remove Duplicate and only Keep the Latest Period

Dear All,

 

Below is the table which I have already sorted the shippable period based on the descending order. I want to remove the duplicate based on the 'Project' column and keep the Unique row with the latest shippable period which should be FY23P02 in below example. 

 

kelvinlkh_0-1650351031244.png

 

However, the unique row kept after I use the remove duplicate row function by 'Project' column giving me the shippable period of FY22P09 which is in between the earlier period FY22P07 and latest FY23P02. 

 

How do I remove the duplicate rows based on the 'Project' column and keep the unique row with the latest shippable period?

 

kelvinlkh_1-1650351131449.png

 

 

1 ACCEPTED SOLUTION
Vijay_A_Verma
Community Champion
Community Champion

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjYxVdJRcgRit0hDywADCyArODMvPbEgvyhVKVaHVBVGxgEGRlRQYUh7FUYBhgTcQVAFMDwM8duCXYWhkbEJUNAJZg0Wp5KqBBQ1mI6lgRJQyJqMKomNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Project Number" = _t, Project = _t, #"Shippable Period" = _t, #"Mgmt Region" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Project Number", Int64.Type}, {"Project", type text}, {"Shippable Period", type text}, {"Mgmt Region", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Number.From(Text.Select([Shippable Period],{"0".."9"}))),
    #"Sorted Rows" = Table.Sort(#"Added Custom",{{"Project", Order.Ascending}, {"Custom", Order.Descending}}),
    #"Grouped Rows" = Table.Group(#"Sorted Rows", {"Project Number"}, {{"Temp", each _, type table [Project Number=nullable number, Project=nullable text, Shippable Period=nullable text, Mgmt Region=nullable text, Custom=number]}}),
    #"Added Custom1" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.AddIndexColumn([Temp],"Index")),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Temp"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Columns", "Custom", {"Project", "Shippable Period", "Mgmt Region", "Custom", "Index"}, {"Project", "Shippable Period", "Mgmt Region", "Custom.1", "Index"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Custom", each ([Index] = 0)),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Custom.1", "Index"})
in
    #"Removed Columns1"

Edit - Another approach which is shorter is possible through the use of Inner join

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjYxVdJRcgRit0hDywADCyArODMvPbEgvyhVKVaHVBVGxgEGRlRQYUh7FUYBhgTcQVAFMDwM8duCXYWhkbEJUNAJZg0Wp5KqBBQ1mI6lgRJQyJqMKomNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Project Number" = _t, Project = _t, #"Shippable Period" = _t, #"Mgmt Region" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Project Number", Int64.Type}, {"Project", type text}, {"Shippable Period", type text}, {"Mgmt Region", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Number.From(Text.Select([Shippable Period],{"0".."9"}))),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Project Number"}, {{"Temp", each List.Max([Custom]), type number}}),
    #"Merged Queries" = Table.NestedJoin(#"Added Custom", {"Project Number", "Custom"}, #"Grouped Rows", {"Project Number", "Temp"}, "Grouped Rows", JoinKind.Inner),
    #"Removed Columns" = Table.RemoveColumns(#"Merged Queries",{"Grouped Rows"}),
    #"Removed Duplicates" = Table.Distinct(#"Removed Columns", {"Project", "Custom"}),
    #"Removed Columns1" = Table.RemoveColumns(#"Removed Duplicates",{"Custom"})
in
    #"Removed Columns1"

 

 

 

View solution in original post

1 REPLY 1
Vijay_A_Verma
Community Champion
Community Champion

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjYxVdJRcgRit0hDywADCyArODMvPbEgvyhVKVaHVBVGxgEGRlRQYUh7FUYBhgTcQVAFMDwM8duCXYWhkbEJUNAJZg0Wp5KqBBQ1mI6lgRJQyJqMKomNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Project Number" = _t, Project = _t, #"Shippable Period" = _t, #"Mgmt Region" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Project Number", Int64.Type}, {"Project", type text}, {"Shippable Period", type text}, {"Mgmt Region", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Number.From(Text.Select([Shippable Period],{"0".."9"}))),
    #"Sorted Rows" = Table.Sort(#"Added Custom",{{"Project", Order.Ascending}, {"Custom", Order.Descending}}),
    #"Grouped Rows" = Table.Group(#"Sorted Rows", {"Project Number"}, {{"Temp", each _, type table [Project Number=nullable number, Project=nullable text, Shippable Period=nullable text, Mgmt Region=nullable text, Custom=number]}}),
    #"Added Custom1" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.AddIndexColumn([Temp],"Index")),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Temp"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Columns", "Custom", {"Project", "Shippable Period", "Mgmt Region", "Custom", "Index"}, {"Project", "Shippable Period", "Mgmt Region", "Custom.1", "Index"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Custom", each ([Index] = 0)),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Custom.1", "Index"})
in
    #"Removed Columns1"

Edit - Another approach which is shorter is possible through the use of Inner join

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjYxVdJRcgRit0hDywADCyArODMvPbEgvyhVKVaHVBVGxgEGRlRQYUh7FUYBhgTcQVAFMDwM8duCXYWhkbEJUNAJZg0Wp5KqBBQ1mI6lgRJQyJqMKomNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Project Number" = _t, Project = _t, #"Shippable Period" = _t, #"Mgmt Region" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Project Number", Int64.Type}, {"Project", type text}, {"Shippable Period", type text}, {"Mgmt Region", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Number.From(Text.Select([Shippable Period],{"0".."9"}))),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Project Number"}, {{"Temp", each List.Max([Custom]), type number}}),
    #"Merged Queries" = Table.NestedJoin(#"Added Custom", {"Project Number", "Custom"}, #"Grouped Rows", {"Project Number", "Temp"}, "Grouped Rows", JoinKind.Inner),
    #"Removed Columns" = Table.RemoveColumns(#"Merged Queries",{"Grouped Rows"}),
    #"Removed Duplicates" = Table.Distinct(#"Removed Columns", {"Project", "Custom"}),
    #"Removed Columns1" = Table.RemoveColumns(#"Removed Duplicates",{"Custom"})
in
    #"Removed Columns1"

 

 

 

Helpful resources

Announcements
June 2022 update 768X460.jpg

Check it out!

Click here to read more about the June 2022 updates!

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Power BI Dev Camp Session 23 768x460.jpg

Check it Out!

Mark your calendars and join us on Thursday, June 30 at 11a PDT for a great session with Ted Pattison!

June 20 episode 7 with aka link 768x460.jpg

The Power BI Community Show

Join us on June 20 at 11 am PDT when Kim Manis shares the latest on Azure Synapse analytics, the Microsoft Intelligent Data Platform, and notable Power BI Updates from Microsoft Build 2022.

Top Solution Authors