Simple loop issue ?

axelg

New Member
Joined
Jan 21, 2016
Messages
43
Office Version
  1. 365
Platform
  1. Windows
I have a repetitive task were I have to combine dat from multiple sheets and check for duplicates. and som other stuff

So the sheet (sheet2, generated thru othe vba scripts,but until there all works ) looks something like this
1672745982577.png


Then I have a short vba loop

VBA Code:
Sub Delete()

Sheets("Sheet2").Select
Range("a1").Select
lr2 = Cells.Find("*", Cells(1, 1), xlFormulas, xlPart, xlByRows, xlPrevious, False).Row

 Dim cell As Range

    For Each cell In Range("b2:b" & lr2)
     If cell.Value = "0" Then
        cell.EntireRow.Delete
     End If
    Next cell

    
End Sub

But this only deletes some rows ?? so my result look like this after running the code

1672746075151.png

Running it again, again some lines are deleted, but not all that contain value 0 in colomn B ?


Seems simple, what am I missing (I'm VBA newby)

PS Short other question, How do I address the #N/A in the list? Once the above is ok it should delete all rows that don't contain #N/A
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
When deleting row-by-row like that you are best to work from the bottom up. Try this instead with a copy of your data.
Also, not a good idea to name a procedure with a word that vba already uses as part of its nomenclature (eg Delete).

VBA Code:
Sub Delete_Rows()
  Dim r As Long
  
  With Sheets("Sheet2")
    For r = .Cells.Find("*", .Cells(1, 1), xlFormulas, xlPart, xlByRows, xlPrevious, False).Row To 2 Step -1
      If .Cells(r, "B").Value = 0 Then .Rows(r).Delete
    Next r
  End With
End Sub
 
Upvote 0
Solution
When deleting row-by-row like that you are best to work from the bottom up. Try this instead with a copy of your data.
Also, not a good idea to name a procedure with a word that vba already uses as part of its nomenclature (eg Delete).

VBA Code:
Sub Delete_Rows()
  Dim r As Long
 
  With Sheets("Sheet2")
    For r = .Cells.Find("*", .Cells(1, 1), xlFormulas, xlPart, xlByRows, xlPrevious, False).Row To 2 Step -1
      If .Cells(r, "B").Value = 0 Then .Rows(r).Delete
    Next r
  End With
End Sub
Thanks for that Peter, works like a charm now.
Also Tip for not using nomenclature. (I had it in a larger script but as this part didn't work as expected I just copied it to see if it was really that part that was going wrong, but thanks for the tip anyhow.

Any hints on how I can remove the lines don't contain #N/A (should be regular text as I copied/ pasted values there) after the above has run?
So I suppose similar script but
If .Cells(r, "B").Value = 0 Then .Rows(r).Delete should then be
If .Cells(r, "C").Value <> "#N/A" 0 Then .Rows(r).Delete (as these should be found in column C) ?
 
Upvote 0
Any hints on how I can remove the lines don't contain #N/A (should be regular text as I copied/ pasted values there) after the above has run?
Just want to check on the requirement. If we look at your image in post #1 and if your code had worked correctly, those last 3 rows with 0 in column B would have been deleted. If we now delete all rows that don't contain #N/A in column C, nothing would be left (except the headings). Have I interpreted the requirement correctly?
That is, in the example below ..
  • Yellow rows would get deleted because they have 0 in column B
  • Blue rows would get deleted because they don't have #N/A in column C
  • Green rows would be the only rows remaining after the code
axelg.xlsm
ABC
1Hdr 1Hdr 2
2a#N/A
30
40#N/A
50#N/A
6bz
7c#N/A
8d
90
10ey
Sheet3
 
Upvote 0
heck on the requirement. If we look at your image in post #1 and if your code had worked correctly, those last 3 rows with 0 in column B would have been deleted. If we now delete all rows that don't contain #N/A in column C, nothing would be left (except the headings). Have I interpreted the requirement correctly?
That is, in the example below ..
  • Yellow rows would get deleted because they have 0 in column B
  • Blue rows would get deleted because they don't have #N/A in column C
  • Green rows would be the only rows remaining after the code
Yes indeed, the green ones are the only ones that should remain.
So first I take out all the "0" in column B and from the remainder I can take out all rows that don't contain #N/A
 
Upvote 0
Yes indeed, the green ones are the only ones that should remain.
Thanks for the confirmation.

So first I take out all the "0" in column B and from the remainder I can take out all rows that don't contain #N/A
Might as well take them all out on the first run through.

VBA Code:
Sub Delete_Rows_v2()
  Dim r As Long
  
  With Sheets("Sheet2")
    For r = .Cells.Find("*", .Cells(1, 1), xlFormulas, xlPart, xlByRows, xlPrevious, False).Row To 2 Step -1
      If .Cells(r, "B").Value = 0 Or .Cells(r, "C").Text <> "#N/A" Then .Rows(r).Delete
    Next r
  End With
End Sub
 
Upvote 0
Thanks for the confirmation.


Might as well take them all out on the first run through.

VBA Code:
Sub Delete_Rows_v2()
  Dim r As Long
 
  With Sheets("Sheet2")
    For r = .Cells.Find("*", .Cells(1, 1), xlFormulas, xlPart, xlByRows, xlPrevious, False).Row To 2 Step -1
      If .Cells(r, "B").Value = 0 Or .Cells(r, "C").Text <> "#N/A" Then .Rows(r).Delete
    Next r
  End With
End Sub
Many thanks, Will defenatly try that. This makes a long, manual repetitive job suddenly very easy :-)
 
Upvote 0
This makes a long, manual repetitive job suddenly very easy
About how many rows of data would you normally be starting with?

About how many rows would normally have to be deleted?

I am asking since if the data is large and particularly if there is a lot of disjoint rows to be deleted then the code I suggested may be quite slow. There are faster ways if required.
 
Upvote 0
About how many rows of data would you normally be starting with?

About how many rows would normally have to be deleted?

I am asking since if the data is large and particularly if there is a lot of disjoint rows to be deleted then the code I suggested may be quite slow. There are faster ways if required.
It's around 7000 lines and after running there will be appox 20 left.
 
Upvote 0
It's around 7000 lines and after running there will be appox 20 left.
Hmm, you may want to also give this one a try to compare. Longer code but much faster.

VBA Code:
Sub Delete_Rows_v3()
  Dim a As Variant, b As Variant
  Dim nc As Long, i As Long, k As Long
  
  With Sheets("Sheet2")
    nc = .Cells.Find(What:="*", LookIn:=xlFormulas, SearchOrder:=xlByColumns, SearchDirection:=xlPrevious).Column + 1
    a = .Range("B2:C" & .Cells.Find("*", .Cells(1, 1), xlFormulas, xlPart, xlByRows, xlPrevious, False).Row).Value
    ReDim b(1 To UBound(a), 1 To 1)
    For i = 1 To UBound(a)
      If a(i, 1) = 0 Or Not IsError(a(i, 2)) Then
        b(i, 1) = 1
        k = k + 1
      End If
    Next i
    If k > 0 Then
      Application.ScreenUpdating = False
      With .Range("A2").Resize(UBound(a), nc)
        .Columns(nc).Value = b
        .Sort Key1:=.Columns(nc), Order1:=xlAscending, Header:=xlNo
        .Resize(k).EntireRow.Delete
      End With
      Application.ScreenUpdating = True
    End If
  End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,098
Messages
6,170,099
Members
452,301
Latest member
QualityAssurance

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