VBA number of events running

Rmv

New Member
Joined
Jul 25, 2010
Messages
1
Hi all! New to the forum.

I'm using the change event in a worksheet and when I initiate a change, it runs the code as expected. My code makes additional changes which triggers the change event code to run again since I leave application.events = true.

My question is how can I keep track whether I am in the original change event or if I'm in one of the sub change events which were triggered by the main one.

Thanks!
 

Some videos you may like

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.

crimson_b1ade

Well-known Member
Joined
Sep 27, 2008
Messages
1,557
I'm not sure I understand the question but you could add a MsgBox to the top of your procedures. That way you'll get a popup box on which code is running. Is this for debugging purposes? Example:

Code:
Sub SomeProcedure()
 
Msgbox "Now Running SomeProcedure"
 
your other code goes here
  
End Sub
 
Last edited:

ZVI

MrExcel MVP
Joined
Apr 9, 2008
Messages
3,714
Office Version
2016, 2010, 2007
Platform
Windows
Hi & Welcome to the Board!

This is my understanding of issue with its solution, see details in the code's comments:
Rich (BB code):

' Code of the sheet's module

Dim EventIsCharged As Boolean

Private Sub Worksheet_Change(ByVal Target As Range)
  
  ' This is the key to skip the code replaying
  If EventIsCharged Then Exit Sub
  
  ' Disable events triggering
  Application.EnableEvents = False
  
  ' Set flag to not trigger of this subrotine again till the end of the code
  EventIsCharged = True
  
  ' Safe calling of some subroutines even with possible Application.EnableEvents = True
  MsgBox "Test() is calling"
  Call Test
  
  ' Reset the flag to allow triggering of this subroutine
  EventIsCharged = False
  
  ' Restore events
  Application.EnableEvents = True
  
  
End Sub

Sub Test()
  
  ' Let's assume that for some reason the events should be enabled
  Application.EnableEvents = True
  
  ' Do something with cells.
  Cells(1, 1).Formula = Cells(1, 1).Formula
  
  ' If EventIsCharged = True then the 1st line of Worksheet_Change() code will exit that sub
    
End Sub
Regards
 
Last edited:

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,770
Perhaps something like
Code:
Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    Static countOfChange As Long
    countOfChange = countOfChange + 1
    
    Rem your code
    
    countOfChange = countOfChange - 1
End Sub
 

Subscribe on YouTube

Watch MrExcel Video

Forum statistics

Threads
1,106,866
Messages
5,513,888
Members
408,975
Latest member
PaperRave

This Week's Hot Topics

  • Sort code advice please
    Hi, I have the code below which im trying to edit but getting a little stuck. This was the original code which worked fine,columns A-F would sort...
  • SUMPRODUCT with nested If statement
    Hi everyone, Hope you're all well. I'm hoping someone will be able to point me in the right direction with a problem I'm having with a SUMPRODUCT...
  • VBA - simple sort is killing me!
    Hello all! This should be so easy, but not for me, apparently! I have a table of data that can be of varying lengths and widths. My current macro...
  • Compare Two Lists
    I have two Lists and I need to be able to Identify differences between them. List 100 comes from a workbook - the other is downloaded form the...
  • Formula that deducts points for each code I input.
    I am trying to create a formula that will have each student in my class start at 100 points and then for each code that I enter (PP for Poor...
  • Conditional formatting formula required for day of week and a value
    Hi, I have a really simple spreadsheet where column A is the date, column B is the activity total shown as a number and column C states the day of...
Top