Inadvertantly Getting Rid of Frozen Panes

Written by Allen Wyatt (last updated December 25, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021


1

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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13366) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Changing the Perspective of Your Chart

Microsoft Graph can be a handy way to add quick and dirty charts to your document. When working with 3-D charts, you can ...

Discover More

Printing Non-Printing Characters

Serious users of Word often display non-printing characters on-screen so they can see them easier. If you want those ...

Discover More

Controlling Endnote Placement

Endnotes are often used in technical and scholarly documents. You can control exactly where the endnotes appear in your ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!

More ExcelTips (ribbon)

Picking a Workbook Format

Need to share workbook information with a wide number of people? It can be puzzling to figure out which version of Excel ...

Discover More

Going to the Corners of a Selected Range

When you select a range of cells (particularly if it is a large range of cells), you may not be quite sure if you've ...

Discover More

Viewing More than Two Places in a Worksheet

If your worksheet gets big enough, it is easy to spend a lot of time navigating back and forth between different areas. ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two less than 9?

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


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.