ID: Q108517
In Microsoft Excel you may receive an error message when you use the Visual Basic Range(Name).Value method to get a value based on a defined name.
This error message occurs if the defined name in question refers to a constant value or a formula rather than a range.
This behavior is by design of Microsoft Excel.
To prevent the error message from appearing, use the Evaluate method to determine the value of the defined name. Please see the "More Information" section of this article for an example that demonstrates this issue.
If a particular defined name will refer to a constant value or a formula, you can use the .Evaluate(Name) method to get the value of the name. The .Evaluate(Name) method can evaluate formulas and constant values even if they don't refer to an actual range.
However, note that the .Evaluate(Name) method may return an error message if the name refers to an error value, such as #REF! or #N/A. In these cases, you may need to employ error checking (such as the On Error Resume Next function) or use an alternative method, such as the Names(Name).RefersTo method, to detect or handle an error value.
For example, if you have a sheet named Sheet1 in a workbook that contains the following global names
This
Name Refers to Cell information
---------------------------------------------------------------
Alpha =Sheet1!$B$1 Cell B1 contains the number 1
Bravo =2
Charlie =SUM(Sheet1!$B$3:$C$3) Cell B3 contains the number 3,
cell C3 contains the number 4
Delta =Alpha
Echo =Charlie
Foxtrot =Alpha+Charlie
Golf =#N/A
and you use the Range(Name).Value and .Evaluate(Name) methods to get the
values of the names you will receive the following results in your macro:
Name Range(Name).Value Sheets("Sheet1").Evaluate(Name)
--------------------------------------------------------------
Alpha 1 1
Bravo [Error message 1] 2
Charlie [Error message 1] 7
Delta 1 1
Echo [Error message 1] 7
Foxtrot [Error message 1] 8
Golf [Error message 1] [Error message 2]
The error messages 1 and 2 are as follows.
Run-time error '1004':
Range method of Application class failed
Run-time error '13':
Type mismatch
Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/refguide/
To check the value of a name, you can use the following subroutine:
'----------------------------------------------------------------------
Option Explicit
Sub CheckNameValue()
Dim Test As Variant
Test = Range("Alpha").Value
'To check the value by using .Evaluate(Name), use
'
' Test = Sheets("Sheet1").Evaluate("Alpha")
'
'in place of the previous test line.
MsgBox Test
End Sub
'----------------------------------------------------------------------
In order to prevent an error when the name refers to an error value (in
this case, if the name is Golf), use the Names(Name).RefersTo method to
check the name before getting its value. For example, you could use:
Sub CheckForError()
'If the name Golf refers to an error value, such as #REF! or #N/A,
If IsError(Evaluate(Names("Golf").RefersTo)) Then
'then show an error message to that effect,
MsgBox "Golf is an error name!"
Else
'otherwise state that the name refers to a good reference.
MsgBox "Golf is OK!"
End If
End Sub
If the name refers to an error value, the IsError test will be true and the
error message box will be displayed. Otherwise, the OK message box will be
displayed. For example, if the name is Golf, which refers to =#N/A, the
error message box will be displayed. Using any of the other example names
will result in the OK message box.
For more information about the Evaluate Method, from the Visual Basic Editor, click the Office Assistant, type "evaluate," click Search, and then click to view "Evaluate Method."
NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If the Assistant is not able to answer your query, please see the following article in the Microsoft Knowledge Base:
ARTICLE-ID: Q176476
TITLE : OFF: Office Assistant Not Answering Visual Basic Questions
For additional information about getting help with Visual Basic for
Applications, please see the following article in the Microsoft Knowledge
Base:
ARTICLE-ID: Q163435
TITLE : VBA: Programming Resources for Visual Basic for
Applications
Additional query words: 5.00 7.00
Keywords : kbprg kbdta kbdtacode PgmOthr KbVBA
Version : WINDOWS:5.0,5.0c,7.0,97; MACINTOSH:5.0
Platform : MACINTOSH WINDOWS
Issue type : kbprb
Last Reviewed: May 17, 1999