Merge duplicates conditionally

Tigerexcel

Active Member
Joined
Mar 6, 2020
Messages
493
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
I have a file with duplicate records but the critical field (Description) has been updated in some cases and that is the one that needs to be returned.

ProcessAffectsRevisionDescription
Building entryAllEntering the building
Building entryEntering the building, requires ID card
OHSRefer manual
OHSRefer manual
RecruitmentJun-20Refer HR
PhotocopyingOfficeRequires training
PhotocopyingOfficeRequires training. Update imminent

What I need as output would be:
Building entry All Entering the building, requires ID card

so that each process is only listed once but it picks up the Description field with the most information ie has more text in it. As far as I can see no process has more than 2 entries, there are a lot of entries though where there's just one entry. How do I merge these records and remove duplicates?
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Hi Tigerexcel,

2 formula options:

Book1
ABCDEFGHI
1ProcessAffectsRevisionDescriptionKeep/DeleteLenKeep
2Building entryAllEntering the buildingDelete21FALSE
3Building entryEntering the building, requires ID cardKeep39TRUE
4OHSRefer manualDelete12TRUE
5OHSRefer manualKeep12TRUE
6Recruitmentjun/20Refer HRKeep8TRUE
7PhotocopyingOfficeRequires trainingDelete17FALSE
8PhotocopyingOfficeRequires training. Update imminentKeep34TRUE
Sheet2
Cell Formulas
RangeFormula
G2:G8G2=LEN(D2)
H2:H8H2=MAXIFS($G$2:$G$8,$A$2:$A$8,A2)=G2
E2:E8E2=IF(COUNTIF($A$2:$A$8,A2)=COUNTIF($A$2:A2,A2),"Keep","Delete")


Then filter and delete rows accordingly.

Same logic can be followed with Power Query, all with UI:
Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Process", type text}, {"Affects", type text}, {"Revision", type datetime}, {"Description", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Length", each Text.Length([Description])),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Process"}, {{"Last", each List.Max([Length]), type number}, {"All", each _, type table [Process=text, Affects=text, Revision=datetime, Description=text, Length=number]}}),
    #"Expanded All" = Table.ExpandTableColumn(#"Grouped Rows", "All", {"Affects", "Revision", "Description", "Length"}, {"Affects", "Revision", "Description", "Length"}),
    #"Added Custom1" = Table.AddColumn(#"Expanded All", "Keep", each [Last]=[Length]),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom1", each ([Keep] = true)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Last", "Length", "Keep"})
in
    #"Removed Columns"
 
Upvote 0
Thanks G., rescued me again. I particularly like that you provide a variety of options from formulae to PQ. I haven't come across the MAXIFS function, thanks for sharing.
 
Upvote 0

Forum statistics

Threads
1,213,538
Messages
6,114,218
Members
448,554
Latest member
Gleisner2

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top