Worksheet Deactivate Question

gheyman

Well-known Member
Joined
Nov 14, 2005
Messages
1,730
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?
 

Some videos you may like

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,556
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
 

Joe4

MrExcel MVP, Junior Admin
Joined
Aug 1, 2002
Messages
53,412
Office Version
365
Platform
Windows
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])"
 

gheyman

Well-known Member
Joined
Nov 14, 2005
Messages
1,730
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")
 

Joe4

MrExcel MVP, Junior Admin
Joined
Aug 1, 2002
Messages
53,412
Office Version
365
Platform
Windows
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.
 

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,556
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
 

steve the fish

Well-known Member
Joined
Oct 20, 2009
Messages
8,072
Office Version
365
Platform
Windows
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
 

gheyman

Well-known Member
Joined
Nov 14, 2005
Messages
1,730
Thanks everyone. I really appreciate all the options.
 

Watch MrExcel Video

Forum statistics

Threads
1,099,086
Messages
5,466,549
Members
406,488
Latest member
syamvg

This Week's Hot Topics

Top