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: Resizing a Text Box in a Macro.
Written by Allen Wyatt (last updated July 13, 2024)
This tip applies to Excel 97, 2000, 2002, and 2003
Rob has a text box, in a worksheet, that contains text copied from Word. He wants to know how he can resize the text box using a macro, so that it covers a specific range of cells.
There are a couple of ways you can approach this task. One is to specify, in the macro, exactly which cells you want to cover with the text box, and then adjust the properties of the text box to match the characteristics of the cells you specify.
Sub ResizeBox1()
Dim sTL As String
Dim sBR As String
Dim rng As Range
' Change top-left and bottom-right addresses as desired
sTL = "A1"
sBR = "M40"
' Ensure a text box is selected
If TypeName(Selection) <> "TextBox" Then
MsgBox "Text box not selected"
Exit Sub
End If
With Selection
Set rng = ActiveSheet.Range(sTL)
.Top = rng.Top
.Left = rng.Left
Set rng = ActiveSheet.Range(sBR)
.Width = rng.Left + rng.Width
.Height = rng.Top + rng.Height
End With
Set rng = Nothing
End Sub
In order to use the macro, change the address of the cells you want to use for the top-left and bottom-right of the text box. Then, select the text box and run the macro.
If you prefer, you could use a named range to specify the range to be covered by the text box. The following macro expects that the range will be named RangeToCover. When you select the text box and run the macro, the text box is resized to match the size of the range.
Sub ResizeBox2()
Dim l_rRangeToCover As Range
Dim l_rLowerRight As Range
' Ensure a text box is selected
If TypeName(Selection) <> "TextBox" Then
MsgBox "Text box not selected"
Exit Sub
End If
' Get the range to cover
Set l_rRangeToCover = _
ActiveSheet.Range(Names("RangeToCover").RefersToRange.Value)
' Get its lower right cell
Set l_rLowerRight = _
l_rRangeToCover.Cells( _
l_rRangeToCover.Rows.Count, _
l_rRangeToCover.Columns.Count)
' Resize the text box
With Selection
.Left = l_rRangeToCover.Left
.Top = l_rRangeToCover.Top
.Width = l_rLowerRight.Left + l_rLowerRight.Width - .Left
.Height = l_rLowerRight.Top + l_rLowerRight.Height - .Top
End With
End Sub
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3143) 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: Resizing a Text Box in a Macro.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
Don't like the color of the lines that Excel chose for your drawing object? It's easy to choose your own colors, as ...
Discover MoreNeed to make sure that someone cannot delete a graphic in a worksheet? The ability to protect the graphic depends on ...
Discover MoreNeed to export a graphics group from a chart so that you can use the group in a different program? It's not as easy as ...
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