Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Extracting File Names from a Path.
Written by Allen Wyatt (last updated September 30, 2023)
This tip applies to Excel 97, 2000, 2002, and 2003
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 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 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 one that steps backward through the path until it locates the last backslash. It then returns everything after the backslash. The following example starts in cell B1, examining everything to the right of the cell (cell A1) and then starts pulling out file names. It steps through all the cells in column A and puts the file name, if any, in column B.
Sub GetFileName1() Dim Delimiter As String Dim Target As String Dim sFile As String Dim J As Integer Dim iDataLen As Integer Delimiter = "\" Range("B1").Select Do While ActiveCell.Offset(0, -1).Value <> "" Target = ActiveCell.Offset(0, -1).Value iDataLen = Len(Target) sFile = "Delimiter Not Found" For J = iDataLen To 2 Step -1 If Mid(Target, J, 1) = Delimiter Then sFile = Right(Target, iDataLen - J) Exit For End If Next J ActiveCell.Formula = sFile ActiveCell.Offset(1, 0).Select Loop End Sub
You could also use a much shorter version of a macro, provided you can use the Split function. This function was introduced in the version of VBA provided with Excel 2000, and it will pull a string apart based upon a delimiter you specify and stuff the parts into an array. This example shows the solution implemented as a user-defined function.
Function GetFileName2(File_Path) As String Dim Parts Parts = Split(File_Path, Application.PathSeparator) GetFileName2 = Parts(UBound(Parts)) End Function
In this usage 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. To use the function, put a formula like this in a cell:
=GetFileName2(A1)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7333) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Extracting File Names from a Path.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
Tracking down a problem that occurs with a single workbook can be vexing. One such problem occurred with Chris, and these ...
Discover MoreDoes your macro need to add information to the end of a text file? This is called appending, and is done using the ...
Discover MoreNot all data is created in Excel. Indeed, you may have data in files created by many other types of programs. You might ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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