If a particular defined name refers 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 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]
NOTE: Error messages 1 and 2 are as follows:
Error Message 1
Run-time error '1004':
Method 'Range' of object '_Global' failed
Error Message 2
Run-time error '13':
Type mismatch
Sample Visual Basic Procedure
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers 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 requirements.
Check the Value of a Name
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
End Sub
To check the value by using .
Evaluate(
Name), use
Test = Sheets("Sheet1").Evaluate("Alpha")
in place of the previous test line.
MsgBox Test
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 is true and the error message box is displayed. Otherwise, the
OK message box is
displayed. For example, if the name is Golf, which refers to =#N/A, the
error message box is displayed. Using any of the other example names
results in the
OK message box.