Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and 2021. 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 Alphabetic Characters.
Written by Allen Wyatt (last updated January 14, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
Bryan has a worksheet that has a lot of cells that have some alphabetic characters in them. He is looking for a way to get rid of only those alphabetic characters, no matter where they appear in the cell. For instance, if the cell contains "ABC123," Bryan wants to get rid of "ABC" and have just "123" remaining. Similarly, "A3B2C1" should become "321" and "#45P*%" should become "#45*%".
The only way to approach this problem is through the use of macros. If you want to simply strip out the characters, in place, then you can do so by selecting the cells you want to affect and then running a macro that examines each cell and deletes the offending characters. There are many ways you could do this; the following macro is a straightforward approach.
Sub CleanText1()
Dim rngCell As Range
Dim intChar As Integer
Dim strCheckString As String
Dim strCheckChar As String
Dim intCheckChar As Integer
Dim strClean As String
For Each rngCell In Selection
strCheckString = rngCell.Value
strClean = ""
For intChar = 1 To Len(strCheckString)
strCheckChar = Mid(strCheckString, intChar, 1)
intCheckChar = Asc(strCheckChar)
Select Case intCheckChar
Case 65 To 90 'upper case chars
'Do nothing
Case 97 To 122 'lower case chars
'Do nothing
Case 128 To 151 'special language chars
'Do nothing
Case 153 To 154 'special language chars
'Do nothing
Case 159 To 165 'special language chars
'Do nothing
Case Else
strClean = strClean & strCheckChar
End Select
Next intChar
rngCell.Value = strClean
Next rngCell
End Sub
The nice thing about this approach to stripping out the characters is that you can easily get rid of other characters by simply modifying what is checked (and what actions are taken) in the Select Case structure.
If you don't want to modify the original cells, a good approach is to put together a user-defined function that will return a "clean" version of a string. This can be achieved by making a few modifications to the previous macro.
Function CleanText2(ByVal sRaw As String) As String
Dim intChar As Integer
Dim strCheckString As String
Dim strCheckChar As String
Dim intCheckChar As Integer
Dim strClean As String
Application.Volatile
strClean = ""
For intChar = 1 To Len(sRaw)
strCheckChar = Mid(sRaw, intChar, 1)
intCheckChar = Asc(strCheckChar)
Select Case intCheckChar
Case 65 To 90 'upper case chars
'Do nothing
Case 97 To 122 'lower case chars
'Do nothing
Case 128 To 151 'special language chars
'Do nothing
Case 153 To 154 'special language chars
'Do nothing
Case 159 To 165 'special language chars
'Do nothing
Case Else
strClean = strClean & strCheckChar
End Select
Next intChar
CleanText2 = strClean
End Function
In order to use the function, you could put a formula such as the following in a cell:
=CleanText2(A1)
The result is that the formula returns a "clean" version of whatever is in cell A1 without disturbing the contents of cell A1.
Another approach is to define, in your macro, what characters are allowed to remain in your text. In this way you could simplify the macro quite a bit. This version is done as a user-defined function, as well:
Function CleanText3(ByVal sRaw As String) As String
Dim J As Integer
Dim sTemp As String
Dim sClean As String
Const OK = "0123456789#$%&'+-*/"
Application.Volatile
sClean = ""
For J = 1 To Len(sRaw)
sTemp = Mid(sRaw, J, 1)
If InStr(OK, sTemp) Then sClean = sClean & sTemp
Next J
CleanText3 = sClean
End Function
The trick in this approach is to make sure you give thought to what characters you want to allow in the processed string. Those characters should all be included in the OK constant.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9011) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Getting Rid of Alphabetic Characters.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!
When you need to stop a macro while it is running, you normally press Ctrl+Break. What are you to do if the keypress ...
Discover MoreWhen working with very large workbooks, it is possible for Excel to behave erratically. This tip looks at ways you can ...
Discover MoreSometimes a macro command line can get very, very long. This can make it hard to understand when you look at it a month ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-05-09 12:15:22
Willy Vanhaelen
The CleanText1 macro in this tip is a textbook example of what you can do with Select Case. The macro works fine except that the list of special foreign characters to remove is very incomplete. For example “é, °, §, µ, ç” (e accent égu, degree, paragraph, mu, c cedille) all characters right available on my Azerty keyboard are not removed.
Instead of listing the characters to remove which results in a very long list, the approach in the CleanText3 user defined function (UDF) is more logical and results in a far smaller macro. Here is its macro version:
Sub CleanText3()
Const OK = "0123456789#$%""&'+-*/"
Dim Cell As Range, Char As String
Dim Cleaned As String, X As Integer
For Each Cell In Selection
For X = 1 To Len(Cell)
Char = Mid(Cell, X, 1)
If InStr(OK, Char) Then Cleaned = Cleaned & Char
Next X
Cell = Cleaned
Cleaned = ""
Next Cell
End Sub
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 © 2025 Sharon Parq Associates, Inc.
Comments