Macro to run on timer errors out on the second cycle

BigShanny

New Member
Joined
Jan 22, 2025
Messages
10
Office Version
  1. 365
Platform
  1. Windows
Hello again,

I have the following code within ThisWorkbook to run a Macro on a timer. The Macro runs successfully upon opening the file, but errors out when it tries to run again in the designated time frame (every 10 seconds while I'm testing the code). Where am I going wrong here? I'd like it to copy the data from "Client Issues Log.xlsx" and paste it into the designated worksheet within "Test_Master_CMTimeTracker.xlsm" repeatedly on the set timer increment.

VBA Code:
Dim RunTimer As Date

Private Sub Workbook_Open()

Call ImportData

End Sub

Sub ImportData()

RunTimer = Now + TimeValue("00:00:10")

Application.OnTime RunTimer, "ImportData"
MsgBox "10 Sec timer has started.", vbInformation


Call OpenClientIssuesLog

Workbooks("Client Issues Log.xlsx").Worksheets("Sheet1").Range("A2:P5").Copy _
    Workbooks("Test_Master_CMTimeTracker.xlsm").Worksheets("Client Issues Log").Range("A2")
  
Call CloseClientIssuesLog
  

End Sub

Sub OpenClientIssuesLog()

Workbooks.Open "C:\Users\LarryMac\OneDrive - LIC\HomeDrive_USURB61NS2VF1_home\Time Tracker\Client Issues Log.xlsx"

End Sub

Sub CloseClientIssuesLog()

Workbooks("Client Issues Log.xlsx").Close

End Sub

This is the error message I get:
1738786877893.png
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
Try this way:

VBA Code:
Dim RunTimer As Date

Private Sub Workbook_Open()
  Call ImportData
End Sub

Sub ImportData()
  Application.ScreenUpdating = False
  Call OpenClientIssuesLog
  Workbooks("Client Issues Log.xlsx").Worksheets("Sheet1").Range("A2:P5").Copy _
      Workbooks("Test_Master_CMTimeTracker.xlsm").Worksheets("Client Issues Log").Range("A2")
  Call CloseClientIssuesLog
  DoEvents
  Application.ScreenUpdating = True

  RunTimer = Now + TimeValue("00:00:10")
  Application.OnTime RunTimer, "ImportData"
End Sub

Sub OpenClientIssuesLog()
  Dim sPath As String
  sPath = "C:\Users\LarryMac\OneDrive - LIC\HomeDrive_USURB61NS2VF1_home\Time Tracker\"
  Workbooks.Open sPath & "Client Issues Log.xlsx"
End Sub

Sub CloseClientIssuesLog()
  Workbooks("Client Issues Log.xlsx").Close
End Sub
 
Upvote 0
Change:
VBA Code:
Application.OnTime RunTimer, "ImportData"
to:
VBA Code:
Application.OnTime RunTimer, "ThisWorkbook.ImportData"
 
Upvote 0
Solution
Try this way:

VBA Code:
Dim RunTimer As Date

Private Sub Workbook_Open()
  Call ImportData
End Sub

Sub ImportData()
  Application.ScreenUpdating = False
  Call OpenClientIssuesLog
  Workbooks("Client Issues Log.xlsx").Worksheets("Sheet1").Range("A2:P5").Copy _
      Workbooks("Test_Master_CMTimeTracker.xlsm").Worksheets("Client Issues Log").Range("A2")
  Call CloseClientIssuesLog
  DoEvents
  Application.ScreenUpdating = True

  RunTimer = Now + TimeValue("00:00:10")
  Application.OnTime RunTimer, "ImportData"
End Sub

Sub OpenClientIssuesLog()
  Dim sPath As String
  sPath = "C:\Users\LarryMac\OneDrive - LIC\HomeDrive_USURB61NS2VF1_home\Time Tracker\"
  Workbooks.Open sPath & "Client Issues Log.xlsx"
End Sub

Sub CloseClientIssuesLog()
  Workbooks("Client Issues Log.xlsx").Close
End Sub
Thank you.
 
Upvote 0

Forum statistics

Threads
1,226,314
Messages
6,190,226
Members
453,598
Latest member
Excelnewbieneedtolearn

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top