Note: The other languages of the website are Google-translated. Back to English

How to compare comma separated values in two cells and return duplicate or unique values in Excel?

As shown in the screenshot below, there are two columns - Column1 and Column2, each cell in the column contains comma separated numbers. To compare the comma separated numbers in Column1 with the cell contents in the same row of Column2 and return all duplicate or unique values, what could you do?

This tutorial provides two methods to help you accomplish this task.


Compare comma separated values in two cells and return duplicate or unique values with formulas

This section provides two formulas to help compare the comma separated values in two cells and return the duplicate or unique values between them.

Note: The following formulas only work in Excel for 365. If you are using other versions of Excel , try using the below VBA method.

Take the above two columns as an example, to compare the comma separated numbers in Column1 with the comma separated numbers in the same row of Column2 and return duplicate or unique values, please do as follows.

Return duplicate values

1. Select a cell to output the duplicate numbers between the two specified cells with comma separated numbers, in this case, I select cell D2, then enter the formula below and press the Enter key. Select the formula cell and drag its AutoFill Handle down to get the duplicate numbers between cells in the other rows.

=LET(x, TRANSPOSE(TEXTSPLIT(TEXTJOIN(", ",TRUE,A2:B2), ", ")),y,UNIQUE(x),z,UNIQUE(x,,1), TEXTJOIN(", ",TRUE,IF(ISERROR(MATCH(y,z,0)),y, "")))

Return unique values

To return the unique numbers between the two specified cells with comma separated numbers in the same row, the following formula can help.

1. Select a cell to output the unique numbers, in this case, I select cell E2, then enter the formula below and press the Enter key. Select the formula cell and drag its AutoFill Handle down to get the unique numbers between cells in the other rows.

=TEXTJOIN(", ",TRUE,UNIQUE(TRANSPOSE(TEXTSPLIT(TEXTJOIN(", ",TRUE,A2:B2), ", ")),,1))

Notes:

1) The above two formulas can only be applied in Excel for 365. If you are using a version of Excel other than Excel for 365, please try the following VBA method.
2) The cells to be compared must be adjacent to each other in the same row or column.

Compare two columns with comma separated values and return duplicate or unique values with VBA

The user-defined function provided in this section helps to compare the comma separated values in two specified cells and return the duplicate values or unique values between them. Please do as follows.

Take the same example as above, to compare the comma separated numbers in Column1 with the comma separated numbers in the same row of Column2 and return duplicate or unique values, please try the user-defined function in this section.

1. In the opening workbook, press the Alt + F11 keys to open the Microsoft Visual Basic for Applications window.

2. In the Microsoft Visual Basic for Applications window, click Insert > Module, and copy the following VBA code in the Module (Code) window.

VBA code: Compare comma separated values in two cells and return duplicate/unique values

Private Function COMPARE(Rng1, Rng2 As Range, Op As Boolean)
'Updated by Extendoffice 20221019
    Dim R1Arr As Variant
    Dim R2Arr As Variant
    Dim Ans1 As String
    Dim Ans2 As String
    Dim Separator As String
    Dim d1 As New Dictionary
    Dim d2 As New Dictionary
    Dim d3 As New Dictionary
    Application.Volatile

    Separator = ", "
    
    R1Arr = Split(Rng1.Value, Separator)
    R2Arr = Split(Rng2.Value, Separator)
    
    Ans1 = ""
    Ans2 = ""
    
    For Each ch In R2Arr
        If Not d2.Exists(ch) Then
            d2.Add ch, "1"
        End If
    Next
    
    If Op Then
        For Each ch In R1Arr
            If d2.Exists(ch) Then
                If Not d3.Exists(ch) Then
                    d3.Add ch, "1"
                    Ans1 = Ans1 & ch & Separator
                End If
            End If
        Next
        If Ans1 <> "" Then
            Ans1 = Mid(Ans1, 1, Len(Ans1) - Len(Separator))
        End If
        COMPARE = Ans1
    Else
        For Each ch In R1Arr
            If Not d1.Exists(ch) Then
                d1.Add ch, "1"
            End If
        Next
        
        For Each ch In R1Arr
            If Not d2.Exists(ch) Then
                If Not d3.Exists(ch) Then
                    d3.Add ch, "1"
                    Ans2 = Ans2 & ch & Separator
                End If
            End If
        Next
        For Each ch In R2Arr
            If Not d1.Exists(ch) Then
                If Not d3.Exists(ch) Then
                    d3.Add ch, "1"
                    Ans2 = Ans2 & ch & Separator
                End If
            End If
        Next
        If Ans2 <> "" Then
            Ans2 = Mid(Ans2, 1, Len(Ans2) - Len(Separator))
        End If
        COMPARE = Ans2
    End If

End Function

3. After pasting the code in the Module (Code) window, go to click Tools > References to open the References – VBAProject window, check the Microsoft Scripting Runtime box and then click the OK button.

4. Press the Alt + Q keys to close the Microsoft Visual Basic for Applications window.

5. Now you need to apply two functions separately to return the duplicate and unique values from two comma separated value cells.

Return duplicate value

Select a cell to output the duplicate numbers, in this example, I select cell D2, then enter the formula below and press the Enter key to get the duplicate numbers between cell A2 and B2.

Select the formula cell and drag its AutoFill Handle down to get the duplicate numbers between cells in the other rows.

=COMPARE(A2,B2,TRUE)

Return unique values

Select a cell to output the unique numbers, in this example, I select cell E2, then enter the formula below and press the Enter key to get the unique numbers between cell A2 and B2.

Select the formula cell and drag its AutoFill Handle down to get the unique numbers between cells in the other rows.

=COMPARE(A2,B2,FALSE)


The Best Office Productivity Tools

Kutools for Excel Solves Most of Your Problems, and Increases Your Productivity by 80%

  • Reuse: Quickly insert complex formulas, charts and anything that you have used before; Encrypt Cells with password; Create Mailing List and send emails...
  • Super Formula Bar (easily edit multiple lines of text and formula); Reading Layout (easily read and edit large numbers of cells); Paste to Filtered Range...
  • Merge Cells/Rows/Columns without losing Data; Split Cells Content; Combine Duplicate Rows/Columns... Prevent Duplicate Cells; Compare Ranges...
  • Select Duplicate or Unique Rows; Select Blank Rows (all cells are empty); Super Find and Fuzzy Find in Many Workbooks; Random Select...
  • Exact Copy Multiple Cells without changing formula reference; Auto Create References to Multiple Sheets; Insert Bullets, Check Boxes and more...
  • Extract Text, Add Text, Remove by Position, Remove Space; Create and Print Paging Subtotals; Convert Between Cells Content and Comments...
  • Super Filter (save and apply filter schemes to other sheets); Advanced Sort by month/week/day, frequency and more; Special Filter by bold, italic...
  • Combine Workbooks and WorkSheets; Merge Tables based on key columns; Split Data into Multiple Sheets; Batch Convert xls, xlsx and PDF...
  • More than 300 powerful features. Supports Office / Excel 2007-2021 and 365. Supports all languages. Easy deploying in your enterprise or organization. Full features 30-day free trial. 60-day money back guarantee.
kte tab 201905

Office Tab Brings Tabbed interface to Office, and Make Your Work Much Easier

  • Enable tabbed editing and reading in Word, Excel, PowerPoint, Publisher, Access, Visio and Project.
  • Open and create multiple documents in new tabs of the same window, rather than in new windows.
  • Increases your productivity by 50%, and reduces hundreds of mouse clicks for you every day!
officetab bottom
Comments (0)
No ratings yet. Be the first to rate!
There are no comments posted here yet
Leave your comments
Posting as Guest
×
Rate this post:
0   Characters
Suggested Locations

Follow Us

Copyright © 2009 - www.extendoffice.com. | All rights reserved. Powered by ExtendOffice. | Sitemap
Microsoft and the Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries.
Protected by Sectigo SSL