I've had a bit of a play with this, using OnTime - based on the principles on Chip Pearson's excellent site: http://www.cpearson.com/excel/OnTime.aspx - and I think I've got a solution for you. It doesn't use a hyperlink; instead it uses the lack of any new selection on the working sheet to switch to a TimeOut sheet after a set time.
Before I get to the code, a few notes:a. I've called the blank sheet 'TimeOut' - either change the name of your blank sheet to this, or change the reference in the code below (in the 'GoToTimeOutSheet' procedure);
b. The code works by running a repeating check of the time now against a time-out time set by either the data sheet being activated or the selection being changed on the data sheet;
c. Change the time-out time to what you want in the 'SetTimeOutTime' procedure - it's set to 50 secs in the code below;
d. The code needs to be put into four different modules: a standard module, the worksheet module for your data sheet, the worksheet module for the TimeOut sheet and the workbook module;
e. If you have more than one data sheet, repeat step 2 below for each one;
f. There's no error-trapping included - I don't think there should be any problems, but as always I advise trying this out on a copy of your file first;
g. As this uses VBA, the file will need to be saved as a macro-enabled file (filename.xlsm not filename.xlsx).
1. Create a new module (I named it 'TimeOut' but that's optional), and paste in all of this:
Option Explicit
' The code below is based on the principles on Chip Pearson's site:
' http://www.cpearson.com/excel/OnTime.aspx
' global variable used to delay the time-out
Public TimeOutTime As Double
' global variable used to run the repeating procedure
Public TimerTime As Double
' global constant used to schedule and re-schedule the repeating procedure
' keep this to less than the time in the SetTimeOutTime procedure
Public Const TimerRerunSecs = 10
' global constant which is the procedure to be run repeatedly
Public Const TimeOutSubToRun = "GoToTimeOutSheet"
Sub SetTimeOutTime()
' delay the time-out by the specified time (hh:mm:ss)
TimeOutTime = Now() + TimeValue("00:00:50")
' call the repeating procedure
StartTimer
End Sub
Sub StartTimer()
' repeating procedure which calls the specified procedure on the specified schedule
TimerTime = Now() + TimeSerial(0, 0, TimerRerunSecs)
Application.OnTime EarliestTime:=TimerTime, Procedure:=TimeOutSubToRun, Schedule:=True
End Sub
Sub GoToTimeOutSheet()
' this is the actual time-out procedure
' check if the time-out time is reached/past
If Now() > TimeOutTime Then
'activates sheet of specific name - change the name in "" as required
Worksheets("TimeOut").Activate
' optional - selects specified cell - change the cell as required
Range("B2").Select
' if the time-out time has not yet been reached then restart the repeating check
Else
StartTimer
End If
End Sub
Sub StopTimer()
' this is called by the Workbook_Close event and when the TimeOut sheet is activated
On Error Resume Next
' turn off the repeating OnTime procedure
Application.OnTime EarliestTime:=TimerTime, Procedure:=TimeOutSubToRun, Schedule:=False
End Sub
2. Paste this code into the worksheet module for your Data sheet(s):
Private Sub WorkSheet_Activate()
' call the procedure to delay the time-out
SetTimeOutTime
End Sub
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
' call the procedure to delay the time-out
SetTimeOutTime
End Sub
3. Paste this code into the worksheet module for the TimeOut sheet:
Private Sub WorkSheet_Activate()
' stop the repeating timer so it doesn't run where it's not necessary
StopTimer
End Sub
4. Paste this code into the workbook module:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
' call the procedure to stop the repeating timer
' (if this is not done and Excel is still open, the workbook will be re-opened to run the procedure again!)
StopTimer
End Sub
I've attached a file which has this working. Hope that does what you need.
Bookmarks