Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Finding and Replacing in Text Boxes.
Written by Allen Wyatt (last updated March 5, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
David wonders if it is possible to use Find and Replace to locate and modify text in text boxes or in labels in charts. The short answer is that it is not possible, but there are several workarounds you can try.
First, you could easily make the text in your text boxes or in your chart labels dynamic, so that it is tied to the contents of some worksheet cells. For instance, you could do the following for your text boxes:
That's it. You can use the same technique with custom chart labels—all you need to do is select the chart label and enter a cell reference in the Formula bar. With the text boxes and chart labels tied to worksheet cells, you can easily use Find and Replace to search for and change information in the cells. When the changes are made, the text boxes and chart labels should automatically reflect the changes in the cells.
The only way to actually change the text within a text box or chart label is to change it manually or change it using a macro. The code would need to step through each text box in the worksheet and then make your change. The following is a simple version of a macro that can make such a change.
Sub TextBoxReplace() Dim shp As Shape Dim sOld As String Dim sNew As String 'Change as desired sOld = "Old string" sNew = "New string" On Error Resume Next For Each shp In ActiveSheet.Shapes With shp.TextFrame.Characters .Text = Application.WorksheetFunction.Substitute( _ .Text, sOld, sNew) End With Next End Sub
This macro steps through all the shapes in the worksheet (text boxes are shapes) and then replaces whatever is in the sOld variable with whatever is in the sNew variable. Applying the same technique to chart labels is only a bit more complex, as shown in the following macro:
Sub ChartLabelReplace() Dim Cht As ChartObject Dim Ser As Series Dim scPt As Point Dim sOld As String Dim sNew As String 'Change as desired sOld = "Old String" sNew = "New String" On Error Resume Next For Each Cht In ActiveSheet.ChartObjects For Each Ser In Cht.Chart.SeriesCollection For Each scPt In Ser.Points With scPt.DataLabel .Text = Application.WorksheetFunction.Substitute( _ .Text, sOld, sNew) End With Next Next Next End Sub
The macro steps through each data label for every data series on every chart and (again) replaces any instances of whatever is in sOld with whatever is in sNew.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9262) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Finding and Replacing in Text Boxes.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Searching for information in an Excel worksheet generally goes very smoothly. There can be times, however, when the ...
Discover MoreThe find and replace used in Excel is less powerful than its counterpart in Word, so it is not able to do some of the ...
Discover MoreNeed to add some characters to the beginning of the contents in a range of cells? It's not as easy as you might hope, but ...
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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments