VBA - Remove entire rows when a cell contains -

Spartanjuli1

New Member
Joined
Sep 13, 2016
Messages
13
Office Version
  1. 365
Platform
  1. Windows
Hello,

This is a topic I was looking on google but every VBA do not work for me and I don't know what I am doing wrong unfortunately.
I am working under Excel 2013.

To make it simple, I have a similar tab below where I want to delete the entire row where there is the value "FALSE" in the B column and shift up other rows.
This table is pretty big and values from columns B are the result of a Formula (I do not know if that will impact the VBA)

Do you know a query that would work here ?

AB
1xFALSE
2vTRUE
...xTRUE
50618vFALSE

<tbody>
</tbody>


To become

AB
1vTRUE
2xTRUE
...xvTRUE

<tbody>
</tbody>

Thank you for your help !
Julien
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
Hi Spartanjuli1,

Run the following macro while on the sheet in question (though initially on a copy of your data as the results cannot be undone if they're not as expected):

Code:
Option Explicit
Sub Macro2()

    Const lngStartRow As Long = 1 'Starting data row number. Change to suit.
    
    Dim lngMyCol As Long, _
        lngMyRow As Long
    Dim xlnCalcMethod As XlCalculation
            
    With Application
        xlnCalcMethod = .Calculation
        .Calculation = xlCalculationManual
        .ScreenUpdating = False
    End With

    lngMyCol = Cells.Find("*", SearchOrder:=xlByColumns, SearchDirection:=xlPrevious).Column + 1
    lngMyRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    
    With Columns(lngMyCol)
        With Range(Cells(lngStartRow, lngMyCol), Cells(lngMyRow, lngMyCol))
            .Formula = "=IF(B" & lngStartRow & "=FALSE,NA(),"""")"
            ActiveSheet.Calculate
            .Value = .Value
        End With
        On Error Resume Next 'Turn error reporting off - OK to ignore 'No cells found' message
            .SpecialCells(xlCellTypeConstants, xlErrors).EntireRow.Delete
        On Error GoTo 0 'Turn error reporting back on
        .Delete
    End With
    
    With Application
        .Calculation = xlnCalcMethod
        .ScreenUpdating = True
    End With

    MsgBox "All rows from Col. B that were flagged with FALSE have now been deleted.", vbInformation

End Sub

Note as it doesn't loop it's very fast.

Robert
 
Upvote 0
Hi Spartanjuli1,

Run the following macro while on the sheet in question (though initially on a copy of your data as the results cannot be undone if they're not as expected):

Code:
Option Explicit
Sub Macro2()

    Const lngStartRow As Long = 1 'Starting data row number. Change to suit.
    
    Dim lngMyCol As Long, _
        lngMyRow As Long
    Dim xlnCalcMethod As XlCalculation
            
    With Application
        xlnCalcMethod = .Calculation
        .Calculation = xlCalculationManual
        .ScreenUpdating = False
    End With

    lngMyCol = Cells.Find("*", SearchOrder:=xlByColumns, SearchDirection:=xlPrevious).Column + 1
    lngMyRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    
    With Columns(lngMyCol)
        With Range(Cells(lngStartRow, lngMyCol), Cells(lngMyRow, lngMyCol))
            .Formula = "=IF(B" & lngStartRow & "=FALSE,NA(),"""")"
            ActiveSheet.Calculate
            .Value = .Value
        End With
        On Error Resume Next 'Turn error reporting off - OK to ignore 'No cells found' message
            .SpecialCells(xlCellTypeConstants, xlErrors).EntireRow.Delete
        On Error GoTo 0 'Turn error reporting back on
        .Delete
    End With
    
    With Application
        .Calculation = xlnCalcMethod
        .ScreenUpdating = True
    End With

    MsgBox "All rows from Col. B that were flagged with FALSE have now been deleted.", vbInformation

End Sub

Note as it doesn't loop it's very fast.

Robert

Out of interest, how does this compare speed-wise to using autofilter on column B and using SpecialCells.(xlCellTypeVisible)?
 
Upvote 0
Try this:
Code:
Sub Filter_Me()
Application.ScreenUpdating = False
    With ActiveSheet.Range(Cells(1, 2), Cells(Cells(Rows.Count, 2).End(xlUp).Row, 2))
        .AutoFilter Field:=1, Criteria1:="False"
        .Offset(1).Resize(.Rows.Count - 1).SpecialCells(xlCellTypeVisible).EntireRow.Delete
        .AutoFilter
    End With
Application.ScreenUpdating = True
End Sub
 
Upvote 0
Try this:
Code:
Sub Filter_Me()
Application.ScreenUpdating = False
    With ActiveSheet.Range(Cells(1, 2), Cells(Cells(Rows.Count, 2).End(xlUp).Row, 2))
        .AutoFilter Field:=1, Criteria1:="False"
        .Offset(1).Resize(.Rows.Count - 1).SpecialCells(xlCellTypeVisible).EntireRow.Delete
        .AutoFilter
    End With
Application.ScreenUpdating = True
End Sub

Hello,

This works great with the example I have above and with my file that's good until the line.
.AutoFilter Field:=1, Criteria1:="False"

but at the time to execute the next one, I have the run time error 1004.
.Offset(1).Resize(.Rows.Count - 1).SpecialCells(xlCellTypeVisible).EntireRow.Delete

in my file, the column where the "FALSE" value is located is "CJ", so column 88.
I modified the Autofilter field to "88" but it is not enough.

How can it be done then ?

Thank you
 
Upvote 0
Try this:

You will see in row 1 of the code I entered 88 in three different places. Leaving filter set to 1
Code:
Sub Filter_Me()
Application.ScreenUpdating = False
    With ActiveSheet.Range(Cells(1, [COLOR=#ff0000]88[/COLOR]), Cells(Cells(Rows.Count, [COLOR=#ff0000]88[/COLOR]).End(xlUp).Row, [COLOR=#ff0000]88[/COLOR]))
        .AutoFilter Field:=1, Criteria1:="False"
        .Offset(1).Resize(.Rows.Count - 1).SpecialCells(xlCellTypeVisible).EntireRow.Delete
        .AutoFilter
    End With
Application.ScreenUpdating = True
End Sub
 
Upvote 0
Out of interest, how does this compare speed-wise to using autofilter on column B and using SpecialCells.(xlCellTypeVisible)?

Good question. It would depend on the size of the data-set I suppose. There is a limit to the number of the rows that can be filtered but we'd be talking thousands of rows.

Maybe Spartanjuli1 could try both and let us know?
 
Upvote 0
If your value to search for and your column to look in will change.
You will get Inputbox asking for these criteria
Try this:

Code:
Sub Filter_Me()
Application.ScreenUpdating = False
On Error GoTo M
Dim ans As Long
ans = InputBox("Enter filter column like 88")
anss = InputBox("Enter filter value Like Apples")
    With ActiveSheet.Range(Cells(1, ans), Cells(Cells(Rows.Count, ans).End(xlUp).Row, ans))
        .AutoFilter Field:=1, Criteria1:=anss
        .Offset(1).Resize(.Rows.Count - 1).SpecialCells(xlCellTypeVisible).EntireRow.Delete
        .AutoFilter
    End With
Application.ScreenUpdating = True
Exit Sub
M:
MsgBox "We found no rows meeting this request"
ActiveSheet.AutoFilterMode = False
End Sub
 
Upvote 0
Hello,

My table has 20,000 rows and 88 columns with data.
I am a newbie with VBA and I believe I did not gave you an important data: the column to filter is included into a "Table" and when I run your script with the data out of the table, it works but not when it is under a "Table"...

Sorry for this, I believe this has an impact then on the script.

Best Regards
 
Upvote 0

Forum statistics

Threads
1,214,858
Messages
6,121,956
Members
449,057
Latest member
FreeCricketId

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