VBA Function To Determine If An Excel File Name Is Valid
What This VBA Macro Code Does
I’ve written a few macros over the past few days that have required the user to submit a name for a newly saved Excel file. If you’ve tried saving files with certain special characters, you know that you can get rejected if you don’t provide a name within the range of allowed characters. Below are a few different ways you can use VBA functions to test if a given string is in compliance with a compatible file name for Excel.
[1] Create A Test Workbook
The concept behind this method is to create a temporary Excel file with your desired file name to see if it errors out. If it does error out, you know that the file name is invalid. At the end of the routine, the temporary Excel file is deleted from your computer like nothing ever happened.
Function ValidFileName(FileName As String) As Boolean
'PURPOSE: Determine If A Given Excel File Name Is Valid
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
Dim wb As Workbook
'Create a Temporary XLS file
On Error GoTo InvalidFileName
Set wb = Workbooks.Add
wb.SaveAs Environ("TEMP") & "\" & FileName & ".xls", xlExcel8
On Error Resume Next
'Close Temporary Workbook file
wb.Close (False)
'Delete Temporary File
Kill Environ("TEMP") & "\" & FileName & ".xls"
'File Name is Valid!
ValidFileName = True
Exit Function
'ERROR HANDLERS
InvalidFileName:
'Close Temporary Workbook file
wb.Close (False)
'File Name is Invalid
ValidFileName = False
End Function
[2] Search for Invalid Characters via A Loop
This code was submitted by Jon Peltier in the comments section and I loved the approach. Essentially he is listing out all the characters that are not allowed in an Excel file name and tests each “invalid character” to see if it’s in the submitted file name.
Function ValidFileName(FileName As String) As Boolean
'PURPOSE: Determine If A Given Excel File Name Is Valid
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
'AUTHOR: Jon Peltier
Const sBadChar As String = "\/:*?<>|[]"""
Dim i As Long
'Assume valid unless it isn't
ValidFileName = True
'Loop through each "Bad Character" and test for an instance
For i = 1 To Len(sBadChar)
If InStr(FileName, Mid$(sBadChar, i, 1)) > 0 Then
ValidFileName = False 'Invalid
Exit For
End If
Next
End Function
[3] Search for Invalid Characters via Regular Expression
Bhavik Khatri proposed an idea in the comments section to use a Regular Expression rule to test the file name for invalid characters in one fell swoop.
Function ValidFileName(FileName As String) As Boolean
'PURPOSE: Determine If A Given Excel File Name Is Valid
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
With CreateObject("VBScript.RegExp")
.Pattern = "[\\/:\*\?""<>\|\[\]]"
ValidFileName = Not .Test(FileName)
End With
End Function
Let’s Test It Out!
Below is a simple macro that should give you an idea of how to use the above validation function for a given filename.
Sub TestFunction()
'PURPOSE: Test the ValidFileName function
If ValidFileName("[My] Workbook") = True Then
MsgBox "The file name provide is a valid name for an Excel file"
Else
MsgBox "The file name provide is NOT a valid name for an Excel file"
End If
End Sub
Using VBA Code Found On The Internet
Now that you’ve found some VBA code that could potentially solve your Excel automation problem, what do you do with it? If you don’t necessarily want to learn how to code VBA and are just looking for the fastest way to implement this code into your spreadsheet, I wrote an article (with video) that explains how to get the VBA code you’ve found running on your spreadsheet.
Getting Started Automating Excel
Are you new to VBA and not sure where to begin? Check out my quickstart guide to learning VBA. This article won’t overwhelm you with fancy coding jargon, as it provides you with a simplistic and straightforward approach to the basic things I wish I knew when trying to teach myself how to automate tasks in Excel with VBA Macros.
Also, if you haven’t checked out Excel’s latest automation feature called Power Query, I have put together a beginner’s guide for automating with Excel’s Power Query feature as well! This little-known built-in Excel feature allows you to merge and clean data automatically with little to no coding!
How Do I Modify This To Fit My Specific Needs?
Chances are this post did not give you the exact answer you were looking for. We all have different situations and it’s impossible to account for every particular need one might have. That’s why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to get quick answers to complex problems in Excel, PowerPoint, VBA, you name it!
I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee that 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don’t have time to fit everyone’s questions in (there never seem to be quite enough hours in the day!).
I wish you the best of luck and I hope this tutorial gets you heading in the right direction!
After 10+ years of creating macros and developing add-ins, I've compiled all the hacks I wish I had known years ago!

Keep Learning
Chris Newman
Chris is a finance professional and Excel MVP recognized by Microsoft since 2016. With his expertise, he founded TheSpreadsheetGuru blog to help fellow Excel users, where he shares his vast creative solutions & expertise. In addition, he has developed over 7 widely-used Excel Add-ins that have been embraced by individuals and companies worldwide.