557 attributed reviews in the last 3 years
Refreshingly small course sizes
Outstandingly good courseware
Whizzy online classrooms
Wise Owls only (no freelancers)
Almost no cancellations
We have genuine integrity
We invoice after training
Review 30+ years of Wise Owl
View our top 100 clients
Search our website
We also send out useful tips in a monthly email newsletter ...
Error-handling and error trapping in Excel Visual Basic macros Part one of a four-part series of blogs |
---|
What happens when your macros go wrong? That depends what error-handling you have in place. Learn how to use ON ERROR and other commands to trap errors in a structured way.
This is one small part of our free online Excel VBA tutorial. To find out how to learn in a more structured way, have a look at our training courses in VBA.
|
Perfect macros don't go wrong, and don't need error-handling? Sadly, not true - this blog explains how error-handling works in VBA, with examples.
Let's start with a simple macro. You want to go to a worksheet and put your name in cell A1, but you're not sure if the worksheet exists. So you could set an error trap:
Sub SignTopLeftCell()
'if an error happens, jump out of the routine
On Error GoTo NoWorksheet
'now try going to worksheet (may trigger error)
Worksheets("TestSheet").Select
'if we get here, the worksheet did exist -
'so sign it and leave
Range("A1").Value = "Wise Owl"
Exit Sub
NoWorksheet:
'if we get here, the worksheet didn't exist -
'display error message
MsgBox "No such worksheet!"
End Sub
This is the template for virtually every error-handling routine: set an error trap, designate where you should go if it's triggered, and exit the subroutine if if isn't.
A label in VBA ends with a colon or : and denotes a place you can jump to.
Labels always appear on the left-hand side of the text:
'it doesn't matter how indented the code is,
'a label will always appear on the left edge
NoWorksheet:
Like most things in VBA, a label can't contain spaces, and should be written in CamelCase (that is, with each word capitalised).
Under normal circumstances, a macro will crash if an error occurs. In the above code, without the error trap this is what you'd see if you tried to go to a non-existent worksheet:
The subscript is out of range because there is no object in the collection of worksheets called TestSheet.
To avoid this happening, you can take control of error messages with one of three statements:
Statement | What it means |
---|---|
On Error GoTo SomeLabel | If an error happens, jump to the given label. |
On Error Resume Next | If an error happens, ignore it and go on to the next statement. |
On Error GoTo 0 | Revert to the default error-handling (ie displaying a system error message). |
The second statement is as dangerous as it sounds. We're not in any way fixing the error - just ignoring it. In the above subroutine, it would have the following effect:
I would avoid On Error Resume Next - it's just asking for trouble!
As soon as an error occurs, you should really reset error handling. Thus our final code would look like this:
Sub SignTopLeftCell()
'if an error happens, jump out of the routine
On Error GoTo NoWorksheet
'now try going to worksheet (may trigger error)
Worksheets("TestSheet").Select
'reset error handling to the default - any
'error from now on is genuine!
On Error GoTo 0
'if we get here, the worksheet did exist -
'so sign it and leave
Range("A1").Value = "Wise Owl"
Exit Sub
'it doesn't matter how indented the code is,
'a label will always appear on the left edge
NoWorksheet:
'reset error handling to the default - any
'error from now on is genuine!
On Error GoTo 0
'if we get here, the worksheet didn't exist -
'display error message
MsgBox "No such worksheet!"
End Sub
I've included the statement:
'reset error handling to the default - any
'error from now on is genuine!
On Error GoTo 0
to make sure that if an error occurs which I hadn't foreseen, it doesn't display a misleading error message.
Now that we've looked at a typical basic error-handling routine, it's time to look at other options you have within error-handling segments of code.
Parts of this blog |
---|
|
Some other pages relevant to the above blogs include:
Kingsmoor House
Railway Street
GLOSSOP
SK13 2AA
Landmark Offices
99 Bishopsgate
LONDON
EC2M 3XD
Holiday Inn
25 Aytoun Street
MANCHESTER
M1 3AE
© Wise Owl Business Solutions Ltd 2023. All Rights Reserved.