Please critique this UDF to return the name of a range

JenniferMurphy

Well-known Member
Joined
Jul 23, 2011
Messages
2,691
Office Version
  1. 365
Platform
  1. Windows
I just updated my little UDF that returns the assigned name of a range. I added an optional second parameter to return the name of the entire row or column of the target cell.

I would appreciate any comments or suggestions.

Code:
Function GetRangeName(pRange As Range, Optional pRowCol As String = "") As String
Application.Volatile    'Needed so it will update with any changes
Dim pieces() As String  'Array to hold the pieces of the range after splitting
Dim addr As String      'Physical address
On Error Resume Next    'Ignore errors
GetRangeName = ""                           'Return null if no name is assigned to the range
Select Case UCase(pRowCol)
  Case "ROW"                                'If they want the entire row,
    GetRangeName = Rows(pRange.Row).Name.Name     'Get that name
    addr = pRange.Row & ":" & pRange.Row          'Generate physcial address
  Case "COLUMN"                             'If they want the entire column,
    GetRangeName = Columns(pRange.Column).Name.Name  'Get that name
    addr = CvtColNum2Ltr(pRange.Column)
    addr = addr & ":" & addr       'Generate physcial address
  Case Else                                 'Otherwise
    GetRangeName = pRange.Name.Name           'Get the name of the range
    addr = pRange.Address
End Select

If GetRangeName = "" Then                   'If range is not named.,
    GetRangeName = "*** None ***"             'Return "None"
    Exit Function
End If

pieces = Split(GetRangeName, "!")       'Split off the sheet name
If UBound(pieces) = 1 Then GetRangeName = pieces(1) Else GetRangeName = pieces(0)
GetRangeName = GetRangeName & "(" & addr & ")"
      
End Function

Thanks
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
CvtColNum2Ltr is missing, so I'll take it on faith that it works. Regardless, your code to determine the address is more complicated than necessary.

Rich (BB code):
Select Case UCase(pRowCol)
  Case "ROW"                                'If they want the entire row,
    GetRangeName = Rows(pRange.Row).Name.Name     'Get that name
    addr = pRange.EntireRow.Address          'Generate physcial address
  Case "COLUMN"                             'If they want the entire column,
    GetRangeName = Columns(pRange.Column).Name.Name  'Get that name
    addr = pRange.EntireColumn.Address 'Generate physcial address
  Case Else                                 'Otherwise
    GetRangeName = pRange.Name.Name           'Get the name of the range
    addr = pRange.Address
End Select

Volatile could cause you some performance problems. Use sparingly.
 
Upvote 0
Solution
CvtColNum2Ltr is missing, so I'll take it on faith that it works.

Yes, I forgot to include that routine.

Regardless, your code to determine the address is more complicated than necessary.

Rich (BB code):
Select Case UCase(pRowCol)
  Case "ROW"                                'If they want the entire row,
    GetRangeName = Rows(pRange.Row).Name.Name     'Get that name
    addr = pRange.EntireRow.Address          'Generate physcial address
  Case "COLUMN"                             'If they want the entire column,
    GetRangeName = Columns(pRange.Column).Name.Name  'Get that name
    addr = pRange.EntireColumn.Address 'Generate physcial address
  Case Else                                 'Otherwise
    GetRangeName = pRange.Name.Name           'Get the name of the range
    addr = pRange.Address
End Select

Excellent. That works great! Thanks. And now I don't need to convert column number to letters.

Volatile could cause you some performance problems. Use sparingly.

I think I included it because someone said it was needed in order for it to automatically update if I were to rename a range. I've commented it out. I'll see how that goes.
 
Upvote 0
"Someone" is correct; I believe you do need it. I was just offering general guidance.

A function is recalculated when any of its precedents are recalculated. For example, SUM(A1, B2) is recalculated if A1 changes or is recalculated. Your function has the argument pRange so will recalculate anytime something in that range is recalculated. However, if range names change, pRange won't necessarily recalculate, and your function will not recalculate. Using Volatile in your function will force the function to recalculate anytime anything in the workbook is recalculated. This will make sure that the result of your function is always up to date. However, sometimes people do this and then use the function thousands of times in their worksheet, which forces it to be recalculated whether it needs it or not.

If you just this function a few times, you won't notice it. If you use it a couple of thousand times, it may slow down calculation.
 
Upvote 0
"Someone" is correct; I believe you do need it. I was just offering general guidance.

A function is recalculated when any of its precedents are recalculated. For example, SUM(A1, B2) is recalculated if A1 changes or is recalculated. Your function has the argument pRange so will recalculate anytime something in that range is recalculated. However, if range names change, pRange won't necessarily recalculate, and your function will not recalculate. Using Volatile in your function will force the function to recalculate anytime anything in the workbook is recalculated. This will make sure that the result of your function is always up to date. However, sometimes people do this and then use the function thousands of times in their worksheet, which forces it to be recalculated whether it needs it or not.

If you just this function a few times, you won't notice it. If you use it a couple of thousand times, it may slow down calculation.

Very helpful, thanks.
 
Upvote 0

Forum statistics

Threads
1,224,595
Messages
6,179,798
Members
452,943
Latest member
Newbie4296

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