Logicwurks Home Page

Links To Excel Code Examples

Tracing VBA Statements
Range/Wkb/Wks Variables
Add Grand Totals Using Ranges
Using Range Offset Property
Using Range Find Method
ConvertCellAddressToRange
Set Conditional Formatting
Union Of Ranges
Parse Range Strings
Delete Duplicate Rows
Delete Rows And Columns
Worksheet Variables
TypeName And TypeOf
Loop Through Worksheets
Loop Through Open Workbooks
Form Button Magic
Command Button Magic
Add Worksheets Dynamically
ImportExternalWorksheets
Find Last Row Or Column
Copy And Paste Special
Copy To Specific Cell Types
Range Copy With Filter
ExcelFileOpenSaveClose
ExcelFileOpenSaveCSV
Open An Excel File
Open An Excel File w/Params
Open An Excel File On Web
Save A Workbook
Save A Workbook Using mso
Clone A Workbook
Test If WEB URL Exists
Parse Using Split Command
Using Classes in Excel
TypeStatementStructures
Color Management
Convert Cell Color To RGB
Sort Methods 2003 - 2010
Sort Alpha/Numeric In ASCII
Search Using Match Function
Search Using Vlookup Function
Search Using Xlookup Function
Using Find Instead of Vlookup
Remove String Non-Printables
Auto_Open And Auto_Close
Initialize Form At Open
Edit Numerics In UserForm
Load Combo And List Boxes
Floating Sheet Combo Boxes
Advanced User Form Coding
Excel Events
Worksheet Change Events
Binary Search Of Array
Typecast Constants
Excel Error Handling
Handling Optional Parameters
Data Validation Drop Downs
Insert Data Validation Sub
Read A Text File w/Handle
Write A Text File w/Handle
Read a Binary File w/Handle
Update a Binary File w/Handle
Binary File Copy and Update
Read A Text Fiile w/Script
Text File Processing Examples
Test For Exists Or Open
Splash Screen
Dynamically Load Formulas
PaymentStreamsByDate
Date Examples
Date Find Same Days
Convert Month To Number
Initialize Arrays
Load Arrays Using Evaluate
ChartsAndGraphsVBA
Redim An Array
Reassign Button Action
Timer Functions
Legacy Calendar Control
Excel 2010 Date Picker
Date Picker Alternative
Generate Multiple Worksheets
Read Access Data Into Excel
Send Outlook Email w/Attach
Copy AutoFilters To Sheets
Export A Text File
Get Windows User Name
VBA Format Statement
Manipulate Files via VBA
Dynamically Load Images
Loop Through Worksheet Objects
Loop Through Form Objects
Loop Through Files with DIR
Active-X Checkboxes
Add Forms Checkboxes Dynam
Paste Pictures Into Excel
Copy Pictures Sheet To Sheet
Copy Pictures Sheet To Sheet
Create Forms Buttons With VBA
Extract Filename From Path
Convert R1C1 Format to A1
Special Cells Property
Insert Cell Comments

Links To Access Code Examples

DAO Versus ADODB
SearchVBACodeStrings
Interface Excel With Access
Create Form Manually
Create Recordset With AddNew
Multi-Select List Boxes
Update Field(s) In A Recordset
Update Excel Pivot From Access
Import A Tab Delimited File
Export Excel FileDialog
Create Excel Within Access
Open Excel Within Access
Open Excel OBJ From Access
Format Excel From Access
Control Excel via Access VBA
On Error Best Practices
Import Tab Delim w/WinAPI
Initialize Global Variables
Using TempVars For Globals
Access Error Handling
Loop Through Form Controls
Insert A Calendar Control
Create A Filtered Recordset
Populate Combo Boxes
Bookmarks And Forms
Combo Box Multiple Sources
Passing Form Objects
Create VBA SQL Statements
Create Dynamic Queries
Display File Images On A Form
Manipulate Files via VBA
Manipulate Files via Scripting
Number Subform Records
Reference Subform Objects
Parse Delimited Fields
Parameterized Queries (VBA)
Manipulating QueryDefs In VBA
FindFirst On Combined Keys
Dlookup Command
Dlookup In Form Datasheet
Execute SQL Delete Records
Commit Form To Table
Report With No Data
Reference Form Objects
DSNLess Connections To MySQL
Print Active Form Record
Count Records in Linked Tables
Delete Empty Tables
Open Linked SQL Tables

 

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