Test If A Worksheet Exists and Is Not Open So It Can Be Updated
The purpose of the code below is to validate that a target workbook is available and not open by another user so it can be updated. In this sample, we open the target workbook and increment a counter in that workbook. Once the counter has been updated, we save and close it. If you read the program notes, you will see all the steps required to ensure that the target workbook is updated properly.
Program Code
Option Explicit
Public Sub TestForFileExists()
' ***************************************************************
' This Demonstration Module Shows The Steps To Open And Update
' A Second Target Workbook From This Workbook
' For Integrity The VBA Code Performs The Following Checks:
' (1) Make Sure the Server Path To the Target Workbook Is Valid
' (2) If The Path Is Valid, Make Sure the Target Workbook Exists
' (3) If The Target Workbook Exists, Make Sure It Is Not Open
' (4) If All The Tests Above Are Good, Then Update The Target
' (5) Save And Close The Target Workbook
' ***************************************************************
Dim strDirectoryPath As String
Dim strTargetWorkbookName As String
Dim strFullPathToWorkbook As String
Dim lngNextSequence As Long
strDirectoryPath = "C:\MyTestDirectory\"
strTargetWorkbookName = "MyTestWorkbook.xls"
' ***************************************************************
' Make Sure That The Target Directory Path Is Available
' This Is Useful When Files Are Opened From a Server
' To Make Sure the Server is Up
' ***************************************************************
If Not FileFolderExists(strDirectoryPath) Then
MsgBox ("The Directory " & strDirectoryPath & _
vbCrLf & " Does Not Exist")
Exit Sub
End If
' ***************************************************************
' Create The Full Path To The Target Workbook
' ***************************************************************
strFullPathToWorkbook = strDirectoryPath & strTargetWorkbookName
' ***************************************************************
' Confirm That The Full Path To The Workbook Exists
' ***************************************************************
If Not FileFolderExists(strFullPathToWorkbook) Then
MsgBox ("The File " & strFullPathToWorkbook & _
vbCrLf & " Does Not Exist")
Exit Sub
End If
' ********************************************************
' Make Sure The Target Workbook Is Not Open
' ********************************************************
If IsFileOpen(strFullPathToWorkbook) Then
MsgBox ("File " & strFullPathToWorkbook & " Is Open By Another User" _
& vbCrLf & "Try Again Later")
Exit Sub
End If
Application.ScreenUpdating = False
' ********************************************************
' Open The Workbook
' ********************************************************
On Error GoTo Target_Workbook_File_Open_Error:
Workbooks.Open strFullPathToWorkbook
On Error GoTo 0
' ********************************************************
' Update The Target Workbook Sequence Number In Cell (2,1)
' ********************************************************
lngNextSequence = Cells(2, 1).Value
lngNextSequence = lngNextSequence + 1
Cells(2, 1).Value = lngNextSequence
Workbooks(ThisWorkbook.Name).Activate
' ********************************************************
' Close And Save the Updated Target Workbook
' ********************************************************
On Error GoTo Target_Workbook_File_Save_Error:
Application.DisplayAlerts = False
Workbooks(strTargetWorkbookName).Close savechanges:=True
Application.DisplayAlerts = True
On Error GoTo 0
' ********************************************************
' Exit The Application
' ********************************************************
Exit_The_Application:
Application.ScreenUpdating = True
On Error GoTo 0
Exit Sub
' ********************************************************
' Target Workbook File Save Error
' ********************************************************
Target_Workbook_File_Save_Error:
MsgBox ("Error Saving The Target Workbook: " & strFullPathToWorkbook)
Resume Exit_The_Application
' ********************************************************
' Target Workbook File Open Error
' ********************************************************
Target_Workbook_File_Open_Error:
MsgBox ("Error Opening: " & strFullPathToWorkbook)
Resume Exit_The_Application
End Sub
Public Function IsFileOpen(FileName As String)
' ********************************************************
' Test To Determine If A File is Open
' ********************************************************
Dim iFilenum As Long
Dim iErr As Long
On Error Resume Next
iFilenum = FreeFile()
Open FileName For Input Lock Read As #iFilenum
Close iFilenum
iErr = Err
On Error GoTo 0
Select Case iErr
Case 0: IsFileOpen = False
Case 70: IsFileOpen = True
Case Else: MsgBox (Error(iErr) & " " & FileName)
End Select
End Function
Public Function FileFolderExists(strFullPath As String) As Boolean
' ********************************************************
' Test To See If A Directory Or File Exists
' ********************************************************
On Error GoTo Exit_Folder_Test
FileFolderExists = False
If Not Dir(strFullPath, vbDirectory) = vbNullString Then FileFolderExists = True
Exit_Folder_Test:
On Error GoTo 0
End Function