Delete rows given text in column A is not within data range

bmoore45

New Member
Joined
Jun 19, 2011
Messages
39
I don't know if my title is completely correct...

Anyway hi guys,

I have two lists of names, which for examples sake we will call List X and List Y.

List X is a small list of names, the names of which can all be found within List Y. List Y is very long and contains a large list of names.

I want to be able to delete each row on List Y given that the cell in column A of that row does not contain a name from List X.

How difficult is this and whats the best way to do it??? If possible Can anybody post a link because I can't seem to find anything concrete on the issue. A solution is also welcome too!

Thanks guys I really appreciate it!

Ben
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
With Y in column A of Sheet1 and X in column A of Sheet2

Code:
Sub atest()
Dim LR As Long, i As Long
With Sheets("Sheet1")
    LR = .Range("A" & Rows.Count).End(xlUp).Row
    For i = LR To 1 Step -1
        If IsError(Application.Match(.Range("A" & i).Value, Sheets("Sheet2").Columns("A"), 0)) Then .Rows(i).Delete
    Next i
End With
End Sub
 
Upvote 0
You could use COUNTIF formulas to determine if each name in List Y is found in List X.
<br /><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;;">List Y</td><td style="font-weight: bold;;">Match?</td><td style="font-weight: bold;text-align: right;;"></td><td style="font-weight: bold;;">List X</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">Al</td><td style="text-align: right;;">FALSE</td><td style="text-align: right;;"></td><td style=";">Joe</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Joe</td><td style="text-align: right;;">TRUE</td><td style="text-align: right;;"></td><td style=";">Ann</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Bob</td><td style="text-align: right;;">FALSE</td><td style="text-align: right;;"></td><td style=";">Phil</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">Sue</td><td style="text-align: right;;">FALSE</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">Bill</td><td style="text-align: right;;">FALSE</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">Jim</td><td style="text-align: right;;">FALSE</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style=";">Phil</td><td style="text-align: right;;">TRUE</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style=";">Jack</td><td style="text-align: right;;">FALSE</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style=";">Ann</td><td style="text-align: right;;">TRUE</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr></tbody></table><br /><br /><table cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">B2</th><td style="text-align:left">=COUNTIF(<font color="Blue">D:D,A2</font>)>0</td></tr></tbody></table></td></tr></table><br />
Then use AutoFilter to display only the False cells in column B and then delete the visible autofiltered rows.

  • Select column B
  • Select from the menu Data\ Filter \Autofilter
  • This will put a drop down list in B1
  • Select from the B1 drop down list False
  • Select all the visible rows and Delete
  • Select Autofilter from the menu again to turn it off
 
Upvote 0
hey Alphafrog,

I'm having a go at accomplishing this using your method but have run into a bit of trouble.

Here is the list I'm checking from (not rcolombo I highlighted)

playerlist.jpg


And here is the list I'm checking (note rcolombo is listed but the formula reads false).

playerlist2.jpg


its coming up as false for some reason.

Here's the the formula i'm using:

=COUNTIF(PlayerGrid!A1088:A4635,A2)>0

can u spot what i'm doin wrong???????
 
Upvote 0
nvm i realize now it has (ft) after each name, it works gr8 now thx mate.

on another note how can i mass delete the (ft) txt from each cell???? the list is 4700+ lines so deleting 1 by 1 is kinda out of the question..
 
Upvote 0
Try something like this...

=COUNTIF(PlayerGrid!$A$1088:$A$4635,LEFT(A2,LEN(A2)-5))>0

This omits the last five characters " (ft)" from the value in A2

Also, you probably want to use an absolute reference for the PlayerGrid list so it doesn't change for each formula.
PlayerGrid!$A$1088:$A$4635
 
Last edited:
Upvote 0
You could also use the Replace tool (Ctrl+H) to replace all the " (FT)" from column A and replace it with nothing.
 
Upvote 0

Forum statistics

Threads
1,224,521
Messages
6,179,286
Members
452,902
Latest member
Knuddeluff

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