Displaying the address of the cell in error

JenniferMurphy

Well-known Member
Joined
Jul 23, 2011
Messages
2,482
Office Version
  1. 365
Platform
  1. Windows
I am working on a UDF that processes a large table of data. A small example might look something like this.

R/CWXYZAAABACAD
24$1004.5AYB333/222502005
25$2505.8CNX214/151352011
26$751.5FNR033/291995
27$1106.0DYG444/204002015

<tbody>
</tbody>
The UDF is passed the table range
Code:
=DoIt(W24:AD27)
The UDF loops through the rows and columns until it completed the work or encounters an error.

Code:
Public Function DoIt(Table as range)

Dim iCol as Integer, iRow as Integer
For iRow = 1 to RowN
  For iCol = 1 to ColN

     . . . code processing table cells

  Next iCol
Next iRow

End Function
In the table above, there is a missing value in AC26. The error occurs when iRow=3 and iCol=7. But these are relative to the first cell in the table. I would like to be able to calculate the actual cell address (AC26 or $AC$26) and show that in a MsgBox.

Can someone help me with the code I need to do that?

Thanks
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
You could add a error handler to the UDF
Code:
Public Function DoIt(Table As Range)
    Dim iCol As Integer, iRow As Integer
    Dim RowN As Long, ColN As Long

    [COLOR="#FF0000"]On Error GoTo ErrorHaNdler[/COLOR]

    For iRow = 1 To RowN
      For iCol = 1 To ColN

         ' . . . code processing table cells
    
      Next iCol
    Next iRow
Exit Function

ErrorHaNdler:
    Dim errString As String

    errString = Err & vbCr & Error
    errString = errString & vbCr & "in " & Cells(iRow, iCol).Address
    errString = errString & vbCr & "Continue or Cancel"
    
    Select Case MsgBox(errString, vbAbortRetryIgnore + vbDefaultButton3)
        Case vbAbort
            Exit Function
        Case vbRetry
            Resume
        Case vbIgnore
            Resume Next
    End Select
End Function
I noticed that RowN and ColN weren't declared.
 
Last edited:
Upvote 0
You could add a error handler to the UDF
I don't need a runtime error handler because the errors are invalid data.

I couldn't quite follow most of that code, but I was able to extract the key expression. This code now does what I need it to do.
Code:
Public Function DoIt(Table As Range)
Dim iCol As Integer, iRow As Integer
Dim RowN As Long, ColN As Long
Dim ErrAddr as string

For iRow = 1 To RowN
  For iCol = 1 To ColN

      . . .

    If (some test) then
      ErrAddr = Table(iRow, iCol).Address
      Msgbox "Error XYZ in cell " & ErrAddr
      DoIt = CVErr(xlErrValue)
      Exit Function
    End If

       . . .

    Next iCol
Next iRow

End Function
Thank you very much for that.

I noticed that RowN and ColN weren't declared.
Really? Line 3 doesn't qualify? :confused:
 
Upvote 0

Forum statistics

Threads
1,213,489
Messages
6,113,952
Members
448,535
Latest member
alrossman

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