Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Extracting File Names from a Path

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.

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.

Related Tips:

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

Michael (Micky) Avidan    03 Oct 2015, 05:46
@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
Michael (Micky) Avidan    03 Oct 2015, 05:26
@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
Michael (Micky) Avidan    03 Oct 2015, 05:21
@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
Mike    02 Oct 2015, 15:32
Great article, Allen. What if I wanted to extract everything EXCEPT the filename (everything before the last backslash in a UNC path)?
Christiaan Hoek    20 Jun 2014, 07:24
Fixed it! (pretty silly mistake really...)

[php]
Function SplitPath(FilePath, ArrayNr) As String
    Dim Parts
    Parts = Split(FilePath, "/")
    SplitPath = Parts(ArrayNr)
End Function
[/php]
Christiaan Hoek    20 Jun 2014, 07:10
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!
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.