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: Getting the Name of the Worksheet Into a Cell.

Getting the Name of the Worksheet Into a Cell

Written by Allen Wyatt (last updated November 23, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003


Kevin has a workbook containing 36 worksheets. He needs a way, in each of the worksheets, to have the worksheet name (from the worksheet's tab) 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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3793) 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: Getting the Name of the Worksheet Into a Cell.

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

Moving Macros from the Personal Workbook

Need to move a macro out of your Personal.xls workbook and into a regular workbook? You can do it using familiar editing ...

Discover More

Printing a Font List

Getting a list of fonts available in a document is not something you can easily do in Word. That is, unless you put the ...

Discover More

Monday's Date on Friday's Report

Automatically putting today's date at the top of a report is easy. Putting a different date, automatically, can be more ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (menu)

Sheets for Days

Need a quick way to have a worksheet for each day in a month? Here's a macro that makes the worksheet creation a snap.

Discover More

Picking Worksheets Quickly

If your workbook contains a multitude of worksheets, the worksheet tabs at the bottom of the program window start to ...

Discover More

Dynamic Worksheet Tab Names

Need a worksheet's name to change based on the contents of a cell? You'll need to rely on a macro to do the changing, but ...

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

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}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. 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 2 + 2?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

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.