Option Explicit
Private Type POINTAPI
X As Long
Y As Long
End Type
[URL="https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=If"]#If[/URL] VBA7 Then
Private Type MSG
hwnd As LongPtr
message As Long
wParam As LongPtr
lParam As LongPtr
time As Long
pt As POINTAPI
End Type
Private Declare PtrSafe Function WaitMessage Lib "user32" () As Long
Private Declare PtrSafe Function PeekMessage Lib "user32" Alias "PeekMessageA" (lpMsg As MSG, ByVal hwnd As LongPtr, ByVal wMsgFilterMin As Long, ByVal wMsgFilterMax As Long, ByVal wRemoveMsg As Long) As Long
Private Declare PtrSafe Function PostMessage Lib "user32" Alias "PostMessageA" (ByVal hwnd As LongPtr, ByVal wMsg As Long, ByVal wParam As LongPtr, ByVal lParam As LongPtr) As Long
[URL="https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=Else"]#Else[/URL]
Private Type MSG
hwnd As Long
message As Long
wParam As Long
lParam As Long
time As Long
pt As POINTAPI
End Type
Private Declare Function WaitMessage Lib "user32" () As Long
Private Declare Function PeekMessage Lib "user32" Alias "PeekMessageA" (lpMsg As MSG, ByVal hwnd As Long, ByVal wMsgFilterMin As Long, ByVal wMsgFilterMax As Long, ByVal wRemoveMsg As Long) As Long
Private Declare Function PostMessage Lib "user32" Alias "PostMessageA" (ByVal hwnd As Long, ByVal wMsg As Long, ByVal wParam As Long, ByVal lParam As Long) As Long
[URL="https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=End"]#End[/URL] If
Private bXitLoop As Boolean
Private Const SHEET_NAME As String = "Sheet1" [B][COLOR=#008000]'<== Change this sheet name as required.[/COLOR][/B]
Private Const TARGET_RANGE_ADDR As String = "A3" [COLOR=#008000][B]'<== Change this target cell as required.[/B][/COLOR]
Private Sub Workbook_SheetSelectionChange(ByVal Sh As Object, ByVal Target As Range)
If Sh.Name = SHEET_NAME Then
If Target.Address(0, 0) = TARGET_RANGE_ADDR Then
bXitLoop = False
Call Monitor_EnterKey_Press
Else
bXitLoop = True
End If
End If
End Sub
Private Sub Monitor_EnterKey_Press()
Const WM_KEYDOWN = &H100
Const WM_KEYUP = &H101
Const PM_REMOVE = &H1
Dim tMsg As MSG
Do
DoEvents
WaitMessage
If PeekMessage(tMsg, Application.hwnd, WM_KEYDOWN, WM_KEYUP, PM_REMOVE) Then
If tMsg.wParam = vbKeyReturn Then
Call MyMacro
bXitLoop = True
End If
PostMessage Application.hwnd, tMsg.message, tMsg.wParam, tMsg.lParam
End If
Loop Until bXitLoop
End Sub
Private Sub Workbook_BeforeClose(Cancel As Boolean)
bXitLoop = True
End Sub
Private Sub MyMacro()
MsgBox "You pressed the ENTER key while on Cell : " & TARGET_RANGE_ADDR _
& vbNewLine & vbNewLine & "Your Macro is now running..."
End Sub