Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Copying Worksheet Code Automatically.

Copying Worksheet Code Automatically

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


Tim correctly notes that a user can right-click on a worksheet tab, then select View Code to open a VBA code sheet for the worksheet. He has code written that automatically manipulates cells, columns, and rows. This code needs to be available on every worksheet in a workbook, even if the user adds new worksheets. Tim wonders if there is a way, using VBA, to have the code of one worksheet automatically copied to a new worksheet in the workbook.

There are a few ways you can approach this problem. One way—and perhaps the simplest way—is to remove the macros from the worksheet's code sheet and move them to the ThisWorkbook module. The worksheet's code sheet is what you see when you right-click a worksheet tab. Code in that sheet is intended to handle events that occur in the worksheet and only in that worksheet. If you move the code to the ThisWorkbook module, then events can still be handled, but those events apply to all worksheets in the workbook.

For instance, when you right-click on a worksheet tab and look at the code window, you are initially working in the Worksheet_SelectionChange event. If you wanted to move this code to the ThisWorkbook module, you could place it within the Workbook_SheetSelectionChange event.

If such a "level change" of your code won't work for some reason, then another approach is to create a template worksheet within the workbook. Give it a name such as "MyMaster," and make sure it includes all the code that you want to add to your newly created worksheets. You can even hide this worksheet, if desired, so it doesn't distract the users. Then, place the following macro into the ThisWorkbook module:

Private Sub Workbook_NewSheet(ByVal Sh As Object)
    Dim tmpName As String

    tmpName = Sh.Name
    Sheets("MyMaster").Copy Before:=Sheets(Sh.Name)
    Application.DisplayAlerts = False
    Sheets(Sh.Name).Delete
    Application.DisplayAlerts = True
    Sheets("MyMaster (2)").Name = tmpName
End Sub

This code is triggered every time a new worksheet is added to the workbook. It looks at the name of the newly added worksheet (which will be something like "Sheet4") and saves that name in a temporary variable. The code then copies the MyMaster worksheet to the workbook (which also copies the macros in the worksheet), deletes the worksheet that was originally created, and then renames the new MyMaster copy to have the same name as the original worksheet.

If the master worksheet ("MyMaster") is hidden, then the worksheet created by the macro will also be hidden. In that case, you simply need to add a single line to the macro, right before the End Sub statement:

Sheets(tmpName).Visible = xlSheetVisible

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 (7884) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Copying Worksheet Code Automatically.

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

Protecting Custom Shortcut Keys

If you spend time creating a rich set of custom shortcut keys, it can be rather frustrating if they suddenly disappear. ...

Discover More

Quickly Adding Formulas Referencing Multiple Worksheets

When you need to pull information from a lot of different worksheets into a single worksheet, it can be baffling to ...

Discover More

Blank Page Printing after Table at End of Document

When you print, do you get an extra blank page printed at the end of the document? It could be because of the final ...

Discover More

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!

More ExcelTips (ribbon)

Storing Macros in Templates

How Excel uses templates is different than how Word uses templates. This tip looks at those differences and discusses ...

Discover More

Sharing Macros with Others

If you develop some handy macros that you use on your system, you may want to share those macros with others. This tip ...

Discover More

E-mailing PDF Reports Results in Consistent Crash

It is possible to create macros that send out reports, via e-mail, from within Excel. Frank did this and ran into ...

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 one more than 4?

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.