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.
Written by Allen Wyatt (last updated March 14, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003
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.
Note:
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.
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!
When creating macros, you can use the ColorIndex and Color properties to set or determine the colors in a cell. Excel ...
Discover MoreMake your macros too long, and Excel may just refuse to run them at all. This tip explains what the limit is for macros, ...
Discover MoreWhen writing macros, you may want to position a message box at a specific location on the screen. This can't be done in ...
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 © 2024 Sharon Parq Associates, Inc.
Comments