Written by Allen Wyatt (last updated December 25, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Steven has a worksheet with many rows and columns of data. He has frozen the first row and column by making cell B2 active and then freezing panes. This works as he wants it to. He can even save and close the workbook, and the panes are still frozen when he reopens the workbook. However, if Steven opens a new window for the workbook (View | Window | New Window), the new window does not have frozen panes. As he has frozen panes on many worksheets in this workbook, he has to be very careful about which window he closes first. If he closes the original window first, when he saves the workbook it saves all the unfrozen worksheets. Steven wonders if there is a way to get the new window to retain the frozen panes settings?
There is no setting in Excel that will handle what Steven needs to happen. The reason that the frozen panes are not saved is because FreezePanes (along with Zoom, Split, and a few other settings) are properties of windows, not of worksheets or workbooks. When a new window is created, the properties are not inherited from the original window.
You can, however, get around this behavior (and solve Steven's problem) by using a macro to do the setup for you. A very short approach is to forego using the ribbon tools to create your new window. Instead, add this macro to the QAT and use it to do the window creation:
Sub CreateNewWindow1() Dim rPane As Range Set rPane = ActiveWindow.VisibleRange(1) ActiveWindow.NewWindow ActiveSheet.Range("B2").Select ActiveWindow.FreezePanes = True End Sub
The macro creates a new window, sets the visible cells equal to what is shown in the original window, selects cell B2 in the new window, and then freezes the panes.
This simple of an approach may not work, however, if your "pane freezing" needs are more varied. For instance, you may want a way to create a new window and have it match whatever panes were in the window that was active when you created the new window.
The following macro checks to see if the current window has a a fozen pane. If it does, then it figures out where it is frozen and uses that to set the frozen panes in a new window. If there are no frozen panes, then a new window is created anyway, and nothing there is frozen. In either case, the same cell is selected in the new window as was selected in the original.
Sub CreateNewWindow2() Dim iRow As Integer Dim iCol As Integer Dim rOldPos As Range iRow = 0 iCol = 0 If ActiveWindow.FreezePanes Then iRow = ActiveWindow.ScrollRow iCol = ActiveWindow.ScrollColumn End If Set rOldPos = ActiveCell ActiveWindow.NewWindow If (iRow > 0) And (iCol > 0) Then Cells(iRow, iCol).Select ActiveWindow.FreezePanes = True End If rOldPos.Select End Sub
This code, again, could be used for creating any new windows you want. They accomplish what Steven needed done because they copy the frozen pane settings from the active window to the newly created window.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13366) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Tired of hitting the F1 key by mistake and pulling up the Help system? Here are a couple of ways (one drastic and one not ...
Discover MoreIf your worksheet gets large enough, you may notice a severe slowdown when it is recalculated. This tip provides some ...
Discover MoreWhen you freeze panes in a worksheet, those panes should persist even though you save the workbook and reload it. There ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-12-25 11:46:24
Willy Vanhaelen
The second macro in this tip is rather complex and preserves only the frozen panes of the active sheet.
The following macro, is only half the size and much more performant. It creates a second window preserving frozen panes (even complex ones) in all sheets of the active workbook:
- It tries to create a custom view preserving frozen panes in all sheets
(it will not succeed if for instance the workbook contains a table).
- It then creates a new window.
- If the creation of a custom view was successful it applies it to the second window
- It then deletes the custom view (if any) because it is not needed anymore.
- If it was not able to create a custom view, only a normal second window is created
and MsgBox warns you of that.
Sub WindowReplica()
On Error Resume Next
With ActiveWorkbook
.CustomViews.Add ViewName:="tmp", PrintSettings:=True, RowColSettings:=True
.NewWindow
.CustomViews("tmp").Show
.CustomViews("tmp").Delete
End With
If Len(Error) Then MsgBox "Attention: no 'Custom View'", vbExclamation
End Sub
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