comparing 2 excel columns and filtering duplicates

apor

New Member
Joined
Dec 20, 2021
Messages
25
Office Version
  1. 2016
Platform
  1. Windows
Hi,

I have two sets of data, one is a column with a certain set of numbers, lets say

11111
33333
55555

Then, i have a second set of data, that is partially made up of this first set of numbers. Each number is matched up with another column. it looks like this:

11111 abc
22222 def
33333 ghi
44444 jkl
55555 mno

I need to somehow filter the second set of data so that i find the results based on the numbers in the first set. my results would be

abc
ghi
mno

i have been doing this by filtering the first column of the second set of data using the data found in my first set, and then copying and pasting the results in the second column of the second set.
how would i go about finding these results using vba code?

any ideas are helpful and thank you in advance!
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
Welcome to Mr. Excel.

Are the "sets of data" in two different sheets?
And, is the second set in two difference columns?
 
Upvote 0
Using Power Query, create a merge (Left Outer Join) of the two tables.

Book4
ABCDEFG
1Column1Column1Column2Column1Table2.Column2
21111111111abc11111abc
33333322222def33333ghi
45555533333ghi55555mno
544444jkl
655555mno
Sheet1


Power Query:
let
    Source = Table.NestedJoin(Table1, {"Column1"}, Table2, {"Column1"}, "Table2", JoinKind.LeftOuter),
    #"Expanded Table2" = Table.ExpandTableColumn(Source, "Table2", {"Column2"}, {"Table2.Column2"})
in
    #"Expanded Table2"
 
Upvote 0
Using Power Query, create a merge (Left Outer Join) of the two tables.

Book4
ABCDEFG
1Column1Column1Column2Column1Table2.Column2
21111111111abc11111abc
33333322222def33333ghi
45555533333ghi55555mno
544444jkl
655555mno
Sheet1


Power Query:
let
    Source = Table.NestedJoin(Table1, {"Column1"}, Table2, {"Column1"}, "Table2", JoinKind.LeftOuter),
    #"Expanded Table2" = Table.ExpandTableColumn(Source, "Table2", {"Column2"}, {"Table2.Column2"})
in
    #"Expanded Table2"

Hi Alan,

thank you for your answer! The third table is exactly the result i wanted. hwoever, is there a way to do this using vba code? the thing is, i get this type of data ( in this set up) daily, in different amounts. sometimes theres 30 rows, sometimes theres 300. I need an automatic and quick way to just enter the data into my worksheet, run the code, and get the result.
 
Upvote 0
Welcome to Mr. Excel.

Are the "sets of data" in two different sheets?
And, is the second set in two difference columns?

hello kwaever,

yes, the second set is in two different columns. the sets of data are not in two different sheets though
 
Upvote 0
Here's a simple and crude VBA to try:

Code:
Sub apor()
Dim lr As Long, lr2 As Long, i As Long, w As Long
lr = Worksheets("Sheet1").Cells(Rows.Count, "A").End(xlUp).Row
lr2 = Worksheets("Sheet2").Cells(Rows.Count, "A").End(xlUp).Row
For i = 2 To lr
 w = Application.WorksheetFunction.Match(Worksheets("Sheet1").Cells(i, "A"), Worksheets("Sheet2").Range("A1:A" & lr2), 0)
 ' no error checking
 Worksheets("Sheet2").Cells(i, "D") = Worksheets("Sheet2").Cells(w, "A")
 Worksheets("Sheet2").Cells(i, "E") = Worksheets("Sheet2").Cells(w, "B")
Next i
End Sub
 
Upvote 0
Here's a simple and crude VBA to try:

Code:
Sub apor()
Dim lr As Long, lr2 As Long, i As Long, w As Long
lr = Worksheets("Sheet1").Cells(Rows.Count, "A").End(xlUp).Row
lr2 = Worksheets("Sheet2").Cells(Rows.Count, "A").End(xlUp).Row
For i = 2 To lr
 w = Application.WorksheetFunction.Match(Worksheets("Sheet1").Cells(i, "A"), Worksheets("Sheet2").Range("A1:A" & lr2), 0)
 ' no error checking
 Worksheets("Sheet2").Cells(i, "D") = Worksheets("Sheet2").Cells(w, "A")
 Worksheets("Sheet2").Cells(i, "E") = Worksheets("Sheet2").Cells(w, "B")
Next i
End Sub
thank you! this worked perfectly. all i did was change i = 2 to i = 2
 
Upvote 0
Power Query is a free AddIn for Excel 2010 and 2013, and is built-in functionality from Excel 2016 onwards (where it is referred to as "Get & Transform Data").

It is a powerful yet simple way of getting, changing and using data from a broad variety of sources, creating steps which may be easily repeated and refreshed. I strongly recommend learning how to use Power Query - it's among the most powerful functionalities of Excel.

- Follow this link to learn how to install Power Query in Excel 2010 / 2013.

- Follow this link for an introduction to Power Query functionality.

- Follow this link for a video which demonstrates how to use Power Query code provided.
 
Upvote 0

Forum statistics

Threads
1,223,231
Messages
6,170,885
Members
452,364
Latest member
springate

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