Check if string is single cell reference

andydtaylor

Active Member
Joined
Feb 15, 2007
Messages
355
Office Version
  1. 2010
Hi,

I'd like to check if a user supplied string is single cell reference. My problem is that the below code comes back as vallid if I enter a range like B2:B4.

Can anyone suggest how I could fix this?

Thanks,

Andrew



Code:
Sub test2()

Dim UserAdd As String
UserAdd = InputBox("Enter your address")
 
 'check if valid:
If ValidAddress(UserAdd) Then
     MsgBox ("it's valid!")
Else
     MsgBox ("it ain't valid!")
End If

End Sub


Function ValidAddress(strAddress As String) As Boolean
    Dim r As Range
    On Error Resume Next
    Set r = Worksheets(1).Range(strAddress)
    If Not r Is Nothing Then ValidAddress = True
End Function
 

Some videos you may like

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
36,079
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2010
Platform
  1. Windows
  2. MacOS
Try this:
Code:
Function ValidAddress(strAddress As String) As Boolean
    Dim r As Range
    On Error Resume Next
    Set r = Worksheets(1).Range(strAddress)
    If Not r Is Nothing Then ValidAddress = (r.Cells.Count = 1)
End Function
 

andydtaylor

Active Member
Joined
Feb 15, 2007
Messages
355
Office Version
  1. 2010
Hi Rory,

I've just found a scenario where this doesn't work unfortunately. It seems to let me enter fff5/ggg6... it correctly errors on 555555555 or ggggggggg or 67yyy however.

Is there another way to catch this you can suggest?

Thanks,


Andrew
 

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,910

ADVERTISEMENT

How about
Code:
Function IsSingleCellAddress(inputString As String) As Boolean
On Error Resume Next
    IsSingleStringAddress = (Range(inputString).Cells(1, 1).Address = Range(inputString).Address)
On Error GoTo 0
End Function
 

andydtaylor

Active Member
Joined
Feb 15, 2007
Messages
355
Office Version
  1. 2010
Hi Mike,

Thanks for that.

Unfortunately using the below in a fresh workbook, it comes up as invalid even if I enter A1 for example. Is there something I can change?

Thanks,


Andrew

Code:
Sub test2()

Dim UserAdd As String
UserAdd = InputBox("Enter your address")
 
 'check if valid:
If IsSingleCellAddress(UserAdd) Then
     MsgBox ("it's valid!")
Else
     MsgBox ("it ain't valid!")
End If

End Sub

Function IsSingleCellAddress(inputString As String) As Boolean
On Error Resume Next
    IsSingleStringAddress = (Range(inputString).Cells(1, 1).Address = Range(inputString).Address)
On Error GoTo 0
End Function
 

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,910

ADVERTISEMENT

My mistake, when I changed the name in the declaration the function, I should have also changed the name of in the body of the function.
Code:
Function IsSingleCellAddress(inputString As String) As Boolean
On Error Resume Next
    IsSingleCellAddress = (Range(inputString).Cells(1, 1).Address = Range(inputString).Address)
On Error GoTo 0
End Function
 

Jonmo1

MrExcel MVP
Joined
Oct 12, 2006
Messages
44,061
How about eliminating the need to test if it's a valid address in the first place...

Rich (BB code):
Sub test2()
Dim UserAdd As Range
 
'This ensures a valid address is selected AND
'The user is able to either SELECT OR TYPE The range
Set UserAdd = Application.InputBox(Prompt:="Enter your address", Type:=8)
 
'This will test if it's a single or multi cell address
If UserAdd.count = 1 Then
    MsgBox "Valid Single Cell Address"
Else
    MsgBox "Valid Multi Cell Address"
End If
End Sub

Hope this helps..
 

Watch MrExcel Video

Forum statistics

Threads
1,122,655
Messages
5,597,384
Members
414,141
Latest member
Joey_T92

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
Top