Worksheet_Change Recursion ARGHH!

D

DBAL

Hey all, good to come out here again.
I have some VBA that executes in "Private Sub
Worksheet_Change", and it takes place whenever the user
updates or makes changes to data on the spreadsheet. The
user actually only makes changes in the C column but the
rest of the spreadsheet refreshes accordingly.

Anyway, part of my VBA access another Sheet and copies
info from there to this sheet while also updating all the
cells of the columns (except the C column).

THE PROBLEM: As soon as the VBA starts changing the
values on this sheet, it re-executes the "Private Sub
Worksheet_Change" again and starts the Macro all over
before it ever finishes. It gets caught in a never
ending cycle?? So the VBA is activating itself because
it produces a Worksheet_Change. But I only want it to
run when the user changes a value in the C column????

I want to use "Worksheet_Change" instead of having a
button that the user has to remember to push. What can I
do? Please advise.

DBAL
 
R

Ron de Bruin

Hi DBAL

You can stop the running of the events when your macro do his work like this

Application.EnableEvents = flase
'your code
Application.EnableEvents = True
 
B

Bob Phillips

also, as a precaution, add an onerror so that if you fall out, you always
re-enable, like

Private Sub Worksheet_Change(ByVal Target As Range)

On Error GoTo ws_exit:
Application.EnableEvents = False
'your code

ws_exit:
Application.EnableEvents = True
End Sub


--

HTH

Bob Phillips
... looking out across Poole Harbour to the Purbecks
(remove nothere from the email address if mailing direct)
 
N

Nigel

The following will test the worksheet change event for changes in column C
only.
This might help ?

Private Sub Worksheet_SelectionChange(ByVal Target As Range)
If Target.Column = 3 Then
MsgBox "its C"
End If
End Sub

Cheers
Nigel
 
D

DBAL

Now this is nice... because it will only run the code
when a change is made in C right? If I put my code in
the middle there. Awesome, let me play with this.

Thanks!
DBAL
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top