Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Getting Rid of Everything Except Numbers.

Getting Rid of Everything Except Numbers

by Allen Wyatt
(last updated May 13, 2017)

3

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 a formula to remove the alpha characters. If the values you want to change are in column A, you could enter the following formula in column B:

=SUM(MID(0&A1,LARGE(INDEX(ISNUMBER(--MID(A1,
ROW($1:$99),1))*ROW($1:$99),),ROW($1:$99))+1,
1)*10^ROW($1:$99)/10)

Make sure you enter this as an array formula by pressing Ctrl+Shift+Enter. The result is that column B contains the values from column A, without the alpha characters. You could use Paste Special to copy the information from column B 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.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11750) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Getting Rid of Everything Except Numbers.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Printing a Draft Watermark

Adding a watermark to the background of a printout can be challenging. This tip explains the different ways you can ...

Discover More

Conditional Format that Checks for Data Type

Conditional formatting can be used to highlight cells that contain the improper type of data for your needs. This tip ...

Discover More

Quickly Customizing the Keyboard

Want a quick way to change the shortcut key associated with a tool available on a ribbon, toolbar, or menu? Here's one ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

More ExcelTips (ribbon)

Easily Adding Blank Rows

Want to add a bunch of blank rows to your data and have those rows interspersed among your existing rows? Here's a quick ...

Discover More

Undoing Actions in Only the Active Workbook

When you undo actions within Excel, those steps you undo may affect the multiple workbooks in which you've been working. ...

Discover More

Combining Multiple Rows in a Column

Do you need to concatenate the contents of a range of cells in the same column? Here's a formula and a handy macro to ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two less than 5?

2020-08-25 20:38:46

Roy

Using SPILL functionality, one could use the following approach:

=VALUE(TEXTJOIN("",TRUE,
IF( UNICODE( MID(A1,SEQUENCE(1,LEN(A1)),1))<48, "",
IF( UNICODE( MID(A1,SEQUENCE(1,LEN(A1)),1))>57, "",
MID( A1, SEQUENCE(1, LEN(A1)), 1) ))))

The last line shows the MID() function's expression in each line (same all lines). Used IF() and the two tests because AND() seems to curtail the SPILL aspect which is critical so... TEXTJOIN() drops all the "" results (from non-numbers) and puts the remaining pieces back together, then VALUE() changes them back to a number.

It can be easily modified to take some extra characters such as "=*^/" and so on, or indeed, any characters you wish.

The same approach can be the basis of removing any characters not part of an acceptable series. For instance, anything above U+0255 which one might use to remove non-printing characters and other garbage web pages and data dumps lard one's data with. Kind of a "negative space" approach then, but the same idea: tear it apart, compare it, keep it or lose it.

Works too if one uses a lookup function and a table of outputs. A simple one might be the first 2-3,000 Unicode characters (numerically) in a column and their return result to the lookup in a second column, and as one finds ones one does NOT want in one's output, their return values to the lookup could be changed to "", or even some other character if one is preferred. (The latter can replace accented characters with the non-accented character, for example.)

Doing it without SEQUENCE() is no trick as that technique is very old. Doing it without SPILL functionality is less pleasant looking as it involves CSE arrays. So here's hoping everyone has SPILL functioanlity by now!

Well heck... had an idea about AND() and it turns out AND() works nicely inside TEXTJOIN() (just not within IF() as the "outside" wrapper. So:

=VALUE(TEXTJOIN("",TRUE,
IF( AND(
UNICODE(MID(C1,SEQUENCE(1,LEN(C1)),1))>47,
UNICODE(MID(C1,SEQUENCE(1,LEN(C1)),1))<58),
MID(C1,SEQUENCE(1,LEN(C1)),1), "" )))

works. There are certain advantages to each of the two ways to approach that testing, and that's a general AND() approach vs. IF() approach thing, but they aren't frequent. Just something to remember, that one can sometimes do a thing neatly with one, but not the other. Not like "Not all pretty and such" but like "not at all."

So, something else to see (it's the "But wait, there's more!" of this comment, I guess): even if an approach won't work along the way due to a function killing the SPILL functionality, that's apparently not the final word as yet another function wrapping the killer might give SPILL functionality back to the whole formula and the approach that seemed a failure might work after all once all the pieces are in place. Folks often work inside to out, so to speak, and drop an approach if it fails figuring the failure would just reflect outward. (I did just now, till I had that thought).) But apparently, it is not the case here.


2019-09-17 11:47:31

Willy Vanhaelen

This user defined function is even shorter:

Function StripChar(aText As String) As Long
Dim I As Integer, aChar As String
For I = 1 To Len(aText)
aChar = Mid(aText, I, 1)
If IsNumeric(aChar) Then StripChar = StripChar & aChar
Next
End Function

It returns a numeric value.
Remove 'As Long' if you prefer a text string.


2017-05-13 06:13:38

Michael (Micky) Avidan

@To whom it may concern,
Although I met, during my Excel Career, longer formulas than the suggested above - here is a nice gimmick using the function: NPV (Net Present Value of an investment).
It is an Array Formula (Entered using <Ctrl+Shift+Enter>)

=NPV(-0.9,0,IFERROR(MID(A1,LEN(A1)-ROW(INDIRECT("A1:A"&LEN(A1)))+1,1)/100,""))

--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” Excel MVP – Excel (2009-2017)
ISRAEL


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.