Written by Allen Wyatt (last updated August 27, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
Karen has a large number of cells that have a tilde character (~) at the beginning of the cells. She would like to change the tilde to a different character (such as an @ sign), but only if the tilde is at the beginning of the cell. She's not sure how to perform this task using Find and Replace.
Excel's Find and Replace would be a good choice if you wanted to replace all tildes in your text. In that case, you would simply search for ~~ (note that this is two tildes in a row) and replace with @. However, since you want to replace just a tilde appearing in the first character position, Find and Replace won't do it for you. There are two ways you can approach the problem.
The first method is to use a formula to remove the tilde. There are many variations on such a formula, with the following being one example:
=IF(LEFT(A1,1)="~","@" & MID(A1,2,LEN(A1)),A1)
You can copy the formula down as many cells as you need, then copy the results and use Paste Special to paste the values back into the original column.
The other option is to use a macro to do the replacement. The following is a good example of a short macro to do the trick:
Sub ReplaceTilde()
Dim c As Range
For Each c In Selection
If Left(c, 1) = "~" Then
c.Value = "@" & Right(c, Len(c) - 1)
End If
Next
End Sub
To use the macro, simply select the cells you want to change and then run it. Each cell in the selection is evaluated and, if appropriate, modified.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13419) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.
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!
The Find and Replace feature in Excel is one of the workhorse editing tools you can use. When the Find and Replace dialog ...
Discover MoreExcel includes a rather simplistic find and replace capability. If you have more complex needs, you'll need to seek out ...
Discover MoreFinding and replace dates contained within other text in a cell can be a bit tricky. This tip looks at some approaches to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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