VBA - Delete row based on cell above (date) and cells left (number)

marshy3300

Board Regular
Joined
Aug 17, 2014
Messages
59
Hi - I have in A some order numbers and D has dates. A will populate blanks below row 1 until a new order begins and then enter a new order number followed by blanks dependent on how many lines on the order. D has 2 different dates.

I want to be able auto fill the blanks in A (already solved) and delete the whole row based on the date above not matching and the order numbers matching as well.
Where the order number is listed as default (before auto fill) the corresponding date will always be the one to keep

Sorry i cant post attachements!

1 .......order number..........code............description.......date.........result<result>
2 .......66644...................Item1 ............Descr 1 ........13/06 .......Keep
3 .......blank ...................item2 ............descr 2 ........13/06 .......keep
4 .......blank ...................item 3 ............descr 3 ........07/06 .......delete
5 .......blank ...................item 4 ............descr 4 ........13/06 .......keep
6 .......66687 .................Item1 ............Descr 1 ........20/06 .......Keep
7 .......blank ..................item5 ............descr 5 ........13/06 .......delete
8 .......blank ...................item 6 ............descr 6 ........20/06 .......keep
9 .......blank ...................item 7 ............descr 7 ........13/06 .......delete
10 .....67015 ...................item 3 ............descr 3 ........19/09 .......keep</result>
 
Last edited:

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Here is how I did it. Make sure you change the sheet name in the indicated line.

Code:
Public Sub DeleteRows()
  Dim lngLastRow As Long
  Dim lngCounter As Long
  Dim rngFirst As Range
  Dim wksData As Worksheet
  Dim j As Long
  
  On Error GoTo ErrorHandler
  Set wksData = ThisWorkbook.Sheets("Orders")   '<--- IMPORTANT: Set name of sheet here
  
  lngLastRow = wksData.Cells(wksData.Rows.Count, "B").End(xlUp).Row

' Fill the blanks in column A:
  
  On Error Resume Next
  With wksData.Range("A2:A" & lngLastRow)
    .SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
    .Value = .Value
  End With
  
' Delete rows with inconsistent dates:
  
  On Error GoTo ErrorHandler
  For j = lngLastRow To 2 Step -1
    Set rngFirst = wksData.Range("A2:A" & lngLastRow).Find( _
      What:=wksData.Cells(j, "A").Value, _
      After:=wksData.Cells(lngLastRow, "A"), _
      LookIn:=xlValues, LookAt:=xlWhole)
    If wksData.Cells(j, "D").Value <> rngFirst.Offset(, 3).Value Then
      wksData.Rows(j).Delete
      lngCounter = lngCounter + 1
    End If
  Next j
  
  MsgBox Format(lngCounter, "#,0") & " row(s) were deleted.", vbInformation
  
ExitHandler:
  Set rngFirst = Nothing
  Set wksData = Nothing
  Exit Sub
  
ErrorHandler:
  MsgBox Err.Description, vbExclamation
  Resume ExitHandler
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,162
Members
453,021
Latest member
Justyna P

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