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:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3860) applies to Microsoft Excel 97, 2000, 2002, and 2003.
Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!
Need to sort your worksheets so that they appear in an order determined by the value of a cell on each worksheet? Using a ...
Discover MoreCopy a formula from one place to another and Excel helpfully adjusts the cell references within the formula. That is, it ...
Discover MoreWant a quick way to combine your worksheets? Excel provides a tool to make the task easier, but you could also bypass the ...
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 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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments