Error Handler not activating

ndsutherland

Active Member
Joined
Jan 30, 2015
Messages
384
Code:
Private Sub InventoryList_LostFocus()
Dim i As Range
If ActiveSheet.Name = "Order Form" Then
    For Each i In ActiveSheet.Range("F2:F" & ActiveSheet.Range("F" & Rows.Count).End(xlUp).Row)
        On Error GoTo Other
        Cells(i.Row, 5) = Sheets("Inventory").Range("A" & WorksheetFunction.Match(i, Sheets("Inventory").Range("C:C"), 0))
        Cells(i.Row, 7) = Sheets("Inventory").Range("D" & WorksheetFunction.Match(i, Sheets("Inventory").Range("C:C"), 0))
        Cells(i.Row, 8) = Sheets("Inventory").Range("F" & WorksheetFunction.Match(i, Sheets("Inventory").Range("C:C"), 0))
        GoTo Either:
Other:
        On Error GoTo 0
        On Error GoTo ErrExit
[COLOR=#ff0000]        Cells(i.Row, 5) = Sheets("Other").Range("A" & WorksheetFunction.Match(i, Sheets("Other").Range("C:C"), 0))[/COLOR]
        Cells(i.Row, 7) = Sheets("Other").Range("D" & WorksheetFunction.Match(i, Sheets("Other").Range("C:C"), 0))
        Cells(i.Row, 8) = Sheets("Other").Range("F" & WorksheetFunction.Match(i, Sheets("Other").Range("C:C"), 0))
Either:
        Cells(i.Row, 1) = "SO-00000000"
        Cells(i.Row, 2) = "TBD"
    Next i
End If
ErrExit:
End Sub
My GoTo Other works just fine, but my code breaks (if match isn't found) on the highlighted line. What am I doing wrong?
code break setting set to "break on unhandled error" (I have tried "break in class module", not sure what that means, but it still doesn't work)
InventoryList is an ActiveX Comb Box
 
Last edited:

Norie

Well-known Member
Joined
Apr 28, 2004
Messages
75,280
Perhaps, without On Error.
Code:
Private Sub InventoryList_LostFocus()
Dim i As Range
Dim Res As Variant

    If ActiveSheet.Name = "Order Form" Then
        For Each i In ActiveSheet.Range("F2:F" & ActiveSheet.Range("F" & Rows.Count).End(xlUp).Row)

            Res = Application.Match(i, Sheets("Inventory").Range("C:C"), 0)
            If Not IsError(Res) Then
                Cells(i.Row, 5) = Sheets("Inventory").Range("A" & Res)
                Cells(i.Row, 7) = Sheets("Inventory").Range("D" & Res)
                Cells(i.Row, 8) = Sheets("Inventory").Range("F" & Res)
            Else
                Res = Application.Match(i, Sheets("Other").Range("C:C"), 0)
                If Not IsError(Res) Then
                    Cells(i.Row, 5) = Sheets("Other").Range("A" & Res)
                    Cells(i.Row, 7) = Sheets("Other").Range("D" & Res)
                    Cells(i.Row, 8) = Sheets("Other").Range("F" & Res)
                Else
                    Cells(i.Row, 1) = "SO-00000000"
                    Cells(i.Row, 2) = "TBD"
                End If
            End If

        Next i
    End If

End Sub
 

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
34,178
Office Version
365, 2019, 2016, 2010
Platform
Windows, MacOS
This might help explain it: On Error WTF? | Excel Matters

Essentially your On Error Goto 0 doesn't clear the current exception, so any further error is unhandled.
 

ndsutherland

Active Member
Joined
Jan 30, 2015
Messages
384
Excel kept crashing when I used Norie's code, so I went back to my original but changed "On Error GoTo 0" to "On Error GoTo -1" to clear the error, and it works perfectly. Norie, I did keep your Res idea to only match 2X instead of 6X. Thanks.
 

Forum statistics

Threads
1,078,253
Messages
5,339,108
Members
399,279
Latest member
danidanidaniel

Some videos you may like

This Week's Hot Topics

Top