Written by Allen Wyatt (last updated May 28, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
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 (11929) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Creating and Naming a Worksheet Using a Macro.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
When creating a workbook that will be used by others, you may wish to ensure that the user fills in some cells before ...
Discover MoreYou may need to automatically generate unique numbers when you create new worksheets in a workbook. Here are a couple of ...
Discover MoreThe personal macro workbook is a great place to save your macros that you want to use with any workbook. The personal ...
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 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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments