Worksheet change is crashing excel

rikvny02

Board Regular
Joined
Aug 9, 2022
Messages
78
Office Version
  1. 365
Platform
  1. Windows
For what reason is the below worksheet change crashing excel. this can easily be done with a formula however, i have a double click function that does not carry the formula.

Private Sub Worksheet_Change(ByVal Target As Range)
Dim LastRow As Long
Dim G As Long
LastRow = Range("A" & Rows.Count).End(xlUp).Row
For G = 2 To LastRow
If Range("E" & G).Value = "99" Then
Range("G" & G).Value = "99"
ElseIf Range("E" & G).Value = "95" Then
Range("G" & G).Value = "95"
ElseIf Range("E" & G).Value = "991" Then
Range("G" & G).Value = "991"
ElseIf Range("E" & G).Value = "71" Then
Range("G" & G).Value = "71"
ElseIf Range("E" & G).Value = "40" Then
Range("G" & G).Value = "40"

End If
Next G
End Sub
 
Last edited:

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
The issue with "Worksheet_Change" event procedures is that they are triggered whenever a change is made. So if you are not careful, and your code is making changes, it could get caught up in an infinite loop. So you need to temporarily disable events while the changes are being made by your code.

You can also simplify the code a little, like this:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim LastRow As Long
    Dim G As Long

    Application.EnableEvents = False

    LastRow = Range("A" & Rows.Count).End(xlUp).Row
    For G = 2 To LastRow
        Select Case Range("E" & G).Value
            Case "99", "95", "991", "71", "40"
                Range("G" & G).Value = Range("E" & G).Value
        End Select
    Next G
   
    Application.EnableEvents = True
   
End Sub
Also note that people typically limit when the code runs depending on which cells are being updated.
Right now, you have your code running against ALL rows any time any data change is made anywhere on the sheet.
 
Upvote 0
Solution
The issue with "Worksheet_Change" event procedures is that they are triggered whenever a change is made. So if you are not careful, and your code is making changes, it could get caught up in an infinite loop. So you need to temporarily disable events while the changes are being made by your code.

You can also simplify the code a little, like this:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim LastRow As Long
    Dim G As Long

    Application.EnableEvents = False

    LastRow = Range("A" & Rows.Count).End(xlUp).Row
    For G = 2 To LastRow
        Select Case Range("E" & G).Value
            Case "99", "95", "991", "71", "40"
                Range("G" & G).Value = Range("E" & G).Value
        End Select
    Next G
 
    Application.EnableEvents = True
 
End Sub
Also note that people typically limit when the code runs depending on which cells are being updated.
Right now, you
The issue with "Worksheet_Change" event procedures is that they are triggered whenever a change is made. So if you are not careful, and your code is making changes, it could get caught up in an infinite loop. So you need to temporarily disable events while the changes are being made by your code.

You can also simplify the code a little, like this:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim LastRow As Long
    Dim G As Long

    Application.EnableEvents = False

    LastRow = Range("A" & Rows.Count).End(xlUp).Row
    For G = 2 To LastRow
        Select Case Range("E" & G).Value
            Case "99", "95", "991", "71", "40"
                Range("G" & G).Value = Range("E" & G).Value
        End Select
    Next G
 
    Application.EnableEvents = True
 
End Sub
Also note that people typically limit when the code runs depending on which cells are being updated.
Right now, you have your code running against ALL rows any time any data change is made anywhere on the sheet.

have your code running against ALL rows any time any data change is made anywhere on th

The issue with "Worksheet_Change" event procedures is that they are triggered whenever a change is made. So if you are not careful, and your code is making changes, it could get caught up in an infinite loop. So you need to temporarily disable events while the changes are being made by your code.

You can also simplify the code a little, like this:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim LastRow As Long
    Dim G As Long

    Application.EnableEvents = False

    LastRow = Range("A" & Rows.Count).End(xlUp).Row
    For G = 2 To LastRow
        Select Case Range("E" & G).Value
            Case "99", "95", "991", "71", "40"
                Range("G" & G).Value = Range("E" & G).Value
        End Select
    Next G
  
    Application.EnableEvents = True
  
End Sub
Also note that people typically limit when the code runs depending on which cells are being updated.
Right now, you have your code running against ALL rows any time any data change is made anywhere on the sheet.
When using your simplified version everything works very smooth. Thanks for your help
 
Upvote 0
You are welcome.
Glad I was able to help!

I hope it makes sense. That is something very important to remember when using Worksheet_Change event procedure, so you don't get caught up in an infinite loop and crash your system.
 
Upvote 1

Forum statistics

Threads
1,215,215
Messages
6,123,668
Members
449,114
Latest member
aides

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