Getting Rid of Everything Except Numbers

Linda has a column that contains alpha and numeric characters. She needs to retain the numeric characters and delete the alpha ones. For example, a cell may contain 10003E111 and she wants to end up with 10003111.

There are a few ways you can approach this problem. Before proceeding with any solution, however, you should make sure that you aren’t trying to change something that isn’t really broken. For instance, you’ll want to make sure that the “E” that appears in the number isn’t part of the format of the number-in other words, a designation of exponentiation. If it is, then you don’t really want to remove the character because it will end up changing the nature of the underlying number.

If you determine that the characters aren’t part of the number’s format, then you can first try using formulas to remove the alpha characters. If the values you want to change are in column A, you could enter the following (very long) formula in column B:

=MID(A1,MATCH(TRUE,ISERROR(1*MID(A1,ROW(INDIRECT
("1:"&LEN(A1))),1)),0),-MATCH(TRUE,ISERROR(1*MID
(A1,ABS(ROW(INDIRECT("1:"&LEN(A1)))-LEN(A1)-1),1))
,0)+LEN(A1)+2-MATCH(TRUE,ISERROR(1*MID(A1,ROW
(INDIRECT("1:"&LEN(A1))),1)),0))

Make sure you enter this as an array formula by pressing Ctrl+Shift+Enter. Then enter the following into column C:

=SUBSTITUTE(A1,B1,"")

The result is that column C contains the values from column A, without the alpha characters. You could use Paste Special to copy the information from column C to another column so that you end up with actual values instead of formula results.

This approach may work great for short-term use on a single workbook, but if you need to do this sort of data processing more often then you will want to create a user-defined function to do the processing. Here’s an example:

Function OnlyNums(sWord As String)
    Dim sChar As String
    Dim x As Integer
    Dim sTemp As String

    sTemp = ""
    For x = 1 To Len(sWord)
        sChar = Mid(sWord, x, 1)
        If Asc(sChar) >= 48 And _
          Asc(sChar) <= 57 Then
            sTemp = sTemp & sChar
        End If
    Next
    OnlyNums = Val(sTemp)
End Function

You use this function by calling it from within a worksheet cell:

=OnlyNums(A1)

The function returns a numeric value. If you want to create an even shorter macro to do the processing, consider the following:

Function StripChar(aText As String)
    Dim I As Integer

    StripChar = ""
    For I = 1 To Len(aText)
        aChar = Mid(aText, I, 1)
        Select Case aChar
            Case "0" To "9"
                StripChar = StripChar & aChar
        End Select
    Next
End Function

To use this function, use either of the following in your worksheet:

=STRIPCHAR(A1)
=VALUE(STRIPCHAR(A1))

The first returns a text string consisting of the digits, the second returns the numeric version of that string.