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.

Placing Textbox Text Into a Worksheet

by Allen Wyatt
(last updated April 21, 2012)

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.

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Exiting a For ... Next Loop Early

If you use For ... Next loops in your macros, make sure you give a way to jump out of the loop early. That way you can limit ...

Discover More

Inserting a Page Number Field

The PAGE field is used to indicate the current page number on which the field occurs. If you want to add this field to your ...

Discover More

Generating Random Testing Data

Need to test your formulas? Then you need some testing data that you can use to see if the formulas function as you expect. ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

MORE EXCELTIPS (MENU)

Grouping and Ungrouping Objects

When you add multiple graphic objects in a worksheet, it can often be beneficial to group those objects together. Here's how ...

Discover More

Inserting Video into Worksheets

You can add all sorts of objects to your workbooks, including video clips. Here's the pros and cons (along with the how-to) ...

Discover More

Using Chart Titles

Titles can be a great addition to any chart. They help provide explanatory information about the information in the chart. ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)

This Site

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.

Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.

Links and Sharing
Share