Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Finding the Parent Folder.
Written by Allen Wyatt (last updated November 12, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Lawrence asked if there was a way to devise a formula that would return the name of the parent folder for the current workbook file. He wanted this to return just the folder name, and he wanted it to be derived using a regular Excel formula, not a macro or user-defined function.
The answer is, yes, it is possible to figure out the parent folder using a formula, but the formula is rather long and complicated. There were several examples of formulas submitted by readers; the following formula is the most concise:
=MID(CELL("filename"), FIND(CHAR(1), SUBSTITUTE(CELL("filename"), "\", CHAR(1), LEN(CELL("filename")) - LEN(SUBSTITUTE(CELL("filename"), "\", "")) - 1)) + 1, FIND("[", CELL("filename")) - 2 - FIND(CHAR(1), SUBSTITUTE(CELL("filename"), "\", CHAR(1), LEN(CELL("filename")) - LEN(SUBSTITUTE(CELL("filename"), "\", "")) - 1)))
Please note that this is a real formula; it must appear on a single line in a cell. It relies on the CELL function with the "filename" parameter, which returns the entire path and filename for the current workbook.
The formula works by using the number of backslashes in the complete file path, and then replacing the second to the last slash with an ASCII value of 1. This value is then used as a "positioning aid" to help extract the parent folder's name.
If you are using the version of Excel provided with Microsoft 365, you can use a much shorter formula that utilizes a couple of the new text-related functions:
=TEXTAFTER(TEXTBEFORE(CELL("filename"),"\",-1),"\",-1)
In this usage, the TEXTBEFORE function returns everything to the left of the final backslash and the TEXTAFTER function returns everything in that text after the final remaining backslash. It returns the exact same parent folder name as is done by the earlier, longer formula.
Finally, you should note that regardless of the formula you use, you will get a #VALUE error until you save the workbook in which the formula is contained. Until that point, there is no path to analyze, so the various functions in the formula return a #VALUE error.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12084) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Finding the Parent Folder.
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!
Excel provides a quick way to access the workbooks you've most recently worked on. This tip addresses how to display a ...
Discover MoreYou can use a macro to read information from a text file. The steps are easy, and then you can use that information in ...
Discover MoreExcel tries to make sense out of any data that you import from a non-Excel file. Sometimes this can have unwanted ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-11-19 04:19:27
Ian Hills
I think it is best to agree to disagree at this point.
I am happy for you to use a difficult method to solve an easy problem if that is your thing. My thing is to make things easier if I can.
So perhaps it's just that we have different goals. I am focusing on using Excel to work on other things, so I am looking for quick and easy solutions. I'm assuming that you are more interested in Excel as a puzzle to solve in its own right and so less interested in the practicalities. More power to you. I like puzzles too.
2022-11-18 09:35:17
J. Woolley
@Ian Hills
The first sentence of the article is "Lawrence asked if there was a way to devise a formula that would return the name of the parent folder for the current workbook file."
2022-11-18 05:04:04
Ian Hills
@philip the title of the article is Finding the Parent Folder. 'Finding the folder' not 'finding a formula.' I think my way is an easier, more direct way of finding the folder.
2022-11-17 08:44:48
J. Woolley
Notice CELL("filename") does not always update when switching between multiple open workbooks. Press F9 to update.
2022-11-16 13:02:57
Mike J
In excel 2010, with two saved files and one unsaved file, each containing this formula and visible, the formula will report the folder of the active workbook in all three windows (or #VALUE if the unsaved workbook is selected) see attached. If however the three files are in separate instances of excel, the formula works as described, so probably fine in later versions - possibly the CELL() function is Instance specific and not File specific.
(see Figure 1 below)
(see Figure 2 below)
(see Figure 3 below)
Figure 1. Saved TestFile 1
Figure 2. Saved TestFile 2
Figure 3. Unsaved File Book2
2022-11-14 09:56:07
J. Woolley
My Excel Toolbox includes the following function to return the substring of Text between two substrings BeginAfter and EndBefore:
=Between(Text,BeginAfter,EndBefore,[CaseSensitive],[Direction])
If Direction is -1, the search is right-to-left for both BeginAfter and EndBefore; therefore, this formula returns the workbook's parent folder:
=Between(CELL("filename"),"\","\[",,-1)
My Excel Toolbox includes two more functions that are useful for this subject:
=FindRev(FindText,WithinText,[StartNum],[CaseSensitive])
=NameOf([This],[Target])
FindRev searches in reverse (right-to-left) to return the location of FindText in WithinText. (See Excel's FIND and VBA's InStrRev functions.)
NameOf is described in the following two articles:
https://excelribbon.tips.net/T007850#comment-form-hd
https://wellsr.com/vba/2019/excel/vba-udf-to-enhance-excel-cell-and-info-functions/
NameOf("path") returns the path of the formula cell's workbook; therefore, this formula returns the workbook's parent folder:
=MID(NameOf("path"),FindRev("\",NameOf("path"))+1,999)
Excel 365 and 2021+ include the LET function; here are two formulas using LET:
=LET(P,NameOf("path"),MID(P,FindRev("\",P)+1,999))
=LET(P,NameOf("path"),RIGHT(P,LEN(P)-FindRev("\",P)))
Notice CELL("filename") does not always update when switching between two open workbooks. (Press F9 to update.) NameOf is Volatile, so that is not a problem.
See https://sites.google.com/view/MyExcelToolbox
2022-11-14 01:47:47
Philip
@Ian, the question to which this tip responds, is "finding a formula" that does this ...
2022-11-12 08:40:54
Ian Hills
If you mean what I think you mean, this can also be achieved by right-clicking on the file's title. This results in a dropdown that lists the file path of the file.
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