Delete rows of data based on ID from another workbook

keiranwyllie

New Member
Joined
May 12, 2017
Messages
47
Hi all,

Can anyone suggest the best to go about this please? I have one workbook that contains 1000's of rows of data. Each row has an ID in column A (This ID may exist on multiple rows). I want to use another workbook that only lists relevant ID, and have the original workbook delete all rows that do not contain any of those IDs (row 1 must remain). See below for example.

Workbook One (before any rows are deleted).
example.xlsx
ABCDE
1IDNameTitleDept IDCse Name
2100000Doe, JohnMR102983Course 1
3100000Doe, JohnMR102983Course 2
4100000Doe, JohnMR102983Course 3
5100000Doe, JohnMR102983Course 4
6100000Doe, JohnMR102983Course 5
7100000Doe, JohnMR102983Course 6
8110000Doe, JaneMS102983Course 1
9110000Doe, JaneMS102983Course 2
10110000Doe, JaneMS102983Course 3
11110000Doe, JaneMS102983Course 4
12110000Doe, JaneMS102983Course 5
13110000Doe, JaneMS102983Course 6
14120000Jane, MaryMRS102983Course 3
15120000Jane, MaryMRS102983Course 4
16120000Jane, MaryMRS102983Course 5
17120000Jane, MaryMRS102983Course 6
18130000Lomar, BarryMR102983Course 1
19130000Lomar, BarryMR102983Course 2
20130000Lomar, BarryMR102983Course 3
21130000Lomar, BarryMR102983Course 4
22130000Lomar, BarryMR102983Course 5
Sheet1


Workbook Two (contains ID of rows I want to keep)
Book1
ABC
1ID
2110000
3130000
4
Sheet1


Workbook One (expected data following deletion of rows)
example.xlsx
ABCDE
1IDNameTitleDept IDCse Name
2110000Doe, JaneMS102983Course 1
3110000Doe, JaneMS102983Course 2
4110000Doe, JaneMS102983Course 3
5110000Doe, JaneMS102983Course 4
6110000Doe, JaneMS102983Course 5
7110000Doe, JaneMS102983Course 6
8130000Lomar, BarryMR102983Course 1
9130000Lomar, BarryMR102983Course 2
10130000Lomar, BarryMR102983Course 3
11130000Lomar, BarryMR102983Course 4
12130000Lomar, BarryMR102983Course 5
Sheet1


Any help would be greatly appreciated.
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Try this out.

VBA Code:
Sub FilterArray()
    
    Dim wb As Workbook, bk As Workbook
    Dim sh As Worksheet, ws As Worksheet
    Dim MyArray() As Variant, x As Long

    Set wb = Workbooks("Source.xlsm")            'workbook with the code and the values to search for
    Set bk = Workbooks("example.xlsx")           'workbook to delete rows.
    Set ws = wb.Sheets("Sheet1")
    Set sh = bk.Sheets("Sheet1")

    With ws
        MyArray = .Range("A2:A" & .Cells(.Rows.Count, "A").End(xlUp).Row).Value
    End With

    With sh
        For x = .Cells(.Rows.Count, "A").End(xlUp).Row To 2 Step -1
            If Not IsNumeric(Application.Match(.Cells(x, 1), MyArray, 0)) Then
                .Cells(x, 1).EntireRow.Delete
            End If
        Next
    End With

End Sub
 
Upvote 0
Thanks for the speedy reply. Unfortunately it's not working. I did a little debugging and noticed that it's trying to delete rows from workbook two (identified by deleting Not from the If statement). Trying to play around with the code now though to see if I can get it to delete from workbook one instead.

Try this out.

VBA Code:
Sub FilterArray()
   
    Dim wb As Workbook, bk As Workbook
    Dim sh As Worksheet, ws As Worksheet
    Dim MyArray() As Variant, x As Long

    Set wb = Workbooks("Source.xlsm")            'workbook with the code and the values to search for
    Set bk = Workbooks("example.xlsx")           'workbook to delete rows.
    Set ws = wb.Sheets("Sheet1")
    Set sh = bk.Sheets("Sheet1")

    With ws
        MyArray = .Range("A2:A" & .Cells(.Rows.Count, "A").End(xlUp).Row).Value
    End With

    With sh
        For x = .Cells(.Rows.Count, "A").End(xlUp).Row To 2 Step -1
            If Not IsNumeric(Application.Match(.Cells(x, 1), MyArray, 0)) Then
                .Cells(x, 1).EntireRow.Delete
            End If
        Next
    End With

End Sub
 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,289
Members
452,631
Latest member
a_potato

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