Macro to delete entire row based on a formula result (procv)

Ulisses_Carso

New Member
Joined
Sep 4, 2020
Messages
39
Office Version
  1. 365
Platform
  1. Windows
Good afternoon,

I have small code to delete rows based on cell value, but my code doesn't work if the value is formula result.
I Make a ProcV to find a cell and i need to search and delete a row based on that ProcV but i can't figure a way to do that.
Can someone give me a light on how to solve.


VBA Code:
Sub BuscaDeletaPlaca()

Dim rngFound As Range
Dim sht1 As Worksheet

Set sht1 = ThisWorkbook.Worksheets("Base")
With sht1.Range("A:A")
    Set rngFound = .Find(What:="desligado")
    If Not rngFound Is Nothing Then
        While Not rngFound Is Nothing
            sht1.Rows(rngFound.Row).EntireRow.Delete
            Set rngFound = .FindNext
        Wend
    End If
End With

End Sub
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
I ran a last test on my code and it didn't work when I uncommented the delete, so stay tuned, ;)
 
Upvote 0
I have made some changes to your code,

  • The Excel Find box remembers previous settings within the same session, so I explicitly added xlValues, which should look at the result of a formula
  • I have also added xlPrevious to the initial find and replaced .FindNext with .FindPrevious.
    This is because deleting rows works more efficiently if you start at the bottom, this is because Excel needs to rearrange all the rows below the deleted row.
  • When I tested the .FindNext was not moving on to the next record both .FindNext & .FindPrevious needed the parameter (rngFound) added.
  • I had to delete the current row "after" I did the next .FindPrevious or the code errored out.

Hope this works for you.

VBA Code:
Sub BuscaDeletaPlaca()

    Dim rngFound As Range
    Dim sht1 As Worksheet
    Dim rowToDelete As Long    
    
    Set sht1 = ThisWorkbook.Worksheets("Base")
    With sht1.Range("A:A")
        Set rngFound = .Find(What:="desligado", LookIn:=xlValues, searchdirection:=xlPrevious)
        If Not rngFound Is Nothing Then
            While Not rngFound Is Nothing
                rowToDelete = rngFound.Row
                Set rngFound = .FindPrevious(rngFound)
                sht1.Rows(rowToDelete).EntireRow.Delete
            Wend
        End If
    End With

End Sub
 
Upvote 0
@ Ulisses_Carso
In you code Just replace with
VBA Code:
 Set rngFound = .Find(What:="desligado", LookIn:=xlValues)
 
Upvote 0
First, thanks for the help, both codes do what I need.

Alex, when your code delete the last row it comes into an error, "The object is required", but it delete all rows as I need
Mohadin, that "LookIn:=xlValues" resolves everything, thx dude
 
Upvote 0
First, thanks for the help, both codes do what I need.

Alex, when your code delete the last row it comes into an error, "The object is required", but it delete all rows as I need
Mohadin, that "LookIn:=xlValues" resolves everything, thx dude
Thanks for the feedback. Here is the updated code.
If you have a large volume of data and there are a lot of formulas on the rows, running the delete from the bottom up should be quite a bit faster.

VBA Code:
Sub BuscaDeletaPlaca()

    Dim rngFound As Range
    Dim sht1 As Worksheet
    Dim rngToDelete As Range
        
    Set sht1 = ThisWorkbook.Worksheets("Base")
    With sht1.Range("A:A")
        Set rngFound = .Find(What:="desligado", LookIn:=xlValues, searchdirection:=xlPrevious)
        If Not rngFound Is Nothing Then
            While Not rngFound Is Nothing
                Set rngToDelete = rngFound
                Set rngFound = .FindPrevious(rngFound)
                If rngFound = rngToDelete Then Set rngFound = Nothing
                rngToDelete.EntireRow.Delete
            Wend
        End If
    End With

End Sub
 
Upvote 0

Forum statistics

Threads
1,213,510
Messages
6,114,044
Members
448,543
Latest member
MartinLarkin

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