Hi all,
I've always wanted to encapsulate the main backbone code in a Class and to also encapsulate the actual calling custom event code in a format that is more instinctive to the user ( something like : Worksheet_MouseMove(ByVal oCellTarget As Range, ByVal lX As Long, ByVal lY As Long...).
Not only would this be more instinctive but would also give more control, flexibility and autonomy to the developper as the event code is now kept seperate from the main.
Using a timer has a bad impact on performance so I have decided to set it up in a different XL instance that is created dinamically within the Class. Although this Does a litle bit improve performance, it poses a problem as the VBE has to be used therefore the Macro Security settings have to be lowered in order for it to work.
Ideally, I would have used VBScript for this but it doesn't support API declartions !
Anyway, thanks to encapsulating this in a Class and thanks to the Callback\Mouse Event handler all there is to do now is create an instance of the Class, set its Properties as shown below and run it. The Class will only run whatever YOU ,the programmer, decide to put in its Callback routine.
Demo Download :
http://www.savefile.com/files/129127
Note: Save the download to disk otherwise it may not work !
Here is an example- Put this in a Standard Module and run the
CreateMouseMoveEvent Routine :
Code:
Option Explicit
Dim MyClassTest As ClsWorkSheet_MouseMoveEvent
Dim sMsg As String
'\\RUN THIS PROCEDURE ******************************
Sub CreateMouseMoveEvent()
'\\declare & set the Class properties
Set MyClassTest = New ClsWorkSheet_MouseMoveEvent
With MyClassTest
.CallBackProcedure = "Worksheet_MouseMove"
.WorkSheetName = Worksheets(1).Name
.Execute
End With
End Sub
'\\*****very important*********
'\\the name of this callback routine has to match exactly
'\\the string passed to the above 'CallBackProcedure' class property !
'\\also exactly 3 arguments are to be passed to the callback and must be passed Byval
'\\error handling should be imlemented to avoid potential crashes !
'\\-----------------------------------------------------------------------------
'\\in this example, the callback which looks like a standard MS event procedure
'\\simply dinamically changes some formatting of the current cell
'\\(which is passed in its first arguments)located under the cursor
'\\THIS CALLBACK\EVENT PROC IS THERE FOR THE PROGRAMMER TO WRITE ANY CODE HE\SHE WANTS
Sub Worksheet_MouseMove(ByVal oCellTarget As Range, ByVal lX As Long, ByVal lY As Long)
Static lOldColor As Long
Static lOldTextColor As Long
Static lOldFontSize As Long
Static bOldFontBold As Boolean
Static sOldFormula As String
Static oOldRange As Range
'\\avoid crashing the app if 'oCellTarget' is Nothing
On Error Resume Next '\\ Very important !!!!!
'\\if the class is terminated, restore old values and get out
If Not MyClassTest.IsMouseEventEnabled Then
Range("A1").ClearContents
With oOldRange
.Interior.ColorIndex = lOldColor
.Font.ColorIndex = lOldTextColor
.Font.Size = lOldFontSize
.Font.Bold = bOldFontBold
.Formula = sOldFormula
End With
Exit Sub
End If
If oCellTarget.Address <> oOldRange.Address Then
With oOldRange
.Interior.ColorIndex = lOldColor
.Font.ColorIndex = lOldTextColor
.Font.Size = lOldFontSize
.Font.Bold = bOldFontBold
.Formula = sOldFormula
End With
Set oOldRange = oCellTarget
With oCellTarget
lOldColor = .Interior.ColorIndex
lOldTextColor = .Font.ColorIndex
lOldFontSize = .Font.Size
bOldFontBold = .Font.Bold
sOldFormula = .Formula
.Interior.ColorIndex = 3
.Font.ColorIndex = 6
.Font.Size = 10
.Font.Bold = True
End With
If Len(sOldFormula) = 0 Then
oCellTarget.Formula = "Empty Cell !!!"
End If
End If
sMsg = "Current Cell :" & oCellTarget.Address
Range("A1") = sMsg
End Sub
Sub KillMouseMoveEvent()
On Error Resume Next
MyClassTest.Disable
End Sub
..and here is the Class Code :
Code:
Option Explicit
'\\Class that simulates a mouse move event
'\\for worksheet cells.
'\\in order to minimise the timer effect on
'\\performance,the class opens a new excel
'\\instance dinamically and runs the timer code from it.
'\\a callback like procedure is also used
'\\to run any custome routine designed by the user.
'\\this callback signature simulates that of other known MS events
'\\xtra care must be taken when editing the callback routine
'\\any mistakes will potentially crash the app !
'\\error handling is therefore vital
'\\Note: this code uses the VBE so it requires that the Macro
'\\Security "Trusted Sources" be enabled.
Private sCode As String
Private oNewXLapp As Excel.Application
Private oNewWbk As Workbook
Private Const vbext_ct_StdModule As Long = 1
Private sSheetName As String
Private sCallBackProc As String
Private bMouseEventEnabled As Boolean
Private sMsg As String
Public WithEvents WbEvent As Workbook
Public Sub Execute()
'\\do not open more than one XL instance
'\\or you will end up with numerous conflicting timers !
If Not Me.IsMouseEventEnabled Then
'\\assign this workbook to WbEvent prop
'\\to close the the new XL instance if the user closes
'\\the workbook before terminating the Class !
Set Me.WbEvent = ThisWorkbook
'\\set this boolean property\flag
Me.IsMouseEventEnabled = True
'\\store the timer code in a string
sCode = "Declare Function SetTimer Lib ""user32"""
sCode = sCode & "(ByVal hwnd As Long, ByVal nIDEvent As Long,"
sCode = sCode & "ByVal uElapse As Long, ByVal lpTimerFunc As Long) As Long" & vbCrLf
sCode = sCode & "" & vbCrLf
sCode = sCode & "Declare Function KillTimer Lib ""user32"""
sCode = sCode & "(ByVal hwnd As Long, ByVal nIDEvent As Long) As Long" & vbCrLf
sCode = sCode & "" & vbCrLf
sCode = sCode & "Declare Function GetTickCount Lib ""kernel32"""
sCode = sCode & "Alias ""GetTickCount"" () As Long" & vbCrLf
sCode = sCode & "" & vbCrLf
sCode = sCode & "Declare Function GetCursorPos Lib ""user32"""
sCode = sCode & "(lpPoint As POINTAPI) As Long" & vbCrLf
sCode = sCode & "" & vbCrLf
sCode = sCode & "Type POINTAPI" & vbCrLf
sCode = sCode & " x as Long" & vbCrLf
sCode = sCode & " y as Long" & vbCrLf
sCode = sCode & "End Type" & vbCrLf
sCode = sCode & "" & vbCrLf
sCode = sCode & "Dim lCurPos As POINTAPI" & vbCrLf
sCode = sCode & "Dim bTimerOn As Boolean" & vbCrLf
sCode = sCode & "Dim lTimerId As Long" & vbCrLf
sCode = sCode & "Dim lHwnd As Long" & vbCrLf
sCode = sCode & "Dim oNewRange As Range" & vbCrLf
sCode = sCode & "Dim oWB As WorkBook" & vbCrLf
sCode = sCode & "" & vbCrLf
sCode = sCode & "Sub StartTimer()" & vbCrLf
sCode = sCode & " Set oWB = GetObject(" & Chr(34)
sCode = sCode & ThisWorkbook.FullName & Chr(34) & ")" & vbCrLf
sCode = sCode & " If Not bTimerOn Then" & vbCrLf
sCode = sCode & " lTimerId = SetTimer"
sCode = sCode & "(0, 0 , 10, AddressOf TimerProc)" & vbCrLf
sCode = sCode & " bTimerOn = True" & vbCrLf
sCode = sCode & " End If" & vbCrLf
sCode = sCode & "End Sub" & vbCrLf
sCode = sCode & "" & vbCrLf
sCode = sCode & "Sub TimerProc()" & vbCrLf
sCode = sCode & " On Error Resume Next" & vbCrLf
sCode = sCode & " GetCursorPos lCurPos" & vbCrLf
sCode = sCode & " Set oNewRange = oWb.Parent.ActiveWindow.RangeFromPoint"
sCode = sCode & "(lCurPos.x, lCurPos.Y)" & vbCrLf
'\\run procedure on one worksheet only
sCode = sCode & "If oWb.ActiveSheet.Name = " & Chr(34)
sCode = sCode & sSheetName & Chr(34) & " Then" & vbCrLf
'\\ensure mouse is pointing to a cell to avoid an error in callback
sCode = sCode & "If TypeName(oNewRange)=""Range"" Then " & vbCrLf
'\\run the callback from here !!
sCode = sCode & "oWb.Parent.Run oWb.Name & " & Chr(34) & "!"
sCode = sCode & sCallBackProc & Chr(34)
sCode = sCode & ",oNewRange, lCurPos.x, lCurPos.Y" & vbCrLf
sCode = sCode & " End If" & vbCrLf
sCode = sCode & " End If" & vbCrLf
sCode = sCode & "End Sub" & vbCrLf
sCode = sCode & "" & vbCrLf
'\\without this, the timer would not stop !
sCode = sCode & "Sub StopTimer()" & vbCrLf
sCode = sCode & " If bTimerOn Then" & vbCrLf
sCode = sCode & " KillTimer 0, lTimerId" & vbCrLf
sCode = sCode & " bTimerOn = False" & vbCrLf
sCode = sCode & " End If" & vbCrLf
sCode = sCode & "End Sub" & vbCrLf
'\\now, open a new invisible XL app and place the
'\\the contents of the string into a new module
'\\ideally,this would have been done via a VB script
'\\but VBS do not support API declarations
'\\
Set oNewXLapp = CreateObject("Excel.Application")
Set oNewWbk = oNewXLapp.Workbooks.Add
'\handle error if access to the VBE is NOT trusted
On Error Resume Next
oNewWbk.VBProject.VBComponents.Add _
(vbext_ct_StdModule).CodeModule.AddFromString sCode
If InStr(1, Err.Description, "not trusted", vbTextCompare) <> 0 Then
sMsg = "To use this 'MouseMoveEvent Class' "
sMsg = sMsg & "you must tick " & vbCrLf
sMsg = sMsg & "the 'Trust Access to Visual Basic Project' CheckBox " & vbCrLf
sMsg = sMsg & "via Tools\Macro\Security\Trusted Sources TAB, " & vbCrLf
sMsg = sMsg & "close Excel and reopen it again to take effect."
MsgBox Err.Description & vbCrLf _
& vbCrLf & sMsg, vbExclamation
With oNewXLapp
.DisplayAlerts = False
.Quit
End With
End
Else
'\\run the code to start the timer from the newly created wbk
oNewXLapp.Run oNewWbk.Name & "!StartTimer"
End If
End If
End Sub
Public Sub Disable()
On Error Resume Next
If Me.IsMouseEventEnabled Then
Me.IsMouseEventEnabled = False
'\\here,we run the StopTimer routine located
'\\ in the invisible XL instance
oNewXLapp.Run oNewWbk.Name & "!StopTimer"
'\\cleanup
With oNewXLapp
.DisplayAlerts = False
.Quit
End With
Set oNewXLapp = Nothing
Set oNewWbk = Nothing
'\\run the callback one more final time to ensure that all the old
'\\cell settings are restored in case the callback had chnged them
Application.Run ThisWorkbook.Name & "!" & sCallBackProc, Nothing, 0, 0
End If
End Sub
Public Property Get WorkSheetName() As String
WorkSheetName = sSheetName
End Property
Public Property Let WorkSheetName(ByVal vNewValue As String)
sSheetName = vNewValue
End Property
Public Property Get CallBackProcedure() As String
CallBackProcedure = sCallBackProc
End Property
Public Property Let CallBackProcedure(ByVal vNewValue As String)
sCallBackProc = vNewValue
End Property
Public Property Get IsMouseEventEnabled() As Boolean
IsMouseEventEnabled = bMouseEventEnabled
End Property
Public Property Let IsMouseEventEnabled(ByVal vNewValue As Boolean)
bMouseEventEnabled = vNewValue
End Property
Private Sub Class_Terminate()
Me.Disable
End Sub
Private Sub WbEvent_BeforeClose(Cancel As Boolean)
Me.Disable
End Sub
Any comments would be much appreciated.
Please, save your work bfore trying this as this could crash the system if not handled propperly
Last updated on 03/Oct/06.
Regards.