How to Call a Macro Repeatedly on a Fixed Time Interval (151503)



The information in this article applies to:

  • Microsoft Excel 97 for Windows
  • Microsoft Excel 98 Macintosh Edition
  • Microsoft Excel for Windows 95
  • Microsoft Excel for Windows 5.0

This article was previously published under Q151503

SUMMARY

You can call a macro repeatedly at a set time interval using the OnTime method and the Call statement.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers 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 requirements. To call a macro four times at five-second intervals, follow these steps:
  1. Type the following code into a new module sheet:
               ' Module level declaration of icount, inumberofcalls. This line
          ' must be at the top of the module sheet
          Dim icount as Integer, inumberofcalls As Integer
    
          Sub StartOnTime()
    
              ' Initialize icount to 1.
              icount = 1
    
              ' Initialize inumberofcalls to 4.
              inumberofcalls = 4
    
              ' Select the range of cells for formatting.
              Range("A2:A" & inumberofcalls + 1).Select
    
              ' Format the selected cells as time.
              Selection.NumberFormat = "h:mm:ss AM/PM"
    
              ' Start in cell A1.
              Range("A1").Select
    
              ' Put the word "Time" in cell A1.
              ActiveCell.Value = "Time"
    
              ' Start the OnTimeMacro.
              Call OnTimeMacro
    
          End Sub
    
          Sub OnTimeMacro()
    
              ' Run the RunEvery5seconds macro inumberofcalls times.
              If icount <= inumberofcalls Then
    
                  ' Run the RunEvery5seconds macro in 5 seconds.
                  Application.OnTime Now + TimeValue("00:00:05"), _
                      "RunEvery5seconds"
    
                  ' Increment icount by 1.
                  icount = icount + 1
    
              Else
    
                  ' Icount is greater than inumberofcalls, so exit the macro.
                  Exit Sub
    
              End If
    
          End Sub
    
          Sub RunEvery5seconds()
    
              ' Places the current time in a cell.
              ActiveCell.Offset(icount - 1, 0).Value = Format(Now(), _
                  "hh:mm:ss")
    
              ' Runs the OnTimeMacro again.
              Call OnTimeMacro
    
          End Sub
    						
  2. Run the macro StartOnTime.

    The macro enters the time at which it ran into cells A2, A3, A4, and A5 on Sheet1 of the active workbook.

REFERENCES

For more information about the OnTime method in Microsoft Excel 97, from the Visual Basic Editor, click the Office Assistant, type OnTime, click Search, and then click to view "OnTime Method."

NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If the Assistant is not able to answer your query, please see the following article in the Microsoft Knowledge Base:

176476 OFF: Office Assistant Not Answering Visual Basic Questions

For more information about the OnTime method in Microsoft Excel version 7.0, click Answer Wizard on the Help menu and type:

OnTime

For more information about the OnTime method in Microsoft Excel version 5.0, click the Search button in Help and type:

OnTime


Modification Type:MinorLast Reviewed:8/17/2005
Keywords:kbdtacode kbhowto kbProgramming KB151503