Bypassing the BeforeClose Event

by Allen Wyatt
(last updated April 12, 2021)

1

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, and 2016.

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

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

Doubling Your Money

Make your money last longer by using your head when printing labels. Here's a great example of how you can double the ...

Discover More

Saving All Open Workbooks

Wouldn't it be nice to have a single command that would save each of your open workbooks, all at once? It's easy to do ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Telling which Worksheets are Selected

If your macro processes information on a number of worksheets, chances are good that you need your macro to figure out ...

Discover More

Making Modal Dialog Boxes Appear in Front of Workbooks

Perhaps the most common way of communicating with programs is through the use of dialog boxes. We expect dialog boxes to ...

Discover More

Determining Differences Between Dates

Macros are often used to process the data in a worksheet. If that data includes dates that need to be processed, you'll ...

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

2016-11-05 11:27:15

Brian Canes

Ribbon>Developer>Controls>Design Mode off
This will disable events and the BeforeClose will not fire.
Regards
Brian


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.