Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Disabling Moving Between Worksheets.
Written by Allen Wyatt (last updated December 19, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Excel provides a variety of ways that you can move from one worksheet to another in a workbook. If you want to disable moving between worksheets, you've got a difficult task in front of you because of the variety of methods you need to do something about.
For instance, one way to move between worksheets is to press Ctrl+Page Up or Ctrl+Page Down. To disable these keys for a particular workbook, you need to use the OnKey method, in the following manner:
Private Sub Workbook_Activate() Application.OnKey "^{PgDn}", "" Application.OnKey "^{PgUp}", "" End Sub
Private Sub Workbook_Deactivate() Application.OnKey "^{PgDn}" Application.OnKey "^{PgUp}" End Sub
These two macros should be placed in the ThisWorkbook object. The first is run whenever the workbook is activated and it disables Ctrl+Page Up and Ctrl+Page Down by having nothing run when they are pressed. The second macro is run when the workbook is deactivated and re-enables the keys.
There are still a number of other ways to switch between worksheets, such as manually selecting the sheet, using Go To, using hyperlinks, etc. The easiest way to prevent moving between worksheets is to hide the worksheets you don't want accessed. Protecting the workbook and protecting the VB project will also aid in "thwarting" the user from moving between sheets.
If the sheets are hidden, they cannot be selected and thus you cannot move to them. Go To will not go to them, hyperlinks will not go to them. If you want users to be able to view the hidden worksheets later, you must create a macro routine with your own controls/buttons to go to those sheets. This routine would "unhide" the sheet you are going to and hide the one you just left.
Depending on your needs, there is one other approach you can try. You could add the following macro to the ThisWorkbook object:
Private Sub Workbook_SheetDeactivate(ByVal mySheet As Object) Application.EnableEvents = False mySheet.Activate Application.EnableEvents = True End Sub
This macro is executed every time the current worksheet is deactivated. It essentially "reactivates" the worksheet that is being left, which means that no other worksheet can ever be selected.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11210) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Disabling Moving Between Worksheets.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
By default, a new Excel workbook contains three blank worksheets. You can (and should) configure Excel to whatever number ...
Discover MoreIf you spend a lot of time creating a worksheet, you might want to make multiple copies of that worksheet as a starting ...
Discover MoreExcel keeps a full set of properties related to workbooks. When it comes to worksheets, however, there is very little ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-12-19 09:41:45
David Bonin
I have many workbooks with VBA for my administrative use, and to gather and process data.
This code is of no value to those who receive my results, and it may be harmful if they try to use it.
I call the following function from many VBA procedures to thwart others from running my code. When the function returns a false, I shut down the calling routine.
It's not fool-proof, but it hasn't let me down yet. Those that try to work around this code and end up breaking things up can never come back to me and say it was an accident or that my code is buggy.
[[CODE START]]
Function IsAuthorizedUser(Optional ByVal BeChatty As Boolean = True) As Boolean
' Purpose: Determine whether the user is authorized to use a particular button.
' Present an error message for everyone else.
'
' Arguments: BeChatty (Optional)
' True - Provide a message to unauthorized users. This is the default.
' False - Do not provide a message to unauthorized users.
'
' Notes: Returns True if authorized. Returns False if not.
'
If Application.UserName = "Dave Bonin") Then
IsAuthorizedUser = True
Else
IsAuthorizedUser = False
If BeChatty = True Then
MsgBox "Only Dave Bonin is allowed to use" & vbCr & "this button. You are not him.", _
vbOKOnly + vbCritical, "You Are Not Authorized"
End If
End If
End Function
[[CODE END]]
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