VBA code to find out if a file is already open

If you work in a team, there are times when more than one person tries to use a file.  Maybe your line manager is checking a piece of information in a workbook, whilst at the same time you are trying to rename the file.  When you’re running files manually, it normally provides a reasonable warning message, but if you’re trying to do this with a macro you will probably receive this type of error:

VBA file open Run-time error '75' File Path access error

If other users will be using your macro, chances are that they will have no idea what this error means.  The code below will check to see if the file is already open by you, or another user.  If it is open, or un-editable for any reason, you will be able to stop the macro from running or display a meaningful error message to the user.

The function has 3 possible results:

  • True = The file is already open
  • False = The file is currently closed
  • [Error Number] = Something else has gone wrong, so the error number is returned.
Function IsFileOpen(fileName As String)

Dim fileNum As Integer
Dim errNum As Integer

'Allow all errors to happen
On Error Resume Next
fileNum = FreeFile()

'Try to open and close the file for input.
'Errors mean the file is already open
Open fileName For Input Lock Read As #fileNum
Close fileNum

'Get the error number
errNum = Err

'Do not allow errors to happen
On Error GoTo 0

'Check the Error Number
Select Case errNum

    'errNum = 0 means no errors, therefore file closed
    Case 0
    IsFileOpen = False
 
    'errNum = 70 means the file is already open
    Case 70
    IsFileOpen = True

    'Something else went wrong
    Case Else
    IsFileOpen = errNum

End Select

End Function

Remember: Functions must be placed into a Module to work correctly.

The following procedure shows how to call the above function.

Sub CheckIfFileOpen()

Dim fileName As String
fileName = "C:\Users\marks\Documents\Already Open.xlsx"

'Call function to check if the file is open
If IsFileOpen(fileName) = False Then

    'Insert actions to be performed on the closed file

Else

    'The file is open or another error occurred
    MsgBox fileName & " is already open."

End If

End Sub

Discover how you can automate your work with our Excel courses and tools.

Excel Academy

Excel Academy
The complete program for saving time by automating Excel.

Excel Automation Secrets

Excel Automation Secrets
Discover the 7-step framework for automating Excel.

Office Scripts Course

Office Scripts: Automate Excel Everywhere
Start using Office Scripts and Power Automate to automate Excel in new ways.

6 thoughts on “VBA code to find out if a file is already open”

  1. I found that this code does not work for files opened from network mapped drive. Maybe that is because network file system isn’t using Windows OS and you don’t have the information if file is open?

    Reply

Leave a Comment