Executing a Macro Every 15 Minutes

Written by Allen Wyatt (last updated June 25, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


Tony wonders if there is a way to automatically execute a macro every 15 minutes. He would like to do this without impacting other operations in Excel, meaning he doesn't want to be hanging in a loop waiting for a certain time.

The key to doing this type of operation is to use the .OnTime method; it allows you to run a particular macro after a specified period of time. So, for instance, let's say you wanted to run a macro called "MyMacro" every 15 minutes. You could achieve this simply by using the following single-line macro:

Sub StartTimer()
    Application.OnTime Now() + TimeValue("00:15:00"), "MyMacro"
End Sub

Exactly 15 minutes after executing this macro, the MyMacro macro will be automatically executed, regardless of what you are doing elsewhere in Excel. Once the time you specified for the .OnTime method is expired and MyMacro is started, MyMacro will not be run again until such point as you again run the StartTimer macro and .OnTime is again invoked. All this means is that you may want to make a call to StartTimer either the first line of MyMacro or the last line, depending on when you want the timer restarted.

You could, if you desire, modify StartTimer just a bit to allow the passing of a parameter, in this manner:

Sub StartTimer(dMinutes As Double)
    Dim dAdjust As Double

    dAdjust = Now() + (dMinutes / (24 * 60))
    Application.OnTime dAdjust, "MyMacro"
End Sub

This approach provides a bit more flexibility because you can pass, to StartTimer, the number of minutes you want to use with the .OnTime method. For instance, if you wanted to start MyMacro after 12.5 minutes, you could add the following line to your existing code:

Call StartTimer(12.5)

If you add such a line in your MyMacro code, then MyMacro will run every 12.5 minutes forever, as long as Excel is running. If you want to stop the timer and you don't want to stop Excel, then you will need to make a few changes to your macro setup:

Public dTimeStore As Double

Sub StartTimer(dMinutes As Double)
    dTimeStore = Now() + (dMinutes / (24 * 60))
    Application.OnTime dTimeStore, "MyMacro"
End Sub
Sub EndTimer()
    Application.OnTime dTimeStore, "MyMacro", , False
End Sub

Note the declaration of the dTimeStore variable, which is used to store the last time used with the .OnTime method. This allows you to, at some point, call the EndTimer macro and, in turn, the .OnTime method properly to turn off the timer. Note, as well, in the EndTimer macro the presence of two sequential commas in the invocation of .OnTime. This is necessary in order to make sure the parameters are in the proper place as required by the method.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13790) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.

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

Noting Inactivity within a Timeframe

There are many times when you are creating a worksheet that you need to analyze dates within that worksheet. Once such ...

Discover More

Rejecting Changes in a Document

When a group of people edits a document with Track Changes turned on, it can be tempting for one of the editors to use ...

Discover More

Using the IF Worksheet Function

Programmers know that a staple of any language is the ability to create conditional statements. Excel understands this, ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (ribbon)

Using SUM In a Macro

Want to use a worksheet function (such as SUM) from within a macro? Here's how easy it is to accomplish the task.

Discover More

Making Common Functions Available to Others

When you use macros to create functions, you might want to share those functions with others�"particularly if they ...

Discover More

Pausing Macros for User Input

Does your macro need to get some input from a user? Here are the ways that Excel provides for that input to be solicited.

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

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 2 + 2?

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 ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

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