Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Self-Deleting Macros

Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Self-Deleting Macros.

Patrick is writing a macro, and he wants the macro to delete itself after a specific expiration date is reached. There are a couple of ways that this task can be approached. First, you could write a macro that would only function before a specific date, in the following manner:

Sub MyMacro()

    ExpirationDate = #6/1/2013#
    If Now() < ExpirationDate Then

        'Rest of macro goes here

    End if
End Sub

The idea is that if (in this case) the current date is prior to June 1, 2013, then the main body of the macro will execute. If it is June 1 or later, then the macro will not execute. This approach, of course, does not actually delete the macro; it simply checks to see that the macro is being executed before a certain date.

To actually get rid of the macro code, you need to take a different approach:

Private Sub Workbook_Open()
    Dim VBComp As VBIDE.VBComponent
    Dim VBComps As VBIDE.VBComponents

    'Delete if Past Date
    If Date >= #6/1/2013# Then
        Set VBComps = ActiveWorkbook.VBProject.VBComponents

        For Each VBComp In VBComps
            Select Case VBComp.Type
                Case vbext_ct_StdModule, vbext_ct_MSForm, _
                  vbext_ct_ClassModule
                    VBComps.Remove VBComp
                Case Else
                    With VBComp.CodeModule
                        .DeleteLines 1, .CountOfLines
                    End With
            End Select
        Next VBComp
    End If

    Set VBComps = Nothing
    Set VBComp = Nothing
End Sub

This code was adapted from a macro originally written by Chip Pearson, available on his site at the following address:

http://www.cpearson.com/excel/vbe.aspx

To make the macro work, you'll need to make sure that there is a reference to Microsoft Visual Basic for Applications Extensibility. (You do this by choosing, in the VB Editor, Tools | References and then choosing Microsoft Visual Basic for Applications Extensibility in the available references.)

The macro runs when the workbook is opened, and if the date is greater than or equal to June 1, 2013, then each component of the VBProject is deleted. This means that the macro is very powerful, because it deletes everything, not just a single procedure or module.

There are a couple of things to keep in mind with this macro, of course. First, if the user chooses to not enable macros when the workbook is opened, then this code will never run and the macro won't be deleted. Second, deleting macros in this way obviously introduces changes to the workbook. That means that when the workbook is closed, the user will be asked if they want to save their changes. If they choose not to, then the deletions will not be saved and the macro will again run the next time the workbook is opened.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3123) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Self-Deleting Macros.

Related Tips:

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

John    02 Aug 2013, 07:35
I don't know why it's not working although I followed the whole instruction
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.