Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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: Positioning a Column on the Screen.
Written by Allen Wyatt (last updated December 21, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 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, 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.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Want to add some macros to your workbook? What do you do if you try to add the macros but the program has disabled the tools?
Discover MoreWhen you assign a macro to a shortcut key, you make it easy to run the macro without ever removing your hands from the ...
Discover MoreDo you need to create a number of words or phrases where you only alter a few letters in each one? If the alterations ...
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