email sent from worksheet value change

VbaHell

Well-known Member
Joined
Jan 30, 2011
Messages
1,220
Hello all

This piece of code sends out an email if the cell value is above 100 but you have to enter and exit the cell "H7" to activate

What I would like is if the cell value changed due to a sum function in that cell so is auto changes then this activate the email

is this possible please or do you have to enter the cell

Dim xRg As Range
'Update by Extendoffice 2018/3/7
Private Sub Worksheet_Change(ByVal Target As Range)
On Error Resume Next
If Target.Cells.Count > 1 Then Exit Sub
Set xRg = Intersect(Range("H7"), Target)
If xRg Is Nothing Then Exit Sub
If IsNumeric(Target.Value) And Target.Value > 100 Then
Call Mail_small_Text_Outlook
End If
End Sub
Sub Mail_small_Text_Outlook()
Dim xOutApp As Object
Dim xOutMail As Object
Dim xMailBody As String
Set xOutApp = CreateObject("Outlook.Application")
Set xOutMail = xOutApp.CreateItem(0)
xMailBody = "Hi there" & vbNewLine & vbNewLine & _
"This is line 1" & vbNewLine & _
"This is line 2"
On Error Resume Next
With xOutMail
.To = ""
.CC = ""
.BCC = ""
.Subject = "send by cell value test"
.Body = xMailBody
'.Send 'or use .Send
.Display
End With
On Error GoTo 0
Set xOutMail = Nothing
Set xOutApp = Nothing
End Sub
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
Use the Worksheet_Calculate event handler instead, which is triggered whenever the worksheet is recalculated.
 
Upvote 0
Hi Domenic

I have changed the code to your suggestion but I am guessing on how it should be and getting an error. CAn you give me advice please on how to fix this

Dim xRg As Range
Private Sub Worksheet_Calculate(ByVal Target As Range)
On Error Resume Next
If Target.Cells.Count > 1 Then Exit Sub
Set xRg = Intersect(Range("G7"), Target)
If xRg Is Nothing Then Exit Sub
If IsNumeric(Target.Value) And Target.Value > 100 Then
Call Mail_small_Text_Outlook
End If
End Sub
 
Upvote 0
With the following code, you might need to amend it, depending on your actual needs. Also, it assumes that cell H7 is located on Sheet1. So change the sheet reference accordingly. Once you've copied the code into your workbook, save, close, and reopen it. When the workbook is opened, it stores the value from H7 in a public variable. Then, whenever the worksheet is recalculated, it checks whether the current value in H7 has changed. If not, it exits the sub. If so, it checks whether the value in H7 is less than or equal to 100. If so, it stores the current value, and exits the sub. If not, it stores the current value, and continues with the rest of the code.

[Regular Module]

Code:
Public PrevVal As Double

[ThisWorkbook Module]

Code:
Private Sub Workbook_Open()
    PrevVal = Worksheets("Sheet1").Range("H7").Value
End Sub

[Sheet Module] Right-click the sheet tab, select View Code, and copy the code into the sheet module.

Code:
Private Sub Worksheet_Calculate()
    Dim rTarget As Range
    Set rTarget = Range("H7")
    If rTarget.Value = PrevVal Then Exit Sub
    If rTarget.Value <= 100 Then
        PrevVal = rTarget.Value
        Exit Sub
    End If
    PrevVal = rTarget.Value
    Application.EnableEvents = False
    'your code to send email
    '
    '
    '
    Application.EnableEvents = True
End Sub

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,223,898
Messages
6,175,274
Members
452,628
Latest member
dd2

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