Sending email when a Cell is changed to value "A" for multiple colums

Sharonca

New Member
Joined
Jan 9, 2022
Messages
16
Office Version
  1. 365
Platform
  1. Windows
Hello,
I have a macro in a shared sheet (different users may be updating different cells in the same column at the same time) that currently works if a cell in the designated range changes to any value. I would need to change that to only when the value changes to "A". I also need to have the same macro for multiple columns. I don't know if I need to put the code for each column and call the module or if there is another solution.

Here is the code I have thus far.

Private Sub Worksheet_Change(ByVal Target As Range)
Dim xRgSel As Range
Dim xOutApp As Object
Dim xMailItem As Object
Dim xMailBody As String
On Error Resume Next
Application.ScreenUpdating = False
Application.DisplayAlerts = False
Set xRg = Range("AA4:AA2000")
Set xRgSel = Intersect(Target, xRg)
ActiveWorkbook.Save
If Not xRgSel Is Nothing Then
Set xOutApp = CreateObject("Outlook.Application")
Set xMailItem = xOutApp.CreateItem(0)
xMailBody = "Cell(s) " & xRgSel.Address(False, False) & _
" in the worksheet '" & Me.Name & "' were modified on " & _
Format$(Now, "mm/dd/yyyy") & " at " & Format$(Now, "hh:mm:ss") & _
" by " & Environ$("username") & "."

With xMailItem
.To = "Email Address"
.Subject = "Worksheet modified - Update TI Survey Schedule Date"
.Body = xMailBody
.Display
End With
Set xRgSel = Nothing
Set xOutApp = Nothing
Set xMailItem = Nothing
End If
Application.DisplayAlerts = True
Application.ScreenUpdating = True
End Sub
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
What are the multiple columns and does the macro change in any way for each column?
 
Upvote 0
Macro does not change in any for each column. Columns are:
AA, AC, AG, AI, BD, BF, BY, CG, CJ, DH, DJ, EB, ED
 
Upvote 0
Try:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim xOutApp As Object, xMailItem As Object, xMailBody As String
    On Error Resume Next
    Application.ScreenUpdating = False
    Application.DisplayAlerts = False
    If Intersect(Target, Range("AA:AA", "AC:AC", "AG:AG", "AI:AI", "BD:BD", "BF:BF", "BY:BY", "CG:CG", "CJ:CJ", "DH:DH", "DJ:DJ", "EB:EB", "ED:ED")) Is Nothing Then Exit Sub
    ActiveWorkbook.Save
    Set xOutApp = CreateObject("Outlook.Application")
    Set xMailItem = xOutApp.CreateItem(0)
    xMailBody = "Cell(s) " & Target.Address(False, False) & " in the worksheet '" & Me.Name & "' were modified on " & _
    Format$(Now, "mm/dd/yyyy") & " at " & Format$(Now, "hh:mm:ss") & " by " & Environ$("username") & "."
    With xMailItem
        .To = "Email Address"
        .Subject = "Worksheet modified - Update TI Survey Schedule Date"
        .Body = xMailBody
        .Display
    End With
    Application.DisplayAlerts = True
    Application.ScreenUpdating = True
End Sub
Using "Error Resume Next" can create problems because it disables all error messages so if your code errors out, you won't know which line of code is causing the error. It is always best to use error checking instead. Delete that line of code unless it is absolutely necessary for some reason. The same for "Application.DisplayAlerts = False". Usually this code is placed immediately before the line of code that would display the alert and "Application.DisplayAlerts = True" immediately after.
 
Upvote 0
Try:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim xOutApp As Object, xMailItem As Object, xMailBody As String
    On Error Resume Next
    Application.ScreenUpdating = False
    Application.DisplayAlerts = False
    If Intersect(Target, Range("AA:AA", "AC:AC", "AG:AG", "AI:AI", "BD:BD", "BF:BF", "BY:BY", "CG:CG", "CJ:CJ", "DH:DH", "DJ:DJ", "EB:EB", "ED:ED")) Is Nothing Then Exit Sub
    ActiveWorkbook.Save
    Set xOutApp = CreateObject("Outlook.Application")
    Set xMailItem = xOutApp.CreateItem(0)
    xMailBody = "Cell(s) " & Target.Address(False, False) & " in the worksheet '" & Me.Name & "' were modified on " & _
    Format$(Now, "mm/dd/yyyy") & " at " & Format$(Now, "hh:mm:ss") & " by " & Environ$("username") & "."
    With xMailItem
        .To = "Email Address"
        .Subject = "Worksheet modified - Update TI Survey Schedule Date"
        .Body = xMailBody
        .Display
    End With
    Application.DisplayAlerts = True
    Application.ScreenUpdating = True
End Sub
Using "Error Resume Next" can create problems because it disables all error messages so if your code errors out, you won't know which line of code is causing the error. It is always best to use error checking instead. Delete that line of code unless it is absolutely necessary for some reason. The same for "Application.DisplayAlerts = False". Usually this code is placed immediately before the line of code that would display the alert and "Application.DisplayAlerts = True" immediately after.
I received a Compile Error at the Range ("AA:AA", etc). Reason was wrong number of arguments or invalid Property assignment. Should these be listed as seperate lines?
 
Upvote 0
Oops!!! Use this line to replace the old one:
VBA Code:
If Intersect(Target, Range("AA:AA, AC:AC, AG:AG, AI:AI, BD:BD, BF:BF, BY:BY, CG:CG, CJ:CJ, DH:DH, DJ:DJ, EB:EB, ED:ED")) Is Nothing Then Exit Sub
 
Upvote 0
That worked wonderfully and you are awesome. One more question. Each one of these status has a site # in column A. How would I include that corresponding site # in the subject line (preferably at the beginning of the subject line)
 
Upvote 0
I'm not sure if I understood correctly. Try this line:
VBA Code:
.Subject = Range("A" & Target.Row).Value & " Worksheet modified - Update TI Survey Schedule Date"
 
Upvote 0
Also, how would I designate the value of "A" that should trigger the email. I think it goes in the line of above but not sure where or the syntax to use.
 
Upvote 0
I'm not sure if I understood correctly. Try this line:
VBA Code:
.Subject = Range("A" & Target.Row).Value & " Worksheet modified - Update TI Survey Schedule Date"
This worked PERFECTLY! Thank you
 
Upvote 0

Forum statistics

Threads
1,215,084
Messages
6,123,024
Members
449,092
Latest member
ikke

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