Written by Allen Wyatt (last updated August 19, 2024)
This tip applies to Excel 2007, 2010, 2013, and 2016
Dorothy's students are customizing a checkbook simulation workbook, replacing the default name with their own. For example, she wants them to search for "Jason Anderson" and replace the name with "Sue Smith." There are 22 occurrences of "Jason Anderson" in text boxes throughout eight worksheet tabs, and several more on the worksheets themselves. Dorothy wonders how she can Find and Replace all worksheet occurrences and all comment occurrences at once.
There is no way to do this without using a macro. The macro would need to look through each cell in the workbook, each comment, and each text box to see if changes needed to be made. The following is an example of how this can be done:
Sub ReplaceNames()
Dim sDefaultName As String
Dim sNewName As String
Dim sht As Worksheet
Dim cmt As Comment
Dim wks As Worksheet
Dim sCmt As String
Dim shp As Shape
sDefaultName = "Jason Anderson"
sNewName = InputBox("Enter your first and last name.", _
"Name Replacement")
' Replace cell text
For Each sht In ActiveWorkbook.Worksheets
sht.Cells.Replace what:=sDefaultName, _
Replacement:=sNewName, LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, _
SearchFormat:=False, ReplaceFormat:=False
Next sht
' Replace comment text
For Each wks In ActiveWorkbook.Worksheets
For Each cmt In wks.Comments
sCmt = cmt.Text
If InStr(sCmt, sDefaultName) <> 0 Then
sCmt = Application.WorksheetFunction. _
Substitute(sCmt, sDefaultName, sNewName)
cmt.Text Text:=sCmt
End If
Next cmt
Next wks
Set wks = Nothing
Set cmt = Nothing
' Replace text box text
On Error Resume Next
For Each wks In ActiveSheet.Parent.Worksheets
For Each shp In wks.Shapes
With shp.TextFrame.Characters
.Text = Application.WorksheetFunction.Substitute( _
.Text, sDefaultName, sNewName)
End With
Next shp
Next wks
End Sub
The macro prompts the user to enter a new name and then searches cells, comments, and text boxes to see if there are any occurrences of the default name ("Jason Anderson"). If so, then the appropriate replacement is made.
If you don't want to use macros to do the searching, perhaps a restructuring of the workbook would be helpful. For instance, you could create a "data input worksheet" in which common information—such as the person's name—is entered. In the other worksheets, the name from the data input worksheet is referenced using formulas. Thus, one change in the data input worksheet, and the name is changed in all the other worksheets.
Using this approach can work with comments, as well. You can select the comment or shape and, in the Formula bar, enter a reference formula such as this:
=MyName
This assumes that the user's name, on the data input worksheet, has been associated with the MyName named range. If there needs to be additional information in the comment or shape, then you could construct that text in a cell on the data input worksheet and then assign the contents of that cell to the comment or shape, just as noted for the MyName named range.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2614) applies to Microsoft Excel 2007, 2010, 2013, and 2016.
Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!
When you search for information in a worksheet, you expect Excel to return results that make sense. If you don't get a ...
Discover MoreFinding and replacing information in a worksheet is easy. Finding and replacing in other objects (such as text boxes or ...
Discover MoreThe Find and Replace capabilities of Excel allow you to easily locate all the cells in a worksheet that contain specific ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-12-29 11:18:13
Chris
I agree, Kevin. Just tried on Excel 365; the text box reference worked, and when I selected the text box then clicked in the formula bar it showed the name of the text box. With a comment, all attempts to enter the formula suggested ended up either with the result of the formula being in the commented cell, or the formula being shown as text in the comment.
2016-05-28 08:03:12
Kevin
"You can select the comment or shape and, in the Formula bar, enter a reference formula such as this:
=MyName"
I don't think this is possible. Formulas cannot be entered in a comment.
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