Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, 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: Placing Textbox Text Into a Worksheet.
Written by Allen Wyatt (last updated March 26, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
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 (11631) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Placing Textbox Text Into a Worksheet.
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!
One way to make your text boxes "stand off" the page is to add a drop shadow to them. This tip shows just how easy it is ...
Discover MoreYou probably know that text boxes can contain text. (Else why call them text boxes?) Did you know that you could make ...
Discover MoreText boxes are handy for placing information in a container that can "float" over your worksheet. This tip explains what ...
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 © 2024 Sharon Parq Associates, Inc.
Comments