Gene asked for a way to delete macros from within a macro. He has a large worksheet that uses macros to put together a purchase order. As the last step, the macro deletes the original data that is no longer necessary for the finished purchase order. This pared-down workbook is then saved under a new name. Gene needs the macro, just prior to saving, to delete a macro that is stored in SelectionChange event handler.
There are a couple of ways that this could be handled. One way is to avoid having to do the deletion all together. Instead, have your macro create a new workbook and then transfer, to that workbook, a copy of the data you need. You could then slice and dice the data in the new workbook and save it as your purchase order. The macros in the existing workbook are never copied to the new workbook during the process, so you don't need to worry about deleting them.
Copying all the worksheets in the current workbook to a new workbook is very easy to do. The following macro shows how it is done:
Sub CopyThisWorkbook() Dim CopiedWB As String CopiedWB = "Copy of " & ActiveWorkbook.Name Sheets.Copy ActiveWorkbook.SaveAs Filename:=CopiedWB, _ FileFormat:=xlNormal End Sub
The Copy method, when applied to the Sheets collection, copies all the worksheets in the active workbook to a new workbook and makes the new workbook active. The final command saves the new workbook under a new name.
Of course, if you need some of your macros to be in the new workbook, but not all of them (such as the SelectionChange event handler), then you are probably best to delete what you don't need and simply save under a new name. The following example macro shows how to delete the SelectionChange event handler from the worksheet code for Sheet1.
Sub DeleteProcedure() Dim VBCodeMod As CodeModule Dim StartLine As Long Dim HowManyLines As Long Set VBCodeMod = ThisWorkbook.VBProject.VBComponents("Sheet1").CodeModule With VBCodeMod StartLine = .ProcStartLine("Worksheet_SelectionChange", _ vbext_pk_Proc) HowManyLines = .ProcCountLines("Worksheet_SelectionChange", _ vbext_pk_Proc) .DeleteLines StartLine, HowManyLines End With End Sub
After the macro is completed, the workbook could be saved, and the desired macro won't be in the saved file. This macro is adapted from information provided at Chip Pearson's Web site, which you should reference if you need additional information on this technique:
http://www.cpearson.com/excel/vbe.aspx
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3073) applies to Microsoft Excel 97, 2000, 2002, and 2003.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
Macros are a great way to expand what you can do with the data you place in Excel. You can make those macros even handier ...
Discover MoreMany times you need to select just the visible cells before taking some action. It is helpful to know how to make this ...
Discover MoreIf you use For ... Next loops in your macros, make sure you give a way to jump out of the loop early. That way you can ...
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 © 2025 Sharon Parq Associates, Inc.
Comments