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.

  1. Handling Errors in Visual Basic for Applications (this blog)
  2. Customising Error-Handling Code
  3. A Worked Example - Error-Handling with InputBox
  4. Advanced Error Traps - Raising Errors and Error Bubbling

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.

Posted by Andy Brown on 29 November 2011

You need a minimum screen resolution of about 700 pixels width to see our blogs. This is because they contain diagrams and tables which would not be viewable easily on a mobile phone or small laptop. Please use a larger tablet, notebook or desktop computer, or change your screen resolution settings.

Handling Errors in Visual Basic for Applications

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.

Creating Labels

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).

Using ON ERROR to Create an Error Trap

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:

Error message for no 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:

  • The routine would fail to go to the TestSheet worksheet, but not display any error message; and then
  • The code would sign cell A1 in whatever the current worksheet happened to be.

I would avoid On Error Resume Next - it's just asking for trouble!

Resetting Error Handling to the Default

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.

 

This blog has 0 threads Add post