Written by Allen Wyatt (last updated August 1, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
Peter regularly needs to copy a master worksheet to a copy in a new workbook. He can do this just fine with VBA. However, the worksheet that he's copying has code associated with it, and the code gets copied too. Peter doesn't want the code in the copy, but he does want it left in the original. He wonders if there is a way, in his macro, to delete the worksheet code in the just-copied worksheet.
How you go about this depends on how you want the finished workbook (the one to which you are copying) to look. Primarily, will the finished workbook contain macros—any macros—or not? If the answer is no, it won't contain any macros, then you can easily accomplish the task by saving the new workbook in XLSX format. That way Excel takes care of getting rid of all the macros for you. You can do this by including a line in your code similar to the following when you save your workbook:
ActiveWorkbook.SaveAs FileName:="MyExcelFile.xlsx", _ FileFormat:=xlOpenXMLWorkbook
If, however, you only want to get rid of the worksheet code but save the new workbook with any other macro code intact, then you'll need to take a different approach. In this instance, you could include the following line in your macro:
ActiveWorkbook.VBProject.VBComponents("Sheet1")
This assumes that the new workbook is the active workbook, and that the worksheet whose code you want to delete is named Sheet1. You could also use these lines to accomplish the same task:
wsName = ActiveSheet.CodeName With ThisWorkbook.VBProject.VBComponents(wsName).CodeModule .DeleteLines 1, .CountOfLines End With
Note that wsName should be declared as a string variable.
For a boatload of other ways you can affect different code modules programmatically, you can't go wrong by referring to Chip Pearson's excellent information here:
http://cpearson.com/excel/vbe.aspx
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7612) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021.
Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!
When 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 MoreWhen you need to get rid of characters in the middle of a cell value, the best way to do it is through the use of macros. ...
Discover MoreMacros depend on the use of variables to do their work. This tip examines how variables are declared in a macro, using ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-08-01 07:20:29
Peter
Thanks for your help. It ran smoothly and did exactly what I wanted. The copy of the spreadsheet then saved as an .xlsx
The only significant change I made was to replace ThisWorkbook with ActiveWorkbook:
With ActiveWorkbook.VBProject.VBComponents(ActiveSheet.CodeName).CodeModule
.DeleteLines 1, .CountOfLines
End With
Otherwise it would have deleted code in my source spreadsheet where the code was running.
I also found it caused an error if the code window that was to be cleared was open in the VBA editor.
Thanks again, Peter
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