Pivot Duplicate Values into Columns

shaharbiras

New Member
Joined
May 30, 2019
Messages
3
Hi,

I have a large dataset with 2 columns -
first column is name and can have duplicate values (any amount of duplicates)
seconds column is id and can also have duplicates

I want to pivot the table in that way -
first column will have a distinct value of the name followed by the corresponding id's per name

in example I want to turn this-
a 1
a 2
b 3
c 3
c 4
c 5
into this -
a 1 2
b 2
c 3 4 5

I would prefer to use Power Query/Pivot in the solution if possible since I deal with very large data sets
 

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
something like this? (with PowerQuery)
you didn't say result (ID) should be in one cell or splited to the columns

NameIDNameID
a
1​
a1, 2
a
2​
b3
b
3​
c3, 4, 5
c
3​
c
4​
c
5​
 
Last edited:
Upvote 0
so...

NameIDNameID.1ID.2ID.3
a
1​
a12
a
2​
b3
b
3​
c345
c
3​
c
4​
c
5​

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Group = Table.Group(Source, {"Name"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "ID", each Table.Column([Count],"ID")),
    Extract = Table.TransformColumns(List, {"ID", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    SplitCount = Table.AddColumn(Extract, "SCount", each List.Count(Text.Split([ID],","))),
    MaxCount = List.Max(SplitCount[SCount]),
    Split = Table.SplitColumn(Extract, "ID", Splitter.SplitTextByDelimiter(","), MaxCount)
in
    Split[/SIZE]
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,207
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