Renaming Worksheets Based On a List

Written by Allen Wyatt (last updated April 22, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


Gilbert has a worksheet (named "Control") that contains a list of desired worksheet names in cells A1:A12. He needs a way, in a macro, to rename each of the other 12 worksheets in the workbook based upon that range of cells. The worksheet names don't need to be dynamic; they just need to be renamed when he runs the macro.

The core of developing a macro to address this need is to rely on the Name property of each worksheet you want to rename. For instance, you could use a very simple macro like this:

Sub RenameSheets()
    Dim c As Range
    Dim J As Integer

    J = 0
    For Each c In Range("A1:A12")
        J = J + 1
        If Sheets(J).Name = "Control" Then J = J + 1
        Sheets(J).Name = c.Text
    Next c
End Sub

The macro simply steps through the cell range A1:A12 and, if the next worksheet isn't named "Control," it renames the worksheet to the cell value.

As noted, this macro is very simplistic and should, in all likelihood, be a lot more robust. For instance, what should be done if there are more (or fewer) than 13 worksheets in the current workbook? What should be done if there are empty cells in the range A1:A12? What should be done if someone runs the macro and "Control" isn't the active worksheet? What should be done if there are two identical values in A1:A12? What if there are leading or trailing spaces on one or more names in the range A1:A12? These and (most likely) a whole range of other questions can affect how the macro finally looks. Here's a commented version of the macro that takes into account several of the possibilities just mentioned:

Sub RenameSheets()
    Dim c As Range
    Dim J As Integer
    Dim K As Integer
    Dim sName As String
    Dim w(12) As String
    Dim bGo As Boolean
    Dim sTemp As String

    bGo = True
    If Worksheets.Count <> 13 Then
        ' Check to make sure exactly 13 worksheets in workbook
        bGo = False
        sTemp = "There are more than 13 worksheets."
    End If
    If ActiveSheet.Name <> "Control" Then
        ' Check to make sure Control is active
        bGo = False
        sTemp = "Control worksheet is not active."
    Else
        ' Check for empty and duplicate cells in range
        J = 0
        For Each c In Range("A1:A12")
            sName = Trim(c.Text)
            If sName <> "" Then
                For K = 1 to J
                    If LCase(w(K)) = LCase(sName) Then
                        bGo = False
                        sTemp = "Duplicate sheet names in list."
                    End If
                Next K
                If bGo Then
                    ' Everything still good; add name
                    J = J + 1
                    w(J) = sName
                End If
            End If
        Next c
    End If

    If bGo Then
        K = 0
        For J = 1 To 12
            K = K + 1
            If Sheets(K).Name = "Control" Then K = K + 1
            Sheets(K).Name = w(J)
        Next J
    Else
        MsgBox(sTemp)
    End If
End Sub

Notice how much longer the second version of the macro is than the first? Anytime you start adding multiple checks in a macro, it can really make it much longer than without the checks. The benefit in adding the checks, of course, is that your macro is less likely to run into problems as it is used by people other than you.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (1506) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.

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

Determining a Paragraph's Style in VBA

When processing a document via a macro, it is often helpful to understand what style has been applied to a paragraph. You ...

Discover More

Finding an Unknown Character

Sometimes the characters that appear in a document can be hard to figure out, especially if the document came from ...

Discover More

Controlling Sorting Order

When you sort information either in a table or the body of you document, Word follows a very specific set of rules to do ...

Discover More

Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!

More ExcelTips (ribbon)

Summing Only Visible Values

When you use SUM to determine the total of a range of values, Excel doesn't really pay attention to whether the values ...

Discover More

Expiration Date for Excel Programs

If you use Excel to create a macro-based application, you may want to make sure that your programs cease working after a ...

Discover More

Resizing Checkboxes

If you create a user form in VBA that includes checkboxes, you may want to make the checkboxes larger. You can't adjust ...

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 3 + 9?

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 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.

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.