BY CATEGORY
VBA CATEGORIES
EXCEL VBA - BASICS VIDEOS
- Excel VBA Part 1 - The VB Editor
- Excel VBA Part 2 - Writing Your First Macro
- Excel VBA Part 3 - What To Do When Things Go Wrong
- Excel VBA Part 4 - Buttons, Toolbars and Keyboard Shortcuts
- Excel VBA Part 5 - Selecting Cells
- Excel VBA Part 6 - Worksheets, Charts and Sheets
- Excel VBA Part 7 - Working with Workbooks
- Excel VBA Part 8 - Variables in VBA
- Excel VBA Part 9 - Object Variables
- Excel VBA Part 10 - Message Boxes
- Excel VBA Part 11 - Input Boxes
- Excel VBA Part 11a - Application.InputBox
- Excel VBA Part 12 - With Statements
- Excel VBA Part 13.1 - If Statements in VBA
- Excel VBA Part 14.1- Select Case Statements
- Excel VBA Part 15.1 - Do Until and Do While Loops
- Excel VBA Part 16 - For Next Loops
- Excel VBA Part 17 - For Each Loops
- Excel VBA Part 18 - Creating Functions
- Excel VBA Part 19 - Error Handling
- Excel VBA Part 20 - Event Procedures
- Excel VBA Part 21 - User Forms
Excel VBA - Basics videos | Excel VBA Part 20 - Event Procedures
Posted by Andrew Gould on 28 February 2014
Writing Event Procedures allows you to create subroutines which run automatically in response to events in a workbook. This video teaches you how to access the events of an object and start writing event procedures for both workbooks and worksheets. You'll also see how to cancel certain events and how to disable events, as well as how to use the parameters of an event procedure.
You can increase the size of the video:

You can view the video in full screen mode as shown on the left, using the icon at the bottom right of the frame.
You can also increase the quality of the video:

You can improve the resolution of the video using another icon at the bottom right of the frame. This will slow down the connection speed, but increase the display and sound quality. This icon only becomes visible when you start playing the video.
Finally, if nothing happens when you play the video, check that you're not using IE in compatibility view.
Andrew,
Is something perculiare with the following? I tested it on Excel 2010.
Option Explicit
Private Sub Worksheet_Change(ByVal Target As Range)
With Application
.EnableEvents = False
Select Case Target.Column
Case 1
Me.Cells(Target.Row, 2).Select
Case 2
Me.Cells(Target.Row, 3).Select
Case 3
Me.Cells(Target.Row, 4).Select
Case 4
Me.Cells(Target.Row, 1).Select
End Select
.EnableEvents = True
End With
End Sub
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
MsgBox "SelectionChange!"
End Sub
The first time you select a cell on the worksheet, it triggers the Worksheet_SelectionChange event and the message box appears. I expect that.
After clicking OK, if I change a value on the worksheet, the Worksheets_Change event kicks off (as expected) and runs to the End Sub.
However, what I did not expect is after the End Sub in Worksheet_Change has been run, it immediately jumps to Sub Worksheet_SelctionChange.
I thought that by adding Applkication.EnableEvents = False, it suppresses the event.
Do you see a similar result (preferably testing in Excel 2010)?
Thanks
Hi duggie,
Are you typing the value into a cell and then pressing Enter? If so, you're triggering two events: 1) the Change event triggered by changing the value; and 2) the SelectionChange event triggered by pressing Enter to move to the next cell.
Try pressing CTRL + Enter to enter the value into the cell without moving to another cell. You'll see that your code works as intended.
I hope that helps!
Andrew,
Thanks for the suggestion wich worked but alas I doubt very much my users will be entering data via the Ctrl key! (I'll get round it).
What got me puzzled was I thought adding Application.EnableEvents stopped events kicking off. As can be seen in my code, that is set to False when a cell is selected, so the event wasn't triggered immediately but as soon as it was switched back on, the SelectionChange event was started.
Hi duggie,
Yes it's not immediately obvious what's going on but here's my basic breakdown:
1. You type in some data and press Enter which triggers the Change event.
2. Within the Change event procedure you disable events and select another cell while events are disabled meaning that no new events are triggered.
3. At the end of the Change event procedure you enable events.
4. After your Change event procedure has finished, the SelectionChange event associated with pressing Enter (or Tab or a cursor key) originally is still triggered.
Here's a very simple way to prevent the message box appearing after you've entered some data and pressed Enter (or Tab or a cursor key):
Option Explicit
Dim DataChanged As Boolean
Private Sub Worksheet_Change(ByVal Target As Range)
DataChanged = True
With Application
.EnableEvents = False
Select Case Target.Column
Case 1
Me.Cells(Target.Row, 2).Select
Case 2
Me.Cells(Target.Row, 3).Select
Case 3
Me.Cells(Target.Row, 4).Select
Case 4
Me.Cells(Target.Row, 1).Select
End Select
.EnableEvents = True
End With
End Sub
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
If Not DataChanged Then
MsgBox "SelectionChange!"
End If
DataChanged = False
End Sub