VBA: Deleting rows after 2 columns have been filtered.

TitoBurrito

New Member
Joined
Oct 27, 2022
Messages
11
Office Version
  1. 365
Platform
  1. Windows
Hello,

After research and trial and error I am unable to get this to work.

Here is my code:

With Sheet2.Range("A1:BM1")
.AutoFilter Field:=13, Criteria1:="*EMEA*", Operator:=xlOr, Criteria2:="*Oceania*"
.AutoFilter Field:=42, Criteria1:="="
.Offset(1, 0).Resize(.Rows.Count - 1).SpecialCells(xlCellTypeVisible).Rows.Delete
End With
Sheet2.AutoFilterMode = False

I am trying to filter column 13 with criteria and column 42 for blanks, then delete all the rows that that are populated.
The filtering is working. The deleting of the rows is the problem.
I am getting Run-time error 1004: Application-defined or object-defined error. With the .OFFSET(1,0) ROW BEING HIGHLIGHTED.

Any help would be lovely,
Thank You
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Try something like:

VBA Code:
    With Sheet2
        .AutoFilterMode = False                                                                     '   Remove filter
'
        With .UsedRange
            .AutoFilter Field:=13, Criteria1:="*EMEA*", Operator:=xlOr, Criteria2:="*Oceania*"
            .AutoFilter Field:=42, Criteria1:="="
'
            On Error Resume Next                                                                    '       For the case when there is no visible rows
            .Resize(.Rows.Count - 1).Offset(1, 0).SpecialCells(xlCellTypeVisible).EntireRow.Delete  '       Skip header row 1
            On Error GoTo 0                                                                         '       Return error handling back to Excel
        End With
'
        .AutoFilterMode = False                                                                     '   Remove filter which leaves remaining rows
    End With
 
Upvote 0
Solution
Maybe you mean something like

Rich (BB code):
    With Sheet2.Range("A1:BM" & Sheet2.Range("A" & Rows.Count).End(xlUp).Row)
        .AutoFilter Field:=13, Criteria1:="*EMEA*", Operator:=xlOr, Criteria2:="*Oceania*"
        .AutoFilter Field:=42, Criteria1:="="
        .Offset(1, 0).Resize(.Rows.Count - 1).SpecialCells(xlCellTypeVisible).EntireRow.Delete
    End With
    Sheet2.AutoFilterMode = False
 
Upvote 0
Try something like:

VBA Code:
    With Sheet2
        .AutoFilterMode = False                                                                     '   Remove filter
'
        With .UsedRange
            .AutoFilter Field:=13, Criteria1:="*EMEA*", Operator:=xlOr, Criteria2:="*Oceania*"
            .AutoFilter Field:=42, Criteria1:="="
'
            On Error Resume Next                                                                    '       For the case when there is no visible rows
            .Resize(.Rows.Count - 1).Offset(1, 0).SpecialCells(xlCellTypeVisible).EntireRow.Delete  '       Skip header row 1
            On Error GoTo 0                                                                         '       Return error handling back to Excel
        End With
'
        .AutoFilterMode = False                                                                     '   Remove filter which leaves remaining rows
    End With
Thank you Johnny!
This worked out and thanks for the explanations on what the code is doing.
 
Upvote 0
Thank you Johnny!
This worked out and thanks for the explanations on what the code is doing.
Just to clarify you can offset a one row range (other than the last row on the sheet), it just becomes the next row
VBA Code:
Sub testone()
Debug.Print Range("A1:G1").Offset(1, 0).Address
End Sub
1675980868658.png

What you can't do is resize a one row range by -1 row as it would be a zero row
VBA Code:
Sub testtwo()
Debug.Print Range("A1:G1").Resize(Range("A1:G1").Rows.Count - 1).Address
End Sub
 
Last edited:
Upvote 0
Just to clarify you can offset a one row range (other than the last row on the sheet), it just becomes the next row

Of course you are right @MARK858. I posted kind of a half thought that I had & by the time I came back to finish it, it was past the edit time allowed.

What I was thinking, but failed miserably in my post, was that you can't offset(1,0) a 1 row range and have it delete all of the visible rows (minus the first row) as the OP was attempting to do. My apologies for the misleading post I made.

The clarification is definitely welcomed.
 
Upvote 0
What you can't do is resize a one row range by -1 row as it would be a zero row

For the record, You can resize a one row range by -1 row.

VBA Code:
Sub testtwo()
    Debug.Print Range("A2:G2").Offset(-1, 0).Address
End Sub

:p
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,182
Members
453,021
Latest member
Mohamed Magdi Tawfiq Emam

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