I have code to email sheet8 on Excel and attach it in Outlook as well as the subject heading and body for the email in Outlook
The only items that the code is not doing , is extracting the email addreses, which are in cells N1:N5 on sheet "Email"
I have set up the subject for the email on sheet "Email" and named this subjectText as well as the body of the email and named this BodyText
It would be appreciated if someone could kindly amend the part of the code that is not extracting the email addresses in the "To" section of microsoft outlook
See my full code below
The only items that the code is not doing , is extracting the email addreses, which are in cells N1:N5 on sheet "Email"
I have set up the subject for the email on sheet "Email" and named this subjectText as well as the body of the email and named this BodyText
It would be appreciated if someone could kindly amend the part of the code that is not extracting the email addresses in the "To" section of microsoft outlook
Code:
.To = Join(Application.Transpose(Sheets("Email").Range("N1:N5").Value), ";")
See my full code below
Code:
Sub Email_Sales_Invoices()
ztext = [bodytext]
Zsubject = [subjectText]
Dim FileExtStr As String
Dim FileFormatNum As Long
Dim Sourcewb As Workbook
Dim Destwb As Workbook
Dim TempFilePath As String
Dim TempFileName As String
Dim OutApp As Object
Dim OutMail As Object
Dim Stringbody As String
With Application
.ScreenUpdating = False
.EnableEvents = False
End With
Set Sourcewb = ActiveWorkbook
'Copy the ActiveSheet to a new workbook
Sheets(8).Copy
Set Destwb = ActiveWorkbook
'Determine the Excel version and file extension/format
With Destwb
If Val(Application.Version) < 12 Then
'You use Excel 97-2003
FileExtStr = ".xls": FileFormatNum = -4143
Else
'You use Excel 2007-2013
Select Case Sourcewb.FileFormat
Case 51: FileExtStr = ".xlsx": FileFormatNum = 51
Case 52:
If .HasVBProject Then
FileExtStr = ".xlsm": FileFormatNum = 52
Else
FileExtStr = ".xlsx": FileFormatNum = 51
End If
Case 56: FileExtStr = ".xls": FileFormatNum = 56
Case Else: FileExtStr = ".xlsb": FileFormatNum = 50
End Select
End If
End With
'Change all cells in the worksheet to values if you want
With Destwb.Sheets(1).UsedRange
.Cells.Copy
.Cells.PasteSpecial xlPasteValues
.Cells(1).Select
End With
Application.CutCopyMode = False
'Save the new workbook/Mail it/Delete it
TempFilePath = Environ$("temp") & ""
SourcewbNoExtn = Left(Sourcewb.Name, InStr(Sourcewb.Name, ".") - 1)
TempFileName = Sourcewb.Name
Set OutApp = CreateObject("Outlook.Application")
Set OutMail = OutApp.CreateItem(0)
With Destwb
.SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum
On Error Resume Next
With OutMail
.To = Join(Application.Transpose(Sheets("Email").Range("N1:N5").Value), ";")
.CC = ""
.BCC = ""
.Subject = Zsubject
.Body = ztext
.Attachments.Add Destwb.FullName
'You can add other files also like this
'.Attachments.Add ("C:\test.txt")
.Display 'Use .send to send automatically or .Display to check email before sending
End With
On Error GoTo 0
.Close savechanges:=False
End With
'Delete the file you have send
Kill TempFilePath & TempFileName & FileExtStr
Set OutMail = Nothing
Set OutApp = Nothing
With Application
.ScreenUpdating = True
.EnableEvents = True
End With
End Sub
Last edited: