Identifying Digit-Only Part Numbers Excluding Special Characters

Chris has a large number of cells that contain part numbers. These cells can contain either digits or characters, in any combination. They can also contain special characters such as dashes, slashes, and spaces. Chris needs a way to identify if a cell contains only digits, without taking the special characters into account. Thus, a cell containing 123-45 would show as containing only digits, while 123AB-45 would not.

The easiest way to figure out if a given cell contains only the allowable characters and digits is to use a formula that removes the non-digit permissible characters and then sees if the resulting value is numeric. All of the following formulas can do the trick quite nicely:

=IF(IFERROR(INT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(A1,"-", ""),"/", "")," ", "")),FALSE), TRUE, FALSE)
=OR(ISNUMBER(SUBSTITUTE(A1,"-","")+0),ISNUMBER(SUBSTITUTE(A1,"/","")+0),ISNUMBER(SUBSTITUTE(A1," ","")+0))
=ISNUMBER(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(A1," ",""),"/",""),"-","")*1)

You could also use a simple macro to figure out if a cell contains only digits and your allowed characters. While there are any number of ways that such a macro could be approached, here’s a rather easy method:

Function DigitsOnly(sRaw As String) As Boolean
    Dim X As Integer
    Const sAllowed As String = "0123456789 -/"

    Application.Volatile
    For X = 1 To Len(sRaw)
       If InStr(sAllowed, Mid(sRaw, X, 1)) = 0 Then Exit For
    Next X
    DigitsOnly = False
    If X > Len(sRaw) Then DigitsOnly = True
End Function

The macro examines whatever is passed to it, comparing each character in the string to a list of allowed characters (in the constant sAllowed). If an disallowed character is detected, the loop is exited early and a False value is returned. Thus, if you wanted to evaluate the cell at A1, you could use the following in your macro:

=DigitsOnly(A1)

Since they return either True or False values, any of these approaches (formula or user-defined function) could be used in conjunction with conditional formatting to make formatting changes to your part numbers.