Worksheet Deactivate Question

gheyman

Well-known Member
Joined
Nov 14, 2005
Messages
2,347
Office Version
  1. 365
Platform
  1. Windows
I want to run a check before the user leaves the tab.

Code:
Private Sub Worksheet_Deactivate()
'
    Range("D1").Select
    ActiveCell.FormulaR1C1 = "=SUMIF(C[1],""parent"",C[9])"
    Range("D1").Select
'
    If Application.Range("D1") > 0 Then MsgBox "You or Someone has entered estimated hours/dollars against a PARENT WBS Task.  Parent level WBS Tasks are Sumary level items.  There should never be estimate directly bid to a Parent."
'
    Range("D1").Clear
'
End Sub

I want it to run when the user leaves the tab, but I am assuming "Deactivate" isn't what I think it is because its not working when I leave the tab. The code works if I run it. Is there a way to run this when they leave the tab?
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
Two things.
First, when the Deactivate event runs, the sheet it refers to is not the Active Sheet, so you'll have to qualtify all the cell references with Me.
Similarly, don't select in the deactivate event.

Code:
Private Sub Worksheet_Deactivate()

    With Me
        .Range("D1").FormulaR1C1 = "=SUMIF(C[1],""parent"",C[9])"
  
         If .Range("D1") > 0 Then MsgBox "You or Someone has entered estimated hours/dollars against a PARENT WBS Task.  Parent level WBS Tasks are Sumary level items.  There should never be estimate directly bid to a Parent."

        .Range("D1").Clear
    End With
End Sub
 
Upvote 0
How is it not working?

What value does your SUMIF return before you clear it?

Note, that you do not need those Select statements.
You can combine all this:
Code:
    Range("D1").Select
    ActiveCell.FormulaR1C1 = "=SUMIF(C[1],""parent"",C[9])"
    Range("D1").Select
into this:
Code:
    Range("D1").FormulaR1C1 = "=SUMIF(C[1],""parent"",C[9])"
 
Upvote 0
Thank You, Mike. Is there a way to go back to the sheet? I want to prevent them from leaving the tab if the condition is true Sheets("BOE")
 
Upvote 0
Thank You, Mike. Is there a way to go back to the sheet? I want to prevent them from leaving the tab if the condition is true Sheets("BOE")
Just put a statement in the TRUE portion of your IF statement that selects/activates that sheet again.
 
Upvote 0
Code:
Private Sub Worksheet_Deactivate()

    With Me
        .Range("D1").FormulaR1C1 = "=SUMIF(C[1],""parent"",C[9])"
  
         If .Range("D1") > 0 Then
             .Activate
             MsgBox "You or Someone has entered estimated hours/dollars against a PARENT WBS Task.  Parent level WBS Tasks are Sumary level items.  There should never be estimate directly bid to a Parent."
        End If
        .Range("D1").Clear
    End With
End Sub
 
Upvote 0
I came up with this and it seems to understand that the evaluation needs to be done on the deactivated sheet:

Code:
If Evaluate("=SUMIF(E:E,""parent"",M:M)") > 0 Then
    MsgBox "You or Someone has entered estimated hours/dollars against a PARENT WBS Task.  Parent level WBS Tasks are Sumary level items.  There should never be estimate directly bid to a Parent."
    Me.Select
End If
 
Upvote 0
Thanks everyone. I really appreciate all the options.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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