Unusual de-dupe question

Chartman of the Bored

Board Regular
Joined
Apr 24, 2002
Messages
83
I have some rows of data with a bunch of duplicate text strings, like this (each fruit is in a separate cell):

Company ABC Apples Oranges Lemons Lemons Lemons Pears
Company DEF Orange Lemons Pears Pears Pears Pears Pears Cucumbers
Company XYZ Apples Apples Apples Pears Pears Lemons Lemons Lemons Lemons Lemons


I'm trying to de-dupe them. I can do it one row at a time (or one column at a time if I transpose) using Excel's "Consolidate" feature. But I have 2,000+ rows. I can't do them one at a time without spending endless hours of monotony.

Is there a way to do this (ideally without VBA)? I would theoretically want the data above to like like this (with one instance of each fruit instead of multiple):

Company ABC Apples Oranges Lemons Pears
Company DEF Orange Lemons Pears Cucumbers
Company XYZ Apples Pears Lemons


Thanks very much
 
Last edited:

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
A2 of sheet1 has first data(Company ABC).
B2 of sheet2 = =IFERROR(IF(ROW($A$1)>SUMPRODUCT((OFFSET(Sheet1!$B2,0,0,1,COUNTA(Sheet1!2:2)-1)<>"")/COUNTIF(OFFSET(Sheet1!$B2,0,0,1,COUNTA(Sheet1!2:2)-1),OFFSET(Sheet1!$B2,0,0,1,COUNTA(Sheet1!2:2)-1)&""))-1,"",INDEX(OFFSET(Sheet1!$B2,0,0,1,COUNTA(Sheet1!2:2)-1),MATCH(0,INDEX(0/ISERROR(MATCH(OFFSET(Sheet1!$B2,0,0,1,COUNTA(Sheet1!2:2)-1),$A2:A2,0)),),0))),"")

VBA
Code:
Sub frt()
Dim i As Long, j As Long, LC As Long
Dim rng As Range, Dic, x, C, buf
Dim ws1 As Worksheet, ws2 As Worksheet
Set ws1 = Sheets("sheet1")
Set ws2 = Sheets("sheet2")
With ws1
    For i = 2 To .cells(Rows.count, 1).End(xlUp).row
    Set Dic = CreateObject("scripting.Dictionary")
    On Error Resume Next
        LC = .cells(i, Columns.count).End(xlToLeft).column
        For Each C In .Range(.cells(i, 1), .cells(i, LC))
            buf = C.Value
            Dic.Add buf, buf
        Next
        x = Dic.keys
        ws2.Range(ws2.cells(i, 1), ws2.cells(i, UBound(x) + 1)) = x
    Next
End With
Set Dic = Nothing
End Sub
 
Upvote 0
Row\Col
A​
B​
C​
D​
E​
F​
G​
H​
I​
J​
K​
1​
2​
ABCApplesOrangesLemonsLemonsLemonsPears
3​
DEFOrangeLemonsPearsPearsPearsPearsPearsCucumbers
4​
XYZApplesApplesApplesPearsPearsLemonsLemonsLemonsLemonsLemons
5​
6​
7​
8​
6​
ABCApplesOrangesLemonsPears
9​
8​
DEFOrangeLemonsPearsCucumbers
10​
10​
XYZApplesPearsLemons
11​

In A8 just enter and copy down as far as needed:

=MATCH(REPT("z",255),$B2:$XFD2)

In C8 control+shift+enter, not just enter, copy across, and down:

=IFERROR(INDEX($B2:INDEX($B2:$XFD2,$A8),SMALL(IF(FREQUENCY(IF(1-($B2:INDEX($B2:$XFD2,$A8)=""),MATCH($B2:INDEX($B2:$XFD2,$A8),$B2:INDEX($B2:$XFD2,$A8),0)),TRANSPOSE(COLUMN($B2:INDEX($B2:$XFD2,$A8))-COLUMN($B2)+1)),TRANSPOSE(COLUMN($B2:INDEX($B2:$XFD2,$A8))-COLUMN($B2)+1)),COLUMNS($B2:B2))),"")
 
Upvote 0

Forum statistics

Threads
1,213,538
Messages
6,114,217
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