WORKAROUND
To cancel an
OnTime method, you must call another
OnTime method to set the schedule argument equal to
False. However, note that this method does not work if the time argument in the
OnTime method is set with the NOW function.
To prepare the first
OnTime method so that you can cancel it later, create a time variable and use this variable in both cases, as in the following example:
Microsoft provides programming examples for illustration only, without warranty either
expressed or implied, including, but not limited to, the implied warranties of
merchantability and/or fitness for a particular purpose. This article assumes
that you are familiar with the programming language being demonstrated and the
tools used to create and debug procedures. Microsoft support professionals can
help explain the functionality of a particular procedure, but they will not
modify these examples to provide added functionality or construct procedures to
meet your specific needs. If you have limited programming experience, you may
want to contact a Microsoft Certified Partner or the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft Certified
Partners, please visit the following Microsoft Web site:
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
- Type or paste the following macro code into a module sheet in a new workbook:
Dim TimeNow As Double
Dim TimeStop As Double
Dim TimeSet As Double
Sub RunMeFirst()
TimeNow = Now
TimeStop = TimeNow + TimeValue("00:00:59") 'this sets the time at
'which all macros will
'stop
TimeSet = TimeNow + TimeValue("00:00:15")
Set_OnTime
End Sub
Sub Set_OnTime()
Application.OnTime TimeSet, "TestMacro"
If TimeSet > TimeStop Then 'compare the time to stop with the time
'at which the TestMacro is scheduled to
'run
Application.OnTime TimeSet, "TestMacro", , False
End If
End Sub
Sub TestMacro()
ActiveCell.Value = 1
ActiveCell.Offset(1, 0).Select
TimeSet = TimeSet + TimeValue("00:00:15")
Set_OnTime
End Sub
- Activate Sheet1 in your workbook.
- Run the RunMeFirst macro.
The TimeStop variable is set to 59 seconds after you run the RunMeFirst macro, and the TimeSet variable is set to 15 seconds after you run the RunMeFirst macro. Then, the Set_OnTime macro is called, which in-turn checks to see if the TimeSet variable is greater than the TimeStop variable. If it is, all macros stop. If it is not, the TestMacro is called. The TestMacro places a value of 1 in the active cell, selects the next cell down from the active cell, and then resets the TimeSet variable to 15 seconds past its current value. The TestMacro then calls the Set_OnTime macro.