Trying to modify code to run when user leaves a sheet

Maniacal

New Member
Joined
Mar 1, 2019
Messages
2
Hi all,

Apologies, I've been doing some reading and little out of my depth. I'm trying to convert the below code to work with worksheet_deactivate() command (when leaving a worksheet "Rebate Conditions"), however not having any luck. It works as a macro in a button on the sheet, just not when leaving the sheet so would assume is has to do with an activesheet issue.

I've read that the 1004 error will be caused by range issues in the code and tried adding in ME. and replacing activesheet with thisworkbook.sheets("rebate conditions") with no success.

Hoping someone may be able to steer me right.

Code:
Sub Refresh_Rebates()Dim RCount As Integer


'Optimize Code
  Call OptimizeCode_Begin


Rows.EntireRow.Hidden = False
RCount = Range("D" & ActiveSheet.Rows.Count).End(xlUp).Row


Range("B4:R" & RCount).Sort key1:=Range("E5:E" & RCount), Order1:=xlDescending, Header:=xlYes
Range("G2").Select
Selection.Copy
Range("H2").Select
ActiveSheet.Paste


Rows.EntireRow.Hidden = False
RCount = Range("B" & ActiveSheet.Rows.Count).End(xlUp).Row
For i = 5 To RCount
    If Range("D" & i).Value = 0 Then
        Range("J" & i).Value = ""
        Range("M" & i).Value = ""
        Range("P" & i).Value = ""
    End If
Next


'Optimize Code
  Call OptimizeCode_End
  
   MsgBox "Data updated"


End Sub
G2 is a fixed value. H2 is a variable.
 

Some videos you may like

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest

steve the fish

Well-known Member
Joined
Oct 20, 2009
Messages
8,110
Office Version
  1. 365
Platform
  1. Windows
Presuming your code is as you want you just need to qualify those ranges with a sheet name.

Code:
Private Sub Worksheet_Deactivate()

Dim RCount As Integer

'Optimize Code
Call OptimizeCode_Begin

With Sheets("Rebate Conditions")
    .Rows.EntireRow.Hidden = False
    RCount = .Range("D" & .Rows.Count).End(xlUp).Row
    .Range("B4:R" & RCount).Sort key1:=.Range("E5:E" & RCount), Order1:=xlDescending, Header:=xlYes
    .Range("G2").Copy .Range("H2")
    RCount = .Range("B" & .Rows.Count).End(xlUp).Row
    For i = 5 To RCount
        If .Range("D" & i).Value = 0 Then
            .Range("J" & i).Value = ""
            .Range("M" & i).Value = ""
            .Range("P" & i).Value = ""
        End If
    Next
End With

'Optimize Code
Call OptimizeCode_End

MsgBox "Data updated"

End Sub

Not quite sure what you mean by G2 is a fixed value and H2 is a variable?
 

mole999

Moderator
Joined
Oct 23, 2004
Messages
10,517
Office Version
  1. 2019
  2. 2016
  3. 2013
Platform
  1. Windows
Code:
Private Sub Worksheet_Deactivate()
Refresh_Rebates
End Sub
 

Maniacal

New Member
Joined
Mar 1, 2019
Messages
2
Presuming your code is as you want you just need to qualify those ranges with a sheet name.

Code:
Private Sub Worksheet_Deactivate()

Dim RCount As Integer

'Optimize Code
Call OptimizeCode_Begin

With Sheets("Rebate Conditions")
    .Rows.EntireRow.Hidden = False
    RCount = .Range("D" & .Rows.Count).End(xlUp).Row
    .Range("B4:R" & RCount).Sort key1:=.Range("E5:E" & RCount), Order1:=xlDescending, Header:=xlYes
    .Range("G2").Copy .Range("H2")
    RCount = .Range("B" & .Rows.Count).End(xlUp).Row
    For i = 5 To RCount
        If .Range("D" & i).Value = 0 Then
            .Range("J" & i).Value = ""
            .Range("M" & i).Value = ""
            .Range("P" & i).Value = ""
        End If
    Next
End With

'Optimize Code
Call OptimizeCode_End

MsgBox "Data updated"

End Sub

Not quite sure what you mean by G2 is a fixed value and H2 is a variable?

Thank you so so much. Works like a charm.
 

Watch MrExcel Video

Forum statistics

Threads
1,108,954
Messages
5,525,873
Members
409,668
Latest member
mitunsLax

This Week's Hot Topics

Top