Macro determines the range name of the active cell in Excel (811438)



The information in this article applies to:

  • Microsoft Office Excel 2003
  • Microsoft Excel 2002
  • Microsoft Excel 2000
  • Microsoft Excel 2001 for Mac
  • Microsoft Excel X for Mac

SUMMARY

This article provides a macro that searches through all the names in the workbook to find which name or names the active cell is currently located in. For example, if the current active cell is A5 on sheet1 and there is a defined name "Test" that refers to "sheet1!A1:C5," the macro will display a message stating:The activecell is in the range named "Test"

MORE INFORMATION

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 a Microsoft Certified Partner or the Microsoft fee-based consulting line at (800) 936-5200. For more information about Microsoft Certified Partners, see the following Microsoft Web site: For additional information about the support options available from Microsoft, visit the following Microsoft Web site:
'This macro searches through all the defined names in a workbook to find
'the name(s) that the activecell appears in. For those names it finds
'it displays a message box with the range name in it
'
Sub Find_Name_ActiveCell_In()
   Dim oCurrentName as Name            
   Dim rRng as Range
'
'Ignore any errors and may occur from some names referencing 
'external workbooks
'
    On Error Resume Next
'
'Loop through all the defined names in the workbook
'
    For Each oCurrentName In Names
'
'make sure the name is a valid cell reference
' 
       Set rRng = Range(oCurrentName.Name)
'
'check the error flag to make sure no error was generated by the
'above line
'
        If Err = 0 Then
'
'Test to see if the active cell is in the current named range
'
           If Not Intersect(ActiveCell, rRng) Is Nothing Then
'
'if it is then display the message box
'
                MsgBox "Activecell is in the range named " & _
                    oCurrentName.Name & """"
            End If
        Else
'
'reset the error flag
'
            Err = 0
        End If
    Next
End Sub

Modification Type:MajorLast Reviewed:6/7/2006
Keywords:kbhowto KB811438