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: Determining a Worksheet's Number.
Written by Allen Wyatt (last updated April 6, 2019)
This tip applies to Excel 97, 2000, 2002, and 2003
Lawrence needs a way to determine the number of a worksheet even if the worksheet has been renamed. For instance, if a worksheet is named Sheet11 it is easy enough to figure out that it is sheet 11. If he renames the sheet to January, Lawrence still needs a way to know this is sheet 11.
The solution to this problem is best done with a user-defined function (a macro). There are, in reality, two numbers that the macro could return for each worksheet. The first is the index number for the worksheet. This number represents the index of the worksheet's Worksheet object within the Worksheets collection. This value can be returned by a macro similar to the following:
Function SheetNumber1(shtname As String) Dim sht As Worksheet Application.Volatile For Each sht In ThisWorkbook.Worksheets If LCase(sht.Name) = LCase(shtname) Then SheetNumber1 = sht.Index Exit Function End If Next SheetNumber1 = -1 End Function
This function, when used in a worksheet, will return the index number of any worksheet whose name is passed to the function. If the name that is passed to the function doesn't exist in the worksheets collection, then a value of -1 is returned by the function. For instance, the following used in a cell would return the index value for the worksheet named "January" within the collection:
=SheetNumber("January")
The problem with this approach is that the order of Worksheet objects in the Worksheets collection can change over time. Thus, you can't always assume that the eleventh sheet in the collection is the sheet that was originally Sheet11.
A more consistent way of figuring out the original name for a worksheet (regardless of how it is renamed) is to use what Visual Basic refers to as the sheet's "CodeName." This is a property of the worksheet and can be determined in the following manner:
Function SheetNumber2(shtname As String) Dim sht As Worksheet Dim sTemp As String Application.Volatile For Each sht In ThisWorkbook.Worksheets If LCase(sht.Name) = LCase(shtname) Then sTemp = sht.CodeName SheetNumber2 = Val(Mid(sTemp, 6, 4)) Exit Function End If Next SheetNumber2 = -1 End Function
The CodeName property is read-only in a macro. It is assigned at the time that the worksheet is created, but it is possible for it to be manually changed within the Visual Basic editor. The CodeName is always a string, representing the very first name that was applied to the worksheet, so it will be something like "Sheet11". Once the CodeName is set, even if the worksheet is renamed (such as to "January"), it will remain stable ("Sheet11").
In the macro example (SheetNumber2) the CodeName property is assigned to the sTemp variable. This will, most of the time, be something like "Sheet3" or "Sheet11". So, the macro then grabs the numeric value of whatever begins with the sixth character (right after "Sheet"). This is the value that is returned by the function.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3398) 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: Determining a Worksheet's Number.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Excel allows you to "freeze" rows in your worksheet. What if you want the rows that are frozen to change as you scroll ...
Discover MoreYour workbooks can contain many, many worksheets. Which of those worksheets are the largest, however? Here's some ideas ...
Discover MoreWhen processing workbook information in a macro, you may need to step through each worksheet to make some sort of ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
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