Results 1 to 3 of 3

Thread: Stop change event

  1. #1
    Acolyte gsnidow's Avatar
    Join Date
    Aug 2011
    Location
    Virginia
    Posts
    38
    Articles
    0

    Stop change event



    Register for a FREE account, and/
    or Log in to avoid these ads!

    Greetings all. I have a general question, so I don't think anyone will need to see the code. I have two cells, I'll call them cell1 and cell2. Cell1 is a date, and cell2 is a number. If someone changes the date in cell1, the change event references another sheet and populates the datediff in days in cell 2. This is working 100%. My problem is that I would like to put the same logic for changes to cell2, i.e. if someone changes the number, it will reference the same date in another sheet, and return the date that results from a date calculation, and populate that in cell1. I had this working 100% also. The problem is that I cannot have them both working, because it causes an unending loop of updates. Any ideas. I'm hoping someone knows something easy, if not I will post the code. Thank you.

    Greg

  2. #2
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,284
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    Your change events are making changes, which cause the change event to be triggered.

    The way I deal with this is:

    Code:
    Dim lEvents As Long  '<-- Put at top of module before any sub lines but after any option lines (if you have any)
    Private Sub Worksheet_Change(ByVal Target As Range)
        lEvents = lEvents + 1
        If lEvents > 1 Then GoTo ExitPoint
        
        'Whatever you were doing goes here
        
    ExitPoint:
        lEvents = lEvents - 1
    End Sub
    What that does is add 1 to a module level variable each time the code is run. If the variable is greater than 1, then none of your internal code is run. Before the procedure finished, it decreases the value again.

    When the code starts initially, the value will be 0. It could trigger loops 100 times though, and wouldn't run the code after the first time until the original procedure ends.

    Full article on it here: http://www.excelguru.ca/content.php?...rolling-Events
    Ken Puls, FCPA, FCMA, MS MVP

    Learn to Master Your Data at the Power Query Academy (the world's most comprehensive online Power Query training), with my book M is for Data Monkey, or our new Power Query Recipe cards!

    Main Site: http://www.excelguru.ca -||- Blog: http://www.excelguru.ca/blog -||- Forums: http://www.excelguru.ca/forums
    Check out the Excelguru Facebook Fan Page -||- Follow Me on Twitter

    If you've been given VBA code (a macro) for your solution, but don't know where to put it, CLICK HERE.

  3. #3
    Acolyte gsnidow's Avatar
    Join Date
    Aug 2011
    Location
    Virginia
    Posts
    38
    Articles
    0
    Thank you Ken, that seems to be working. I messed around with constants, and could not get around the self calling nature of what I am trying to do. I had an errant 'Exit Sub' in the middle of my code that was messing me all up, since it bypassed the decrementing of the counter. Anyhow, thank you for the tip.

    Greg

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •