Deleting Macros from within a Macro

by Allen Wyatt
(last updated February 23, 2013)

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

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3073) applies to Microsoft Excel 97, 2000, 2002, and 2003.

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

Naming Tabs for Weeks

Need to set up a workbook that includes a worksheet for each week of the year? Here's a couple of quick macros that can do ...

Discover More

Turning Off Sharing

All good things must come to an end at some point. When you are done sharing your workbook with others, this is how you can ...

Discover More

Controlling How Documents Stack when Opened

When you open multiple documents, Windows cascades the document windows on your desktop. If you want the windows to be ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

MORE EXCELTIPS (MENU)

Retrieving Drive Statistics

Need to gather some information about the drives on a system? It can be pretty easy to do using a macro, as shown in this ...

Discover More

Switching Windows in a Macro

When you have multiple workbooks open at the same time, Excel allows you to easily switch between those workbooks. How you do ...

Discover More

Continuing Macro Lines

Sometimes a macro command line can get very, very long. This can make it hard to understand when you look at it a month or so ...

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 for this tip:

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 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.

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.

Links and Sharing
Share