Power Query: Removing duplicate values in Multi-Value Cells

lneidorf

Board Regular
Hi there.

Long-time Excel user and dabbler in VBA who discovered Power Query for the first time today.

I've used this to combine values spanning multiple rows into single row entries with multi-value fields/cells. An example should be helpful:

Here's a mock-up of my source data.
Column A Column B
Beatles John
Beatles Paul
Beatles George
Beatles Ringo
Beatles John
Stones Mick
Stones Keith
Stones Charlie
Stones Ronnie
Stones Mick

Band name in Col A; Band Member in Col B. Note that we have duplicates, with "Beatles | John" and "Stones | Mick" appearing twice.

I've used Power Query to roll this stuff up nicely, with the result a single row per value in Column A. My current results looks like this:

Column A Column B
Beatles John;Paul;George;Ringo;John
Stones Mick;Keith;Charlie;Ronnie;Mick

Column B contains multi-value field/cells, with individual values separated by semicolons.

The issue is the duplicates. It's important to note that my duplicates are duplicate values within single, multi-value cells. So the question is how to use Power Query to clean those cells and remove any duplicative values in each individual cell. In this cae, the offending values are the duplicate John and Mick values.

My goal is to get to this result:
Column A Column B
Beatles John;Paul;George;Ringo
Stones Mick;Keith;Charlie;Ronnie


I figure there's got to be a way to do this right in Power Query, but my web searches haven't found anything touching upon this.

Any input welcome.

Thanks!
 

sandy666

Well-known Member
try

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Group = Table.Group(Source, {"Column1"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "List", each List.Distinct(Table.Column([Count],"Column2"))),
    Extract = Table.TransformColumns(List, {"List", each Text.Combine(List.Transform(_, Text.From), ";"), type text})
in
    Extract[/SIZE]
Column1Column2Column1List
BeatlesJohnBeatlesJohn;Paul;George;Ringo
BeatlesPaulStonesMick;Keith;Charlie;Ronnie
BeatlesGeorge
BeatlesRingo
BeatlesJohn
StonesMick
StonesKeith
StonesCharlie
StonesRonnie
StonesMick
 
Last edited:

lneidorf

Board Regular
Thanks for this.

I'm afraid I've got a remedial follow up question: how would I execute this code? I've got about a day of experience with Power Query, so I'm afraid I'm a total newbie.

I've tried Add Column\Custom Column, entering the formula there. It executes, generating a new column. I've then expanded my new column, which generates a new column populated with the composite values I'm looking for, but doesn't remove any of my original rows. I've got dupes.

I imagine I'm missing something very basic here.

Lastly, I should ask: do you think this is scalable? I've got a spreadsheet with 45,000 rows I'd like to run this across.

Thanks!
 

sandy666

Well-known Member
how would I execute this code?
Change source range to table (Ctrl+T), - be sure the name of the table is the same as in the code - in this case : Table1
then use From Table (Get&Transform part on the ribbon)
then open Advanced Editor and replace code there with copied from the post
then Close&Load

do you think this is scalable?
don't ask just try ;) ( if it works with 5 mln rows , it should work with your 45 000)
 
Last edited:

lneidorf

Board Regular
sandy666,

Holy s$%t! Amazing.

I spent days playing with VBA and came up with a multi-step process that took 20-30 min to completely execute, with a lacking result. And this needs to be run across a dozen columns.

Thank you so much!
--LAN
 

Some videos you may like

This Week's Hot Topics

  • Get External Data (long shot question!)
    This is likely a long shot but I am wondering if it is at all possible for Excel to somehow 'change' the contents of a URL that is being linked to...
  • Importing multiple excel files into one spreadsheet
    Hi, I'm trying to import multiple excel files (with the same format into a single spreadsheet) so that each day's file is listed underneath the...
  • Cell Formatting
    Good Morning, I need to format a few different cells in the following manners: A1 has to always add a colon (:) after whatever is typed in by a...
  • How to copy multiple rows using If
    Hi all, I'm very new to VBA and have written this simple code to copy certain cells if a certain cell within that row contains any data. I need...
  • Workbook_Change stopped working !
    I am working on an app to speed up & automate processing of Credit Cards statements. After data is input from a CSV file, it is presented to the...
  • VBA If statement
    Dear All, I have two dates, where I'd like a message box to pop, if the dates are between this criteria. [CODE] sDate1 = #10/1/2019#...
Top