Worksheet change event only working once

LSM1604

New Member
Joined
Jan 8, 2010
Messages
49
Hey all,

I have some code on a few of my worksheets which makes some changes to others sheets when the cell values are changed. However, there is an issue. When I change the worksheet, the macro runs, but when I change it again, nothing happens.

Here is a sample of my code:

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Call Module1.MonthSheetChange
If Target.Column = 5 Then
    If Target.Row = 3 Or Target.Row = 4 Or Target.Row = 5 Or Target.Row = 6 Then
        Application.EnableEvents = False
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N3").Value = Range("E3").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N78").Value = Range("E3").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N153").Value = Range("E3").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N228").Value = Range("E3").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N303").Value = Range("E3").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N378").Value = Range("E3").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N453").Value = Range("E3").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N4").Value = Range("E4").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N79").Value = Range("E4").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N154").Value = Range("E4").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N229").Value = Range("E4").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N304").Value = Range("E4").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N379").Value = Range("E4").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("N454").Value = Range("E4").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U3").Value = Range("E5").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U78").Value = Range("E5").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U153").Value = Range("E5").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U228").Value = Range("E5").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U303").Value = Range("E5").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U378").Value = Range("E5").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U453").Value = Range("E5").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U4").Value = Range("E6").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U79").Value = Range("E6").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U154").Value = Range("E6").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U229").Value = Range("E6").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U304").Value = Range("E6").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U379").Value = Range("E6").Value
        Sheet11.Unprotect Password:="BBEAK11"
        Sheet11.Range("U454").Value = Range("E6").Value
        Sheet11.Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End If
ElseIf Target.Column = 12 Then
    If Target.Row = 3 Or Target.Row = 4 Or Target.Row = 5 Or Target.Row = 6 Then
        Application.EnableEvents = False
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N3").Value = Range("E3").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N78").Value = Range("E3").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N153").Value = Range("E3").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N228").Value = Range("E3").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N303").Value = Range("E3").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N378").Value = Range("E3").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N453").Value = Range("E3").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N4").Value = Range("E4").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N79").Value = Range("E4").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N154").Value = Range("E4").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N229").Value = Range("E4").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N304").Value = Range("E4").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N379").Value = Range("E4").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("N454").Value = Range("E4").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U3").Value = Range("E5").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U78").Value = Range("E5").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U153").Value = Range("E5").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U228").Value = Range("E5").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U303").Value = Range("E5").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U378").Value = Range("E5").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U453").Value = Range("E5").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U4").Value = Range("E6").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U79").Value = Range("E6").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U154").Value = Range("E6").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U229").Value = Range("E6").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U304").Value = Range("E6").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U379").Value = Range("E6").Value
        Sheet12.Unprotect Password:="BBEAK11"
        Sheet12.Range("U454").Value = Range("E6").Value
        Sheet12.Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End If
End If
End Sub

Also, if anyone could shorten the code for me please, I will be very greatful.

Thanks,
LSM1604
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Oh there are *plenty* of changes to be made here, especially to shorten the code.

Several things, here:
- you can combine a lot of these lines of code
- you only have to unprotect a sheet once
- you can combine the code to check for either 5 or 12 at once, rather than having the same code repeating
- the code is only working the once because you have forgotten to set EnableEvents back to True at the end of the code. So you turned it off when the code runs and it's still off until you turn it back on or restart Excel.

This seems to work for me (limited testing, but it's a start at least).
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim Rng1 As Range, Rng2 As Range
Dim Rng3 As Range, Rng4 As Range
 
Call Module1.MonthSheetChange
 
'save the ranges to variables so you don't have to type them out
With Sheet11
    Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
    Set Rng2 = Rng1.Offset(1, 0)
    Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
    Set Rng4 = Rng3.Offset(1, 0)
End With
 
'if changed cell is within E3:E6 or L3:L6 ranges
If Not Intersect(Target, Range("E3:E6")) Is Nothing Or _
Not Intersect(Target, Range("L3:L6")) Is Nothing Then
    
    'turn events off
    Application.EnableEvents = False
    
    With Sheet11
        'unprotect sheet
        .Unprotect Password:="BBEAK11"
        
        'update values
        Rng1.Value = .Range("E3").Value
        Rng2.Value = .Range("E4").Value
        Rng3.Value = .Range("E5").Value
        Rng4.Value = .Range("E6").Value
        
        'reprotect sheet
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    
    'turn events on again
    Application.EnableEvents = True
End If
End Sub
 
Upvote 0
Hi Von Pookie,

Thank you, with a little bit of editing, your code works a treat. I am still new to VBA and don't really work with it enough to be able to shorten my code. Here is the final bit a code:

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim Rng1 As Range, Rng2 As Range
Dim Rng3 As Range, Rng4 As Range
Dim MSheet As Worksheet
Set MSheet = ActiveSheet
 
Call Module1.MonthSheetChange
 
If Not Intersect(Target, Range("E3:E6")) Is Nothing Then
    Application.EnableEvents = False
    With Sheet11
        Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
        Set Rng2 = Union(.[N4], .[N79], .[N154], .[N229], .[N304], .[N379], .[N454])
        Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
        Set Rng4 = Union(.[U4], .[U79], .[U154], .[U229], .[U304], .[U379], .[U454])
        .Unprotect Password:="BBEAK11"
        Rng1.Value = MSheet.Range("E3").Value
        Rng2.Value = MSheet.Range("E4").Value
        Rng3.Value = MSheet.Range("E5").Value
        Rng4.Value = MSheet.Range("E6").Value
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    Application.EnableEvents = True
ElseIf Not Intersect(Target, Range("L3:L6")) Is Nothing Then
    Application.EnableEvents = False
    With Sheet12
        Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
        Set Rng2 = Union(.[N4], .[N79], .[N154], .[N229], .[N304], .[N379], .[N454])
        Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
        Set Rng4 = Union(.[U4], .[U79], .[U154], .[U229], .[U304], .[U379], .[U454])
        .Unprotect Password:="BBEAK11"
        Rng1.Value = MSheet.Range("L3").Value
        Rng2.Value = MSheet.Range("L4").Value
        Rng3.Value = MSheet.Range("L5").Value
        Rng4.Value = MSheet.Range("L6").Value
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    Application.EnableEvents = True
ElseIf Not Intersect(Target, Range("S3:S6")) Is Nothing Then
    Application.EnableEvents = False
    With Sheet13
        Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
        Set Rng2 = Union(.[N4], .[N79], .[N154], .[N229], .[N304], .[N379], .[N454])
        Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
        Set Rng4 = Union(.[U4], .[U79], .[U154], .[U229], .[U304], .[U379], .[U454])
        .Unprotect Password:="BBEAK11"
        Rng1.Value = MSheet.Range("S3").Value
        Rng2.Value = MSheet.Range("S4").Value
        Rng3.Value = MSheet.Range("S5").Value
        Rng4.Value = MSheet.Range("S6").Value
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    Application.EnableEvents = True
ElseIf Not Intersect(Target, Range("Z3:Z6")) Is Nothing Then
    Application.EnableEvents = False
    With Sheet14
        Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
        Set Rng2 = Union(.[N4], .[N79], .[N154], .[N229], .[N304], .[N379], .[N454])
        Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
        Set Rng4 = Union(.[U4], .[U79], .[U154], .[U229], .[U304], .[U379], .[U454])
        .Unprotect Password:="BBEAK11"
        Rng1.Value = MSheet.Range("Z3").Value
        Rng2.Value = MSheet.Range("Z4").Value
        Rng3.Value = MSheet.Range("Z5").Value
        Rng4.Value = MSheet.Range("Z6").Value
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    Application.EnableEvents = True
ElseIf Not Intersect(Target, Range("AG3:AG6")) Is Nothing Then
    Application.EnableEvents = False
    With Sheet15
        Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
        Set Rng2 = Union(.[N4], .[N79], .[N154], .[N229], .[N304], .[N379], .[N454])
        Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
        Set Rng4 = Union(.[U4], .[U79], .[U154], .[U229], .[U304], .[U379], .[U454])
        .Unprotect Password:="BBEAK11"
        Rng1.Value = MSheet.Range("AG3").Value
        Rng2.Value = MSheet.Range("AG4").Value
        Rng3.Value = MSheet.Range("AG5").Value
        Rng4.Value = MSheet.Range("AG6").Value
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    Application.EnableEvents = True
ElseIf Not Intersect(Target, Range("AN3:AN6")) Is Nothing Then
    Application.EnableEvents = False
    With Sheet16
        Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
        Set Rng2 = Union(.[N4], .[N79], .[N154], .[N229], .[N304], .[N379], .[N454])
        Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
        Set Rng4 = Union(.[U4], .[U79], .[U154], .[U229], .[U304], .[U379], .[U454])
        .Unprotect Password:="BBEAK11"
        Rng1.Value = MSheet.Range("AN3").Value
        Rng2.Value = MSheet.Range("AN4").Value
        Rng3.Value = MSheet.Range("AN5").Value
        Rng4.Value = MSheet.Range("AN6").Value
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    Application.EnableEvents = True
ElseIf Not Intersect(Target, Range("AU3:AU6")) Is Nothing Then
    Application.EnableEvents = False
    With Sheet17
        Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
        Set Rng2 = Union(.[N4], .[N79], .[N154], .[N229], .[N304], .[N379], .[N454])
        Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
        Set Rng4 = Union(.[U4], .[U79], .[U154], .[U229], .[U304], .[U379], .[U454])
        .Unprotect Password:="BBEAK11"
        Rng1.Value = MSheet.Range("AU3").Value
        Rng2.Value = MSheet.Range("AU4").Value
        Rng3.Value = MSheet.Range("AU5").Value
        Rng4.Value = MSheet.Range("AU6").Value
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    Application.EnableEvents = True
ElseIf Not Intersect(Target, Range("BB3:BB6")) Is Nothing Then
    Application.EnableEvents = False
    With Sheet18
        Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
        Set Rng2 = Union(.[N4], .[N79], .[N154], .[N229], .[N304], .[N379], .[N454])
        Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
        Set Rng4 = Union(.[U4], .[U79], .[U154], .[U229], .[U304], .[U379], .[U454])
        .Unprotect Password:="BBEAK11"
        Rng1.Value = MSheet.Range("BB3").Value
        Rng2.Value = MSheet.Range("BB4").Value
        Rng3.Value = MSheet.Range("BB5").Value
        Rng4.Value = MSheet.Range("BB6").Value
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    Application.EnableEvents = True
ElseIf Not Intersect(Target, Range("BI3:BI6")) Is Nothing Then
    Application.EnableEvents = False
    With Sheet19
        Set Rng1 = Union(.[N3], .[N78], .[N153], .[N228], .[N303], .[N378], .[N453])
        Set Rng2 = Union(.[N4], .[N79], .[N154], .[N229], .[N304], .[N379], .[N454])
        Set Rng3 = Union(.[U3], .[U78], .[U153], .[U228], .[U303], .[U378], .[U453])
        Set Rng4 = Union(.[U4], .[U79], .[U154], .[U229], .[U304], .[U379], .[U454])
        .Unprotect Password:="BBEAK11"
        Rng1.Value = MSheet.Range("BI3").Value
        Rng2.Value = MSheet.Range("BI4").Value
        Rng3.Value = MSheet.Range("BI5").Value
        Rng4.Value = MSheet.Range("BI6").Value
        .Protect Password:="BBEAK11", DrawingObjects:=True, Contents:=True, Scenarios:=True
    End With
    Application.EnableEvents = True
End If
End Sub


Thanks again,

LSM1604
 
Upvote 0

Forum statistics

Threads
1,224,587
Messages
6,179,741
Members
452,940
Latest member
rootytrip

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