Error-Handling for Repeat VBA Code for Multiple Values

JohnHenry

New Member
Joined
Mar 12, 2013
Messages
27
I think the code is fairly self-explanatory, but I'm trying to search for a number (VehNum) in a column (VehCol) and copy all of the rows with the same number in the that column to a new sheet. I'm receiving a "Run-time error 1004: Application-defined or object-defined error" in 14th line of code: "If Cells(VehNumRow, VehCol).Value = VehNum Then." If the numbers in my array exist in the sheet, it works perfectly. However, the numbers in the code can't change day-to-day but their existence on the sheet do. I'm aware of different error-handling procedures like: "On Error Resume Next" but am unsure where to implement the line or of a more feasible method. Any help would be appreciated.


'''''''''''CODE START
Sub VehNum_Test()


''''''''''Discover location of "Vehicle" column
Sheets("Data").Select
Range("A1:Z100").Select
Cells.Find(What:="Vehicle").Select
VehCol = Selection.Column
VehRow = Selection.Row

Sheets("Data").Select
Dim VehNum As Variant, VehNumRow As Long, VehNumStart As Long, VehNumEnd As Long

For Each VehNum In Array(5, 8, 9, 20, 24, 33, '39, 43, 55, 75, _
76, 77, 83, 84, 85, 86, 509, 510, 511, 752)
Sheets("Data").Select
For VehNumRow = 3 To 3000
If Cells(VehNumRow, VehCol).Value = VehNum Then
VehNumStart = VehNumRow
Exit For
End If
Next VehNumRow

'''''''''''Figure out where the "Vehicle VehNum" data ends.
For VehNumRow = VehNumStart To 3000
If Cells(VehNumRow, VehCol).Value <> VehNum Then
VehNumEnd = VehNumRow
Exit For
End If
Next VehNumRow
VehNumEnd = VehNumEnd - 1

'''''''''''Paste data into correct month available cells
Sheets("January").Select
OpenRow = 2
Do While Cells(OpenRow, "A") <> ""
OpenRow = OpenRow + 1
Loop


Sheets("Data").Select
Cells(VehNumStart, "A").Select
Range(Selection, Cells(VehNumEnd, "Z")).Copy
Sheets("January").Select
Range("A" & OpenRow).PasteSpecial
Application.CutCopyMode = False
Next


End Sub
'''''''''''CODE END
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
Instead of on error resume next, why not try to see if you got a match.
VehNumStart = 0
For VehNumRow = 3 To 3000
If Cells(VehNumRow, VehCol).Value = VehNum Then
VehNumStart = VehNumRow
Exit For
End If
Next VehNumRow
If (VehNumStart > 0) Then
'.. do rest
End If


How ever I think this would be more efficient way. I have not testing it though
''''''''''CODE START
Sub VehNum_Test()
Dim cell As Range

''''''''''Discover location of "Vehicle" column
Sheets("Data").Select

Set cell = Range("A1:Z100").Find(What:="Vehicle")
If cell Is Nothing Then
MsgBox "Not able to find vehicle column"
Exit Sub
End If

vehcol = cell.Column
VehRow = cell.Row

Dim VehNum As Variant, VehNumRow As Long, VehNumStart As Long, VehNumEnd As Long

Sheets("Data").AutoFilterMode = False
Range(Cells(2, vehcol), Cells(Rows.Count, vehcol)).AutoFilter

For Each VehNum In Array(5, 8, 9, 20, 24, 33, 39, 43, 55, 75, 76, 77, 83, 84, 85, 86, 509, 510, 511, 752)

Range(Cells(2, vehcol), Cells(Rows.Count, vehcol)).AutoFilter Criteria1:=VehNum
VehNumEnd = Cells(Rows.Count, vehcol).End(xlUp).Row
If (VehNumEnd > 2) Then
'''''''''''Paste data into correct month available cells
openrow = Sheets("January").Cells(Rows.Count, "A").Row
openrow = openrow + 1
Application.CutCopyMode = False
Range(Cells(3, "A"), Cells(VehNumEnd, "Z")).Copy
Sheets("January").Range("A" & openrow).PasteSpecial
Application.CutCopyMode = False
End If
Next

End Sub
'''''''''''CODE END
 
Upvote 0
Rizvisa1,

Thanks for your reply. It does look more efficient. However, I am receiving an error: "AutoFilter method of Range class failed" in the line "Range(Cells(2, vehcol), Cells(Rows.Count, vehcol)).AutoFilter Criteria1:=VehNum." Is there a way I can upload a copy of my sample data as excel file either to this thread or to you directly? Thanks again for helping.

John
 
Upvote 0
Here is tested one :)

Sub VehNum_Test()
Dim cell As Range

''''''''''Discover location of "Vehicle" column
Sheets("Data").Select

Set cell = Range("A1:Z100").Find(What:="Vehicle")
If cell Is Nothing Then
MsgBox "Not able to find vehicle column"
Exit Sub
End If

vehcol = cell.Column
VehRow = cell.Row

Dim VehNum As Variant, VehNumRow As Long, VehNumStart As Long, VehNumEnd As Long

Sheets("Data").AutoFilterMode = False
Range(Cells(2, vehcol), Cells(Rows.Count, vehcol)).AutoFilter

For Each VehNum In Array(5, 8, 9, 20, 24, 33, 39, 43, 55, 75, 76, 77, 83, 84, 85, 86, 509, 510, 511, 752)

Range(Cells(2, vehcol), Cells(Rows.Count, vehcol)).AutoFilter Field:=1, Criteria1:=VehNum
VehNumEnd = Cells(Rows.Count, vehcol).End(xlUp).Row
If (VehNumEnd > 2) Then
'''''''''''Paste data into correct month available cells
openrow = Sheets("January").Cells(Rows.Count, "A").End(xlUp).Row
openrow = openrow + 1
Application.CutCopyMode = False
Range(Cells(3, "A"), Cells(VehNumEnd, "Z")).Copy
Sheets("January").Range("A" & openrow).PasteSpecial
Application.CutCopyMode = False
End If
Next

End Sub
'''''''''''CODE END
 
Upvote 0
Rizvisa1,

It works beautifully, thank you very much. Maybe now I can meet my April 1st deadline for this report ;)

John
 
Upvote 0
You are quite welcome. Long time to April 1st. You still have about 6:20 odd minutes. Whats the rush :)
 
Upvote 0

Forum statistics

Threads
1,213,515
Messages
6,114,080
Members
448,548
Latest member
harryls

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