Written by Allen Wyatt (last updated March 22, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365
Riek encountered a problem while developing a macro that sets up the screen for user input. Columns A:G always need to stay on the screen, so his macro freezes those columns. He then issues a command to move to column Z to start input. This places columns T:Z to the right of the frozen columns A:G. What Riek really wants is for columns Z:AF to appear to the right of A:G, but he doesn't know how to accomplish that.
There are several ways that the desired results can be achieved. The first is to simply move "past" the desired target, and then move back to it, as in the following macro:
Sub GotoCol1() With Application ActiveWindow.FreezePanes = False Range("H1").Select ActiveWindow.FreezePanes = True .Goto Range("IV1") .Goto Range("Z1") End With End Sub
The important code lines are those that use the Goto method. The first jump is to the last cell of the first row, and the second jump moves back to the true target, Z1. By moving in this way, column Z ends up just to the right of the frozen range, A:G.
While this works just fine, a better solution would be to use the Scroll parameter with the Goto method. Consider the following example:
Sub GotoCol2() ActiveWindow.FreezePanes = False Range("H1").Select ActiveWindow.FreezePanes = True Application.Goto Reference:=Range("Z1"), Scroll:=True End Sub
The Scroll parameter is optional with the Goto method; it defaults to False. If you set it to True, then Goto scrolls through the window so that the upper-left corner of the target range (Z1) appears in the upper-left corner of the window.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10523) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Positioning a Column on the Screen.
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!
Developing macros can be rewarding, but it can also be challenging. Getting individual macros to run properly is hard ...
Discover MoreMacros are often used to process the data stored in a worksheet. Some of these processing needs can be pretty specific to ...
Discover MoreISBNs are used to uniquely identify books. You may need to know if an ISBN is valid or not, which involves calculating ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2025-03-23 16:50:25
Mike J
Both of these macros fail if columns A:G are not all visible when run. For instance if the leftmost visible column is C then columns A and B will still not be visible after running the macro.
Inserting Range("A1").Select before Range("H1").Select will ensure Columns A:G will all be visible.
2025-03-22 08:38:11
Alan Cannon
I think a simpler approach would be to simply hide columns H:Y then select cell Z1. This can readily be done with a macro. Another macro could unhide the columns before saving or closing.
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 © 2025 Sharon Parq Associates, Inc.
Comments