Using a macro to select a row of text and email it...

pontybiker

Board Regular
Joined
Oct 27, 2015
Messages
73
Hi,

If possible, I would like the ability to select text from an excel workbook and email it to an email address. The email address would be dependent on what text is in a certain cell.

This is an example of the workbook containing the data (workbook A):
Sport£1£2AAAA
Education£2£2BBBB
Managment£6£1CCCC
Art£4£3DDDD

<tbody>
</tbody>

This is an example of the email workbook (workbook B);
Sportj@j.com
Educationb@j.com
Managementg@j.com
Artk@j.com

<tbody>
</tbody>

So the code would need to email the row of text in workbook A to the email address in workbook B by matching the text in column A in workbook A to the correct email address in column B in workbook B.

I hope this makes sense. I realise this may be asking a lot. As always, I honestly do appreciate anyone's help with these questions.

Kind regards,

J.
 
OK, so I couldn't see anything specifically wrong with your code and even tested it at my end and it seemed to be working as described, including throwing out a message when it comes across a department that doesn't match.

Have a look at the zip file I have posted HERE which contains the test files I used along with a text document containing a slightly modified version of your code. The only change I made was to add the IsFileOpen check to the Telephone-Charges.xlsx workbook.

If you can temporarily replace your actual documents in the C:\Users\sm18441\Documents\Call Logger folder with the ones from my zip file and test to see if it works as described that would be helpful. You will want to change the email address on the emaillist workbook to one you can actually check for mail.

Let me know if that works.
 
Upvote 0

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Yeah, that works perfectly. I will run this against my spreadsheets and see what happens. I'll let you know the outcome.

Once again, thank you so much for taking the time to help me.
 
Upvote 0
Yeah, that works perfectly. I will run this against my spreadsheets and see what happens. I'll let you know the outcome.

Once again, thank you so much for taking the time to help me.
You're most welcome. I hope you get to the bottom of what was causing the anomaly with your own workbooks ;)
 
Upvote 0
Hmm, this is strange when i run the code against my files it sends an email even if the text doesn't exist in workbook B?

I have uploaded the files here just in case it will help you to look at my information.

I'm so sorry to have to trouble you with all this.
 
Upvote 0
By the way, you may notice that the files have test in the name. The actual files have the correct names.

J.
 
Upvote 0
Hmm, this is strange when i run the code against my files it sends an email even if the text doesn't exist in workbook B?

I have uploaded the files here just in case it will help you to look at my information.

I'm so sorry to have to trouble you with all this.
Hi again Jamie,

I will have a look at your workbooks when I get back from lunch and will let you know how I get on :)
 
Upvote 0
I've conducted some further testing and it looks like if the department doesn't exist it uses the email address it last sent a message to? Does that make sense to you?

Sorry for this.
 
Upvote 0
I've conducted some further testing and it looks like if the department doesn't exist it uses the email address it last sent a message to? Does that make sense to you?

Sorry for this.
That is bang on the money mate. I had just figured the same thing myself.

Basically the variable EmailAdd needs to be cleared either at the start or end of each "loop" otherwise regardless of whether or not the department exists the value of EmailAdd is retained and therefore it will send out that row of data.

Replace the main macro with this and it should do the trick. I have highlighted my change in red:

Rich (BB code):
Sub MailWithLookupLoop()
' Defines variables
Dim wb1 As Workbook, wb2 As Workbook, FindString As String, EmailAdd As String, Cell As Range, cRange As Range, lRange As Range
' Disable screen updating to reduce flicker
Application.ScreenUpdating = False


'''SETUP WORKBOOK 1'''
' If Telephone-Charges is not already open (amend file path as required) then...
If Not IsFileOpen("C:\Users\sm18441\Documents\Call Logger\Telephone-Charges.xlsx") Then
    ' Open and Sets wb1 as Telephone-Charges.xlsx (amend file path as required)
    Set wb1 = Workbooks.Open("C:\Users\sm18441\Documents\Call Logger\Telephone-Charges.xlsx")
    ' Re-activate wb1
    wb1.Activate
' Else if EmailList is already open then...
Else
    ' Sets wb1 as Telephone-Charges.xlsx
    Set wb1 = Workbooks("Telephone-Charges.xlsx")
End If
' Defines LastRow1 as the last row of data on wb1 sheet1 based on column A
LastRow1 = wb1.Sheets(1).Cells(Rows.Count, "A").End(xlUp).Row
' Sets the check range as A1 to the last row of A on wb1 sheet1
Set cRange = wb1.Sheets(1).Range("A1:A" & LastRow1)


'''SETUP WORKBOOK 2'''
' If EmailList is not already open (amend file path as required) then...
If Not IsFileOpen("C:\Users\sm18441\Documents\Call Logger\emaillist.xlsx") Then
    ' Open and Sets wb2 as emaillist.xlsx (amend file path as required)
    Set wb2 = Workbooks.Open("C:\Users\sm18441\Documents\Call Logger\emaillist.xlsx")
    ' Re-activate wb1
    wb1.Activate
' Else if EmailList is already open then...
Else
    ' Sets wb2 as emaillist.xlsx
    Set wb2 = Workbooks("emaillist.xlsx")
End If
' Defines LastRow2 as the last row of data of wb2 sheet1 based on column A
LastRow2 = wb2.Sheets(1).Cells(Rows.Count, "A").End(xlUp).Row
' Sets lookup range as A1 to the last row of B on wb2 sheet1
Set lRange = wb2.Sheets(1).Range("A1:B" & LastRow2)


'''START LOOP'''
' For each cell in the check range
For Each Cell In cRange
    ' Sets variable FindString as the contents of the current cell on wb1 sheet1
    FindString = Cell.Value
    ' On error continue
    On Error Resume Next
    ' Sets variable EmailAdd to nothing
    EmailAdd = ""
    ' Sets variable EmailAdd as the corresponding email address based on the FindString on wb2 sheet1
    EmailAdd = Application.WorksheetFunction.VLookup(FindString, lRange, 2, False)
              
'''
'''OPTIONAL MESSAGE IF DEPARTMENT IS NOT FOUND - DELETE THE BELOW SECTION FOR SEAMLESS PROCESSING'''
' If an error is encountered then...
    If Err.Number <> 0 Then
        ' Display message that the department was not found and move on
        MsgBox FindString & " department not found.  Moving on."
    End If
'''END OF OPTIONAL MESSAGE PART - DELETE THE ABOVE SECTION FOR SEAMLESS PROCESSING'''
'''


    ' If EmailAdd is not blank then
    If EmailAdd <> "" Then
        ' Select the range of cells on the ws1 as this is what will be emailed
        wb1.Sheets(1).Range("A" & Cell.Row, "D" & Cell.Row).Select
        ' Show the envelope on the ActiveWorkbook
        ActiveWorkbook.EnvelopeVisible = True
        With ActiveSheet.MailEnvelope
            ' Sets the optional introduction fields thats adds
           .Introduction = "This is what will be in the opening of your email"
           ' Send to the email address in EmailAdd
           .Item.To = EmailAdd
           ' Define your desired subject line
           .Item.Subject = "Your chosen email subject"
           ' Send the email
           .Item.Send
        End With
    End If
' Check next cell in check range
Next Cell
'''END LOOP'''


' Re-enable screen updating
Application.ScreenUpdating = True
' Display message box to confirm the process has completed
MsgBox "All mails sent."


End Sub
 
Upvote 0
That's great, it works perfectly.

I have two more things I'd like to add to it but I feel I've asked too much of you already. Let me know if you have time or if you have had enough.

I know I have said it several times but really, this is going to help me so much with my job.

J.
 
Upvote 0

Forum statistics

Threads
1,215,310
Messages
6,124,187
Members
449,147
Latest member
sweetkt327

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