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: Setting Program Window Size in a Macro.
Written by Allen Wyatt (last updated March 23, 2019)
This tip applies to Excel 97, 2000, 2002, and 2003
Christopher needs, within a macro, to set the size of the Excel program window. He knows how to set the size of a worksheet within the program window, but that isn't what he needs. He wonders how he can set the overall size of the program window, plus make sure that he doesn't set it larger than the user's actual screen size.
This can be done rather easily if one knows which objects and properties to use in your macro. The object you want to use is the Application object, which refers to the Excel application. Here are the pertinent properties:
With these in mind, you could set the position and size of the program window in this manner:
Sub SetWindowSize1()
Application.WindowState = xlNormal
Application.Top = 25
Application.Left = 25
Application.Width = 300
Application.Height = 200
End Sub
This macro specifies the upper-left corner of the program window to be 25 pixels from the top of the screen and 25 pixels from the left of the screen. Then, the program window is set to be 300 pixels wide and 200 pixels tall. Note, as well, the setting of the WindowState property at the first of the macro. This sets the window to be in a "normal" state, meaning one that can be resized to something larger than minimized and smaller than maximized. (If you want the Excel program window to take their entire screen, simply set the WindowState property to xlMaximized and forget the rest of the settings in the macro.)
Of course, this macro sets the Excel program window to be rather small. In all likelihood you'll want it to be larger, but you don't want it to be larger than the size of the user's screen. The easiest way to figure out the size of the user's screen is to simply maximize the Excel application window and then look at the Width and Height properties. You can then adjust those figures based on where you want the upper-left corner of the screen to be and then adjust accordingly.
As an example, let's say that you want the program window to start at 25, 50 and you want it to be 1000 x 500. You could use code similar to the following:
Sub SetWindowSize2()
Dim iMaxWidth As Integer
Dim iMaxHeight As Integer
Dim iStartX As Integer
Dim iStartY As Integer
Dim iDesiredWidth As Integer
Dim iDesiredHeight As Integer
iStartX = 50 ' Distance from left
iStartY = 25 ' Distance from top
iDesiredWidth = 1000
iDesiredHeight = 500
With Application
.WindowState = xlMaximized
iMaxWidth = Application.Width
iMaxHeight = Application.Height
' Adjust for starting point
iMaxWidth = iMaxWidth - iStartX
iMaxHeight = iMaxHeight - iStartY
If iDesiredWidth > iMaxWidth Then
iDesiredWidth = iMaxWidth
End If
If iDesiredHeight > iMaxHeight Then
iDesiredHeight = iMaxHeight
End If
.WindowState = xlNormal
.Top = iStartY
.Left = iStartX
.Width = iDesiredWidth
.Height = iDesiredHeight
End With
End Sub
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10938) 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: Setting Program Window Size in a Macro.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Part of writing macros is to make sure they work as you expect. This involves a process known as debugging. Here's how ...
Discover MoreWhen you have a macro that processes a huge amount of data, it can seem like it takes forever to finish up. These ...
Discover MoreWhen you delete all the macros in a workbook, Excel may still think you have some there. Here's why that happens and 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 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