Inadvertantly Getting Rid of Frozen Panes

by Allen Wyatt
(last updated January 31, 2015)

4

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.

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

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

Renaming a Macro

Want to give your macros a different name than they currently use? There are a couple of ways you can do the renaming, as ...

Discover More

Wildcards in 'Replace With' Text

When doing searches in Excel, you can use wildcard characters in the specification of what you are searching. However, you ...

Discover More

Entering or Importing Times without Colons

Enter a time into a cell and you normally include a colon between the hours and minutes. If you want to skip that pesky ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (ribbon)

Embedding Your Phone Number in a Workbook

Want to provide a bit of contact information in a workbook? A great place to do it (out of sight, but not inaccessible) is in ...

Discover More

Removing Add-ins

Add-ins are used to extend Excel's capabilities in lots of different ways. If you want to get rid of an add-in completely, ...

Discover More

Disabling a Function Key

Function keys are used to perform common tasks in Excel. If you want to disable one of the function keys, it's rather easy to ...

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}] 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 nine more than 9?

2015-06-09 18:27:35

Lou

This works fine on non-Table tabs except if you have filtered data that tricks your code into thinking the filtered row is the one that is displayed. This is a real problem if you have more than a screen worth's of data filtered out and then you do a Show All on the new window. The whole screen is frozen!

Is this something can be fixed?

I tried various ways in VBA with Freeze Panes but if the first record after the title cells are filtered out, the wrong row is selected to be frozen. This is probably due to the Freeze Panes actions only working with visible cells.

Also I added a small modification to your code to capture the Window zoom and apply it to the new window as such:

Sub CreateNewWindow()
Dim iRow, iCol, iZoom 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
iZoom = ActiveWindow.Zoom
ActiveWindow.NewWindow
If (iRow > 0) And (iCol > 0) Then
Cells(iRow, iCol).Select
ActiveWindow.FreezePanes = True
End If
rOldPos.Select
ActiveWindow.Zoom = iZoom
End Sub


2015-02-03 09:42:43

Willy Vanhaelen

@Suzan
This works fine except when your workbook contains a table. Then Custom Views is grayed out and cannot be used.


2015-02-02 16:22:31

Susan

There is another way you can handle this without using macros. Before creating a new window you can click on view then custom views. From there you can add a view and name it what ever you want. Then as soon as you create the new window click on custom view again and click on the new view you created.


2015-02-02 10:29:44

Kevin

I modified the code to apply identical frozen pane and window zoom properties to every sheet in the new window.

Sub CreateNewWindow()
Dim iRow As Integer
Dim iCol As Integer
Dim rOldPos As Range
Dim iZoom As Integer
Dim wOldWindow As Window
Dim wNewWindow As Window
Dim sSheet As Worksheet
Dim sOldSheet As Worksheet

Set wOldWindow = ActiveWindow
Set sOldSheet = ActiveSheet
wOldWindow.NewWindow
Set wNewWindow = ActiveWindow
For Each sSheet In ActiveWorkbook.Worksheets
wOldWindow.Activate
sSheet.Select
Set rOldPos = ActiveCell
iRow = 0
iCol = 0
If wOldWindow.FreezePanes Then
iRow = ActiveWindow.ScrollRow
iCol = ActiveWindow.ScrollColumn
End If
iZoom = wOldWindow.Zoom

wNewWindow.Activate
sSheet.Select
If (iRow > 0) And (iCol > 0) Then
Cells(iRow, iCol).Select
wNewWindow.FreezePanes = True
End If
wNewWindow.Zoom = iZoom
rOldPos.Select
Next sSheet
wOldWindow.Activate
sOldSheet.Select
wNewWindow.Activate
sOldSheet.Select
Set wOldWindow = Nothing
Set wNewWindow = Nothing
Set rOldPos = Nothing
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.