Testing if a Workbook is Open

Written by Allen Wyatt (last updated March 30, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


1

Brian has a complex workbook that opens other supporting workbooks very briefly and then closes them, saving changes. He has an office with three people that use his macros, and on occasion they get a conflict where two people are trying to get a purchase order number at the same time. This causes the PO workbook to open in 'read only' mode for the second occurrence, which is confusing to users. Brian wonders if there is a line of VBA code that will stop the 'open workbook' command if the target workbook is already open by a different user. That way he could catch potential problems before they occur.

It is much easier to have your code, after opening, check to see if the workbook opened in read-only mode. If it did, then you can take an action appropriate to your situation. (For instance, you could close the workbook, wait a short period, and retry the operation and test.) Here's how you can check to see the read-only status:

Set wkBook1 = Workbooks.Open("c:\MyBigBook.xlsx")

If wkBook1.ReadOnly Then
    wkBook1.Close False
End If

Note that it is the ReadOnly property that yields the desired info. If you need to check the file ahead of time, you might try using some of the file-access statements available in VBA. That's what the following function does.

Function FileIsLocked(strFileName As String) As Boolean
    FileIsLocked = False
    On Error Resume Next
    Open strFileName For Binary Access Read Write Lock Read Write As #1
    Close #1

    ' If an error occurs, the document is currently open
    If Err.Number <> 0 Then
       FileIsLocked = True
       Err.Clear
    End If
End Function

To use the function, pass it the name (including full path) of the workbook you want to check. The function returns True if the file is locked and False if it isn't. Remember, though, that from the time this function checks the file to the time that you actually try to open the file, it could have been opened by someone else. Thus, the first approach (checking after trying to open) may be the best approach to use.)

It should be noted, as well, that you could also save the other workbooks as shared workbooks. This would allow them to be opened by multiple users with no problems. Of course, you'll want to check how this approach affects the data you may be wanting to save in the workbooks.

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 (5831) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.

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

Using Multiple Test Conditions

When creating conditional formats, you are not limited to only one condition. You can create up to three conditions, all ...

Discover More

Delivery Address Won't Print on Envelopes

Word includes a feature that allows you to easily create and print envelopes, based on the addresses you insert in your ...

Discover More

Mail Merge and Data Source Documents become Unattached

When you create a mail merge document, you attach it to a data source that is the basis for the information to be merged ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (ribbon)

Updating Automatically when Opening Under Macro Control

If your workbook contains links, you are normally given the opportunity to update those links when you open the workbook. ...

Discover More

Changing the Default Drive

Do you have a macro that needs to read and write files? If so, then there is a good chance you need to specify the ...

Discover More

Exiting a For ... Next Loop Early

If you use For ... Next loops in your macros, make sure you give a way to jump out of the loop early. That way you can ...

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 two minus 0?

2024-03-30 15:54:37

J. Woolley

I suggest modifying the Tip's first VBA code block as follows:

    Set wkBook1 = Workbooks.Open("c:\MyBigBook.xlsx")
    If wkBook1.ReadOnly Then
        wkBook1.ChangeFileAccess Mode:=xlReadWrite, Notify:=True
    End If

If the workbook was previously opened by others, the first message will be displayed (see Figure 1 below) and it will be opened in read-only mode. If the user clicks Notify in the first message, then when all others have closed the workbook the second message will be displayed (see Figure 2 below) and the user can reopen the workbook in read-write mode, with the third message (see Figure 3 below) displaying available options.

Figure 1. 

Figure 2. 

Figure 3. 


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.