Results 1 to 6 of 6

Thread: Power Query: Removing duplicate values in Multi-Value Cells
Thanks Thanks: 0 Likes Likes: 0

  1. #1
    Board Regular
    Join Date
    May 2004
    Posts
    77
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Power Query: Removing duplicate values in Multi-Value Cells

    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!

  2. #2
    Board Regular sandy666's Avatar
    Join Date
    Oct 2015
    Posts
    2,853
    Post Thanks / Like
    Mentioned
    32 Post(s)
    Tagged
    1 Thread(s)

    Cool Re: Power Query: Removing duplicate values in Multi-Value Cells

    try

    Code:
    // 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
    Column1 Column2 Column1 List
    Beatles John Beatles John;Paul;George;Ringo
    Beatles Paul Stones Mick;Keith;Charlie;Ronnie
    Beatles George
    Beatles Ringo
    Beatles John
    Stones Mick
    Stones Keith
    Stones Charlie
    Stones Ronnie
    Stones Mick
    Last edited by sandy666; Sep 18th, 2019 at 12:28 AM.
    I know you know but I forgot my Crystal Ball and don't know what you know



    In the first post, show the type of machine (PC / Mac) and the Office version you are working on
    I don't use vba in any form!

  3. #3
    Board Regular
    Join Date
    May 2004
    Posts
    77
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Power Query: Removing duplicate values in Multi-Value Cells

    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!

  4. #4
    Board Regular sandy666's Avatar
    Join Date
    Oct 2015
    Posts
    2,853
    Post Thanks / Like
    Mentioned
    32 Post(s)
    Tagged
    1 Thread(s)

    Cool Re: Power Query: Removing duplicate values in Multi-Value Cells

    Quote Originally Posted by lneidorf View Post
    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

    Quote Originally Posted by lneidorf View Post
    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 by sandy666; Sep 18th, 2019 at 04:11 PM.
    I know you know but I forgot my Crystal Ball and don't know what you know



    In the first post, show the type of machine (PC / Mac) and the Office version you are working on
    I don't use vba in any form!

  5. #5
    Board Regular
    Join Date
    May 2004
    Posts
    77
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Power Query: Removing duplicate values in Multi-Value Cells

    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

  6. #6
    Board Regular sandy666's Avatar
    Join Date
    Oct 2015
    Posts
    2,853
    Post Thanks / Like
    Mentioned
    32 Post(s)
    Tagged
    1 Thread(s)

    Cool Re: Power Query: Removing duplicate values in Multi-Value Cells

    you are welcome

    maybe time to learn more about PowerQuery

    I know you know but I forgot my Crystal Ball and don't know what you know



    In the first post, show the type of machine (PC / Mac) and the Office version you are working on
    I don't use vba in any form!

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •