Written by Allen Wyatt (last updated June 17, 2021)
This tip applies to Excel 2007, 2010, 2013, and 2016
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:
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.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Copying information from one program (such as Word) to another (such as Excel) is a common occurrence. If you want to ...
Discover MoreCopying from one cell to another is easy when editing your worksheet. Doing the copying without selecting a cell other ...
Discover MorePutting the contents of two cells together is easy. Putting together the contents of lots of cells is more involved, as ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2023 Sharon Parq Associates, Inc.
Comments