Extract unique values from columns

proficient

Well-known Member
Joined
Apr 10, 2012
Messages
745
Office Version
  1. 2016
Platform
  1. Windows
  2. Mobile
Hi all,

Need your help, I have two columns, column A has

A B C O E W G H
whereas column B has
A B C E G H J L P

I want Unique alphabats from column B only, means as you can see O and W are also unique in column A but I want to extract J, L and P only.

TIA
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Re: Want to extract unique values from columns

While you're waiting for Aladin to respond, here's a UDF you can try. See the example below for setting the arguments.
Excel Workbook
ABCD
1Unique To Col BUnique to col A
2A B C O E W G HA B C E G H J L PJ L PO W
Sheet4



Code:
Function UniqueToCol(R As Range, Col As Long) As String
Dim V1 As Variant, V2 As Variant, i As Long, j As Long
If Col > R.Columns.Count Or Col > 2 Then
    UniqueToCol = CVErr(xlErrValue)
    Exit Function
End If
V1 = Split(R(1), " ")
V2 = Split(R(2), " ")
Application.Volatile
Select Case Col
    Case 2  'look for elements in the second col of R that are not in the first col of R
        For i = LBound(V2) To UBound(V2)
            For j = LBound(V1) To UBound(V1)
                ct = ct + 1
                If V2(i) = V1(j) Then Exit For
                If ct = UBound(V1) + 1 Then UniqueToCol = UniqueToCol & " " & V2(i)
            Next j
            ct = 0
        Next i
        UniqueToCol = Trim(UniqueToCol)
    Case 1  'look for elements in the first col of R that are not in the second col of R
        For i = LBound(V1) To UBound(V1)
            For j = LBound(V2) To UBound(V2)
                ct = ct + 1
                If V1(i) = V2(j) Then Exit For
                If ct = UBound(V2) + 1 Then UniqueToCol = UniqueToCol & " " & V1(i)
            Next j
            ct = 0
        Next i
        UniqueToCol = Trim(UniqueToCol)
End Select
End Function
 
Upvote 0
Re: Want to extract unique values from columns

Need your help, I have two columns, column A has

A B C O E W G H
whereas column B has
A B C E G H J L P
Are those letters all in one cell (space delimited as shown) or is each individual letter in its own cell down the column?
 
Upvote 0
Re: Want to extract unique values from columns

No, all letters are in seperate cells, assume range from A1 to A10 and B1 to B10
 
Upvote 0
Re: Want to extract unique values from columns


Book1
ABCD
1AAJ
2ABL
3BCP
4CE
5OG
6EH
7WJ
8GL
9HP
Sheet1


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

=IFERROR(INDEX($B$1:$B$9,SMALL(IF(FREQUENCY(IF(1-($B$1:$B$9=""),IF(ISNA(MATCH($B$1:$B$9,$A$1:$A$9,0)),MATCH($B$1:$B$9,$B$1:$B$9,0))),ROW($B$1:$B$9)-ROW($B$1)+1),ROW($B$1:$B$9)-ROW($B$1)+1),ROWS($D$1:D1))),"")

This creates a unique list of items from column B which do not occur in column A. Hope this is the correct interpretation of what you are asking for.
 
Upvote 0
Re: Want to extract unique values from columns

No, all letters are in seperate cells, assume range from A1 to A10 and B1 to B10
Not the way I interpreted the initial post, so the UDF in post#3 is not applicable.
 
Upvote 0
Re: Want to extract unique values from columns

Aladin has given you a (somewhat complex) formula solution. If you are willing to entertain a VB solution, here is a subroutine that you would call from within a macro or event procedure. The subroutine takes three arguments... the first is the column of cells you want to check for unique letters (Column B from your example), the second is the columns of cells you want to compare is against (Column A from your example) and the third is the first cell that the output will start in.
Code:
[table="width: 500"]
[tr]
	[td][B][COLOR="#008000"]' This is the subroutine that you call from your macro or event procedure[/COLOR][/B]
Sub UniqueToCol(CheckCol As Range, CompareCol As Range, OutCell As Range)
  Dim V As Variant, UCol As Variant, CCol As Variant
  UCol = Application.Transpose(CheckCol)
  CCol = CompareCol
  For Each V In CCol
    UCol = Filter(UCol, V, False)
  Next
  OutCell.Resize(1 + UBound(UCol)) = Application.Transpose(UCol)
End Sub


[B][COLOR="#008000"]' A test macro to show how to call the above subroutine[/COLOR][/B]
Sub Test()
  UniqueToCol Range("B1:B9"), Range("A1:A8"), Range("C1")
End Sub[/td]
[/tr]
[/table]
 
Last edited:
Upvote 0
Re: Want to extract unique values from columns

Yes.
 
Upvote 0
Re: Want to extract unique values from columns

ABCD
1AAJ
2ABL
3BCP
4CE
5OG
6EH
7WJ
8GL
9HP

<colgroup><col style="width: 25pxpx"><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

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

=IFERROR(INDEX($B$1:$B$9,SMALL(IF(FREQUENCY(IF(1-($B$1:$B$9=""),IF(ISNA(MATCH($B$1:$B$9,$A$1:$A$9,0)),MATCH($B$1:$B$9,$B$1:$B$9,0))),ROW($B$1:$B$9)-ROW($B$1)+1),ROW($B$1:$B$9)-ROW($B$1)+1),ROWS($D$1:D1))),"")

This creates a unique list of items from column B which do not occur in column A. Hope this is the correct interpretation of what you are asking for.


@Aladin Akyurek, You can't be wrong ever; I believe! Thanks a lot! this is exactly what I wanted.

Could you explain the formula for me?
 
Upvote 0

Forum statistics

Threads
1,214,593
Messages
6,120,434
Members
448,961
Latest member
nzskater

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