Written by Allen Wyatt (last updated August 20, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
If Roy holds down the Shift key when opening a workbook, Excel bypasses the running of any "auto" macros that would normally run, including the Workbook_Open event. He wonders if there is an equally easy way, when closing a workbook, to cause Excel to bypass the Workbook_BeforeClose event.
There is not an equally easy way. That doesn't mean it can't be done, but "equally easy" generally means "something built in; some key to press or setting to make." Such keys and settings to bypass the BeforeClose event just aren't built into Excel.
What you can do is adjust how you program the BeforeClose event so that if a particular condition is met, then the code within the event handler is bypassed. An easy approach is to simply bypass the code if a particular worksheet cell is selected, in this manner:
Private Sub Workbook_BeforeClose(Cancel As Boolean) If ActiveCell.Address = "$Z$27" Then Exit Sub ' ' Your normal code here... ' End Sub
In this case, if the active cell—the one selected when the BeforeClose event is triggered—happens to be cell Z27, then your regular code in the event handler is skipped. If any other cell is selected, then it isn't skipped. (I purposely picked cell Z27 because it is both esoteric and obscure. You can, of course, change the code to reflect any other cell you desire.)
If you are dead-set on checking to see if the Shift key is being held down, you can do that by utilizing the Windows API. This involves adding some code to the declarations area of a module. This can be a regular module; it doesn't have to be in the ThisWorkbook code window. You just need to make sure it is in the declarations area, before any procedures are declared.
#If VBA7 Then Declare PtrSafe Function GetKeyState Lib "USER32" (ByVal vKey As Long) As Integer #Else Declare Function GetKeyState Lib "USER32" (ByVal vKey As Long) As Integer #End If
Note that the #If VBA7 conditional directive is used so that if you are using Excel 2010 or later, the correct syntax of the declaration will be used so there is no errors on either 32-bit or 64-bit versions of the program.
Now, within your BeforeClose event handler you can do the following:
Private Sub Workbook_BeforeClose(Cancel As Boolean) Const VSHIFT = &H10 Const SHIFTED = &H80 If GetKeyState(VSHIFT) And SHIFTED Then Exit Sub ' ' Your normal code here... ' End Sub
If the Shift key is held down as the BeforeClose event is triggered, then the BeforeClose code is skipped. You should note that it may be a bit difficult to figure out when to hold down the Shift key or if you've held it down long enough. For this reason, I tend to prefer the "check the ActiveCell" approach better, as you can simply select the cell, close the workbook, and forget about it.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2628) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Do you need to create a number of words or phrases where you only alter a few letters in each one? If the alterations ...
Discover MoreWant to add some macros to your workbook? What do you do if you try to add the macros but the program has disabled the tools?
Discover MoreNeed to figure out an absolute value within your macro code? It's easy to do using the Abs function, described in this tip.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-08-20 11:26:29
J. Woolley
With the Tip's Declare statement for GetKeyState, My Excel Toolbox includes the following procedure to return the True/False (Down/Up) status of Shift, Ctrl, and Alt:
Const VK_SHIFT As Integer = &H10 ' Shift
Const VK_CONTROL As Integer = &H11 ' Ctrl
Const VK_MENU As Integer = &H12 ' Alt
Sub GetKeys_ShiftCtrlAlt(ByRef Shift As Boolean, _
ByRef Ctrl As Boolean, ByRef Alt As Boolean)
Shift = (GetKeyState(VK_SHIFT) < 0)
Ctrl = (GetKeyState(VK_CONTROL) < 0)
Alt = (GetKeyState(VK_MENU) < 0)
End Sub
See https://sites.google.com/view/MyExcelToolbox/
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