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.
Written by Allen Wyatt (last updated January 10, 2026)
This tip applies to Excel 97, 2000, 2002, and 2003
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:
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.
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!
Excel allows you to hide worksheets so that they aren't visible to those using your workbook. Hiding worksheets has a ...
Discover MoreWhen writing a macro, you may want to fill a range of cells with different values. The easiest way to do this is to use ...
Discover MoreThe security features built into Excel 2002 and 2003 allow you to digitally sign your macros so that users can rest ...
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 © 2026 Sharon Parq Associates, Inc.
Comments