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: Creating and Naming a Worksheet Using a Macro.

Creating and Naming a Worksheet Using a Macro

Written by Allen Wyatt (last updated August 31, 2019)
This tip applies to Excel 97, 2000, 2002, and 2003


2

Jeff would like to create a copy of his "master" worksheet, prompt for a name of the new worksheet, and move it to the end of the worksheet tabs, all from within a macro. He tried to record a macro to do this, but it didn't work.

The fact that the recorded macro didn't work isn't terribly surprising. When you record a macro, you tell Excel to record the steps you take. Those steps (in this instance) included the naming of the worksheet, so that name was recorded in the macro. Try to run the macro a second time, and you will get an error because the worksheet you are trying to create on the second pass was already created on the first.

In this case you have to write a macro manually. You can start with recording the process, and you will get a code like the following:

Sub Macro1()
    Sheets("Master").Select
    Sheets("Master").Copy After:=Sheets(3)
    Sheets("Master (2)").Select
    Sheets("Master (2)").Name = "NewMaster"
End Sub

Note that the code places the worksheet (after the third sheet) and then always names it the same thing. There's a lot to change here. What you want to do is change it to something like the following:

Sub CopyRename()
    Dim sName As String
    Dim wks As Worksheet
    Worksheets("Master").Copy after:=Sheets(Worksheets.Count)
    Set wks = ActiveSheet
    Do While sName <> wks.Name
        sName = Application.InputBox _
          (Prompt:="Enter new worksheet name")
        On Error Resume Next
        wks.Name = sName
        On Error GoTo 0
    Loop
    Set wks = Nothing
End Sub

This macro will copy the worksheet named "Master" to the end of sheet list (no matter how many sheets you have in the workbook) and continue to prompt for a new worksheet name until a valid name is entered.

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 (3898) 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: Creating and Naming a Worksheet Using a Macro.

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 Part of a Footer Down a Line

Setting up a single footer line for your printouts is fairly easy. If you want to move part of the footer down a line so ...

Discover More

Changing the Percent Symbol

Some symbols can be easily changed in Excel or in Windows, such as the symbols used for currency and to separate ...

Discover More

Forcing Printouts to Black and White

If you want to force Word to print some of its colors in black and white, you may be out of luck. One bright spot, as ...

Discover More

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!

More ExcelTips (menu)

Relative References when Recording Macros

When you record a macro, make sure that you know how Excel is recording your cell movements. This tip explains the ...

Discover More

Using SUM In a Macro

Want to use a worksheet function (such as SUM) from within a macro? Here's how easy it is to accomplish the task.

Discover More

Making Common Functions Available to Others

When you use macros to create functions, you might want to share those functions with others, particularly if they ...

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 six more than 6?

2020-05-21 03:59:25

Willy Vanhaelen

The code produced by the macro recorder is not necessarily the most efficient.
Sheets("Master").Copy after:=Sheets(3) will run correctly whether or not the copied sheet is the active one.
The newly created sheet will by default be the active one.
So in the first macro the fist and third line can be left out:

Sub Macro1()
Sheets("Master").Copy after:=Sheets(3)
Sheets("Master (2)").Name = "NewMaster"
End Sub

The second macro can also by simplified:

Sub CopyRename()
Dim sName As String
Sheets("Master").Copy after:=Sheets(3)
On Error Resume Next
Do
sName = Application.InputBox(Prompt:="Enter new worksheet name")
Sheets("Master (2)").Name = sName
Loop Until ActiveSheet.Name = sName
End Sub


2020-05-20 10:02:46

Racheal M

Thank you so much! I was tasked with reworking an excel model, and I do not know visual basic, but thanks to your explanations i have made a fair attempt.


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.