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.

Extracting File Names from a Path

by Allen Wyatt
(last updated February 8, 2014)

6

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)

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Creating a String

Need to use a macro to create a text string? One easy way to do it is to use the String function, described in this tip.

Discover More

Selecting Formulas

Want to select only the formulas in your worksheet? It's easy to do using the Go To Special dialog box.

Discover More

Preventing Changes to Formatting and Page Size

When you create workbooks for others to use, you might want to make sure that they can't change the formatting and paper size ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

MORE EXCELTIPS (MENU)

Saving All Open Workbooks

Wouldn't it be nice to have a single command that would save each of you open workbooks, all at once? It's easy to do with ...

Discover More

Stopping Date Parsing when Opening a CSV File

Excel tries to make sense out of any data that you import from a non-Excel file. Sometimes this can have unwanted results. ...

Discover More

Getting Rid of Extra Quote Marks in Exported Text Files

If you don't like the way that Excel exports information you intend to use with other programs, then your best bet is to ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments for this tip:

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is eight more than 7?

2015-10-03 05:46:13

Michael (Micky) Avidan

@Mike,
Better late than never - try this:

=LEFT(A2,FIND("|",SUBSTITUTE(A2,"","|",LEN(A2)-LEN(SUBSTITUTE(A2,"",)))))
----------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2015-10-03 05:26:33

Michael (Micky) Avidan

@Mike,
The following proposed formula does not comply with your request.

=MID(CELL("filename"),1,FIND("[",CELL("filename"))-1)
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2015-10-03 05:21:05

Michael (Micky) Avidan

@Mike,
Check out the two proposed formulas:

=SUBSTITUTE(A2,TRIM(RIGHT(SUBSTITUTE(A2,"",REPT(" ",100)),99)),)

=MID(CELL("filename"),1,FIND("[",CELL("filename"))-1)
-----------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2015-10-02 15:32:53

Mike

Great article, Allen. What if I wanted to extract everything EXCEPT the filename (everything before the last backslash in a UNC path)?


2014-06-20 07:24:56

Christiaan Hoek

Fixed it! (pretty silly mistake really...)

[php]
Function SplitPath(FilePath, ArrayNr) As String
Dim Parts
Parts = Split(FilePath, "/")
SplitPath = Parts(ArrayNr)
End Function
[/php]


2014-06-20 07:10:42

Christiaan Hoek

I tried to change the function so I can choose which part of the array I want returned to the cell, but I can't get it to work. Can you maybe help me spot my error? Here's my code:

[code]Function SplitPath(FilePath, ArrayNr) As String
Dim Parts
Parts = Split(FilePath, "/")
SplitPath = Parts(UBound(Parts, ArrayNr))
End Function[/code]

Thanks!


Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.

Links and Sharing
Share