Run macro after the enter key is pushed on specific cell

craigg3

Board Regular
Joined
Dec 23, 2002
Messages
163
Office Version
  1. 365
Platform
  1. Windows
I have it to where users enter a number in cell A3. I need a macro to run after they hit enter when on cell A3 and only cell A3. They may not enter any data in cell A3, but need it to run a macro regardless if hitting enter while in cell A3. Not sure how to do that.
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
How about this.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Not Intersect(Target, Range("A3")) Is Nothing Then
    MsgBox ("Your code here")
End If
End Sub
 
Upvote 0
What you want is actually trickier than it looks at first sight so you will need to resort to the windows api.

Place this code in the ThisWorkbook module:

The code assumes the Cell is A3 in Sheet1 and the Macro to run when pressing the enter key is MyMacro located at the bottom of the code... Change these as required

Code:
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
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,822
Messages
6,181,164
Members
453,021
Latest member
Justyna P

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