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: Getting the Name of the Worksheet Into a Cell.
Written by Allen Wyatt (last updated August 29, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Kevin has a workbook containing 36 worksheets. He needs to have the worksheet name present in a cell of that worksheet. He has created a user-defined function that returns the worksheet name, but it returns the same name on all 36 worksheets—the name of whatever worksheet is displayed when the user-defined function is executed. He wonders if there is a macro, in user-defined function (UDF) form, that he can use that will always return the name of the sheet on which the function is used. In other words, in his 36-worksheet workbook, it should return 36 different results, depending on the worksheet in which it is used.
The short answer is yes, there is a way. In fact, there are a couple of ways. And, interestingly enough, you don't have to use a macro or function if you don't want to. For instance, here is a regular worksheet formula that will work in any cell on the worksheet:
=MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)
The instance of the CELL function in this formula returns the full name of the worksheet, including the filename and file path. The use of the FIND function results in the stripping out of everything except the worksheet name.
Note the use of a cell reference (A1) in each instance of the CELL function. This forces the CELL function to return the name of the worksheet that contains the cell reference. Without it, you will get the same result (the first worksheet) for each instance of the formula.
You should also know that the formula will not return valid results if you use it in a new workbook—one that hasn't been saved. You need to save the workbook so it actually has a name that can be returned by the CELL function successfully. It also will not work properly if the workbook or worksheet name contains a right bracket character ("]"). In that case, you'll want to use one of the other solutions discussed in this tip.
If you prefer to use a user-defined function, you can try something simple, like this function:
Function TabName1() As String Application.Volatile TabName1 = ActiveSheet.Name End Function
This function won't provide the desired outcome, however, because it always returns the name of the active worksheet. That means that if you have the function called on each of the sheets in your workbook, it will always return the name of the active sheet on each of those worksheets, instead of the name of the sheet on which the function is used. The following function provides better results:
Function TabName2() As String Application.Volatile TabName2 = Application.Caller.Parent.Name End Function
If you think you'll want to use the function to refer to a worksheet name elsewhere in the workbook, then this function will work better for you:
Function TabName3(cell As Range) TabName3 = cell.Worksheet.Name End Function
This version of the function requires that you provide a cell reference—any cell reference—to a cell on the worksheet whose name you want to use.
Of course, if you would rather not use a user-defined function, you could simply create a macro that would stuff the name of each worksheet tab into the same cell in each worksheet. For instance, the following macro steps through each of the worksheets in the workbook and places the name of each worksheet into cell A1.
Sub TabName4() For J = 1 To ActiveWorkbook.Sheets.Count Sheets(J).Cells(1, 1).Value = Sheets(J).Name Next End Sub
You should note that this approach is not dynamic (it needs to be rerun each time you change worksheet names or add new worksheets). It also overwrites anything that is in cell A1. (If you want the worksheet names placed in a different cell on each worksheet, change the values used in the Cells collection.)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11419) 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: Getting the Name of the Worksheet Into a Cell.
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!
By default, a new Excel workbook contains three blank worksheets. You can (and should) configure Excel to whatever number ...
Discover MoreExcel provides a little-known way to copy worksheets simply by clicking and dragging. Here's how to do it.
Discover MoreYou can hide a bunch of worksheets at the same time, but Excel makes it much more difficult (depending on your version of ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-03-29 15:16:15
Notnice Nomore
So you (Microsoft) can give me (us) the number of the Sheet but not the name. And you think you deserve to be $billionaires? If humans had any real brains left, you would be tarred and feathered for your pathetic APPs. It really is mind boggling.
btw (re: not a bot test) 6-3 used to be 3 but according to HARVARD now it may or may not be. So when I tell you that humans have lost their brains, beleive it.
2021-01-12 10:35:10
J. Woolley
According to Microsoft re. CELL("filename",...), "This value is not supported in Excel for the web, Excel Mobile, and Excel Starter."
2021-01-11 18:33:15
Ethan
Hello, I'm using the formula =MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255) and it works! Thank you. However, when I upload the excel spreadsheet to our office365 sharepoint site, and then open inside of a web browser, that field shows a "VALUE" error message.
Of course, I could always "open in excel" but I'm trying to create a simple shared document with others in my office and would like it to display the sheet name while being access inside of the web browser.
Any ideas?
Thanks!
Ethan
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