find all named ranges that contain the selected cell?

context

New Member
Joined
Jan 10, 2018
Messages
3
How do I find out if a cell I have selected is included(or not) in one of the numerous named ranges in my workbook?
It would be nice to do this outside of coding.
Ideally I would like to select a cell and have a list of named ranges that include that cell.
Why.. because I have inherited a huge spreadsheet with multiple authors and must rationalize it. Huge is > a million cells, 80 sheets.
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Thanks stunnrock-- I mean the cell reference. I want to know if I restructure the sheet containing the cell what impact it will have. Also the naming of the ranges helps in the comprehension of the overall excel model. There are about 200 named ranges. I may just resort to some code.
 
Upvote 0
Try:

Code:
Sub FindNameRefs()

Dim rng As Range
Dim wb As Workbook
Dim NR As Name
Dim msg As String
Set wb = ActiveWorkbook
For Each NR In wb.Names
    If Not Intersect(Selection(1, 1), Range(NR.RefersTo)) Is Nothing Then
        'Debug.Print NR.Name
        msg = msg & vbCrLf & NR.Name
    End If
Next
If Len(msg) > 0 Then
    MsgBox "Current cell is referenced in: " & vbCrLf & msg
Else
    MsgBox "No named ranges refer to current cell."
End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,894
Messages
6,175,254
Members
452,623
Latest member
Techenthusiast

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