Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Extracting File Names from a Path.
Written by Allen Wyatt (last updated June 13, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Barry has a worksheet in which a column contains many file paths. He would like a way to extract just the filename (the part to the right of the final backslash) from each path. He wonders if there is a quick way to do this without using the Text to Columns feature.
There are several different ways, depending on whether you want to use a macro or not.
If your filenames are all the same length, then you can simply use the RIGHT function to pull out the last characters. (This formula assumes the full path and file name is in cell A1.)
=RIGHT(A1,11)
This assumes that the filename is always 11 characters long, such as "text001.txt". If the filename is a different length in each instance, then this approach won't work. Instead, you can try this formula:
=MID(A1,FIND(CHAR(1),SUBSTITUTE(A1,"\",CHAR(1), LEN(A1)-LEN(SUBSTITUTE(A1,"\",""))))+1,LEN(A1))
Note that the formula uses the SUBSTITUTE function twice. In each case it replaces the backslashes (\) with something else. The first time it replaces all of them with an ASCII value of 1 and the second time it replaces them with nothing (an empty string) so that it can determine how many backslashes were in the original path. The MID function is used to locate (with the help of FIND and the SUBSTITUTE functions) the location of the last backslash in the path and return everything after that point.
A shorter formula can be used if you are sure that the filename will never be more than 99 characters long:
=TRIM(RIGHT(SUBSTITUTE(A2,"\",REPT(" ",100)),99))
This formula replaces all the backslashes with 100 spaces, grabs the right-most 99 characters from the resulting string (that would be the filename with a bunch of spaces in front of it) and then trims off all the spaces.
If you want to use a macro you can create a very short function that will pull apart a string (the full path, in this case) based upon delimiters:
Function GetFileName(File_Path) As String Dim Parts Parts = Split(File_Path, Application.PathSeparator) GetFileName = Parts(UBound(Parts)) End Function
Told you it was short! The function that does the heavy work is the Split function which pulls a string apart based upon a delimiter you specify and stuffs the parts into an array. In this example the Split function uses as a delimiter whatever path separator is appropriate for the system on which Excel is running.
The last element of the resulting array (determined with the UBound function) contains the portion of the original path that is to the right of the last path separator—the file name.
You can develop an even shorter function to do the job:
Function GetFileName(File_Path) As String GetFileName=Mid(File_Path,InStrRev(File_Path,"\")+1 End Function
To use either function, put a formula like this in a cell:
=GetFileName(A1)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12903) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Extracting File Names from a Path.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Replacing one character in a text value with another character is easy. All you need to do is use the SUBSTITUTE ...
Discover MoreAutoFill is a great feature. It can detect patterns and adjust cell contents as you drag a selection on-screen. It ...
Discover MoreWhen Excel performs a calculation, the results you see in an unformatted cell may cause a bit of concern. This tip ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-10-16 08:25:01
JC
I recommend investigating the use of FileSystemObject, which can easily parse a fully-qualified filename to provide:
file name
extension
base name
parent folder
absolute path
...and more
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments