Viewing Same Cells on Different Worksheets

Written by Allen Wyatt (last updated September 25, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003


When using multiple worksheets, Chris wonders if there is a way to 'lock' the scrolling through all worksheets. For instance, if he scrolls down and across on Sheet1 until rows 100 to 140 and columns G to P are in view, then when he switches to Sheet2 (or any other worksheet) he would like the same rows and columns to be shown on those worksheets.

The only way to accomplish this task is through the use of macros. What has to happen is that the macro needs to determine which rows and columns are visible when a sheet is deactivated (being left) and then set the display of the activated sheet (the one you are going to) to the same rows and columns. The following macros, added to the ThisWorkbook module, perform exactly this task.

Dim grngSelection As Range
Dim gintScrollColumn As Integer
Dim glngScrollRow As Long

Private Sub Workbook_SheetActivate(ByVal Sh As Object)
    If TypeName(ActiveSheet) = "Worksheet" Then
        On Error Resume Next
        With ActiveWindow
            Sh.Range(grngSelection.Address).Select
            .ScrollColumn = gintScrollColumn
            .ScrollRow = glngScrollRow
        End With
    End If
End Sub
Private Sub Workbook_SheetDeactivate(ByVal Sh As Object)
    Dim oSheet As Object
    If TypeName(Sh) = "Worksheet" Then
        Set oSheet = ActiveSheet
        Application.EnableEvents = False
        Sh.Activate
        With ActiveWindow
            gintScrollColumn = .ScrollColumn
            glngScrollRow = .ScrollRow
            Set grngSelection = .RangeSelection
        End With
        oSheet.Activate
        Application.EnableEvents = True
    End If
End Sub

Note the use of the variables outside of the event handlers. These variables are used to pass the values of the column, row, and selected area from the SheetDeactivate handler to the SheetActivate handler.

Of course, you may not want an automatic solution. Instead, you may want the user to take a specific step to trigger whether the worksheets are synchronized. This can be done by adding the following macro to a regular module in your workbook:

Global WindowScrollRow
Global WindowScrollCol
Global WindowSyncOn As Boolean

Public Sub WindowLock()
    If Not WindowSyncOn Then
        WindowScrollRow = ActiveWindow.VisibleRange.Row
        WindowScrollCol = ActiveWindow.VisibleRange.Column
        Application.StatusBar = "WindowSync: ON"
    Else
        Application.StatusBar = ""
    End If
    WindowSyncOn = Not WindowSyncOn
End Sub

All that this macro does is to check the status of the global variable WindowSyncOn. If the value is False, then the current settings for the top visible row and leftmost visible column are stored into global variables. The setting of these variables are then used by the following event handler, added to the ThisWorkbook module:

Private Sub Workbook_SheetActivate(ByVal Sh As Object)
    If WindowSyncOn Then
        If Not ActiveWindow Is Nothing Then
            ActiveWindow.ScrollRow = WindowScrollRow
            ActiveWindow.ScrollColumn = WindowScrollCol
        End If
    End If
End Sub

The macro simply checks the setting of the WindowSyncOn variable, and if it is True (it has been set), then the macro sets which row and column are at the top and left of the active 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 (3860) applies to Microsoft Excel 97, 2000, 2002, and 2003.

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

Short-Lived Book1

If you have a problem that crops up when you first start Excel, it can be a bear to track down the cause of the problem. ...

Discover More

Adjusting Spell Check for Internet Addresses

When you check the spelling of worksheet data, you may want to spell checker to either ignore or check Internet addresses ...

Discover More

Implementing a Dynamic Document Control Table

Accurately and repeatedly referencing information within a document is a common task that needs to be done. One way to ...

Discover More

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!

More ExcelTips (menu)

Viewing Two Worksheets At Once

If you need to work on two worksheets in the same workbook at the same time, Excel makes this rather easy to do. All you ...

Discover More

Shortcut to Move between Two Worksheets

Moving between to adjacent worksheets is easy; Excel provides a shortcut key to do the trick. If you want to move between ...

Discover More

Referencing a Worksheet Name

Excel provides ways to reference the column or row number of a cell, but it doesn't provide a built-in way to reference a ...

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 2 + 2?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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.