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: Placing Textbox Text Into a Worksheet.
Written by Allen Wyatt (last updated June 22, 2019)
This tip applies to Excel 97, 2000, 2002, and 2003
Excel allows you to place all sorts of graphic objects on your worksheet. One type of graphic object actually contains text—a textbox. If you have quite a few textboxes in a worksheet, you may be wondering if there is a way to extract the text from each textbox and place it in the worksheet itself.
There is no command to do this; you must instead use a macro. The following macro steps through each textbox in a worksheet and makes the desired extraction:
Sub ExtractText()
Dim shp As Shape
Dim sLoc As String
For Each shp In ActiveSheet.Shapes
With shp
If Left(.Name, 8) = "Text Box" Then
sLoc = .TopLeftCell.Address
Do Until Range(sLoc) = ""
sLoc = Range(sLoc).Offset(1, 0).Address
Loop
Range(sLoc) =.TextFrame.Characters.Text
.Delete
End If
End With
Next
End Sub
Since Excel stores all graphic shapes in the Shapes collection, you can step through the collection and make a determination as to which shapes you want to work with. In this case, the first eight characters of the shape's name is checked. Only if the name begins with "Text Box" does the macro consider the shape to be a text box from which text can be extracted.
Rather than check for the "Text Box" wording in the name, the macro could also check to see what type of shape is being considered. If you prefer to do this, then simply replace the test line (If Left...) with the following test line:
If shp.Type = msoTextBox Then
The sLoc variable is used to store the location of the textbox, which is contained in the .TopLeftCell property. A Do loop is then used to make sure that the cell pointed to by the address is empty. (This prevents any existing contents of the cell from being overwritten.) If it is not empty, then the address is "incremented" to the next cell in the column.
With the address of an empty cell determined, the text of the textbox is stored in the cell. The .Delete method is then used to get rid of the actual text box.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2388) 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: Placing Textbox Text Into a Worksheet.
Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!
Add a new shape or drawing object to your worksheet, and there it sits—ram-rod straight and ready to enhance your ...
Discover MoreExcel doesn't limit you to only numbers and text in your worksheets. You can also add different types of shapes. Here's ...
Discover MoreWant to draw a few simple shapes or lines on your worksheet? It really is simple; here's how to do it.
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 © 2025 Sharon Parq Associates, Inc.
Comments