Email Macro not extractimng Name & Email address

howard

Well-known Member
Joined
Jun 26, 2006
Messages
6,595
Office Version
  1. 2021
Platform
  1. Windows
I have the following macro below which extract sheet 'Imported assets' and attaches it to outlook but without the email address/s

I have the email addresses in S1 to S5 on sheet7


I would like the macro amended so as to extract the email address from sheet 7 which is in S1 to S5

Sheet "Imported Assets" is deleted each month and then recreated via a macro


It would be appreciated if someone could assist me


Code:
 Sub Email_ImportedAssets()
ztext = [bodytext]                              'read in text from named cell
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

    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With

    Set Sourcewb = ActiveWorkbook

    'Copy the ActiveSheet to a new workbook
    Sheets("Imported Assets").Select
    ActiveSheet.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-2016
            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") & "\"
    TempFileName = "Part of " & Sourcewb.Name & " " & Format(Now, "dd-mmm-yy h-mm-ss")

    Set OutApp = CreateObject("Outlook.Application")
    Set OutMail = OutApp.CreateItem(0)

    With Destwb
        .SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum
        On Error Resume Next
        With OutMail
        With Sheets(7)
          .To = Range("S1").Value
            
            .CC = Join(Application.Transpose(Range("S2:S5").Value), ";")
            
            .BCC = ""
            .Subject = Zsubject
           .Body = ztext
          End With

            .Attachments.Add Destwb.FullName
            'You can add other files also like this
            '.Attachments.Add ("C:\test.txt")
            .Display  'or use .Display
        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
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
Try replacing...

Code:
[COLOR=#574123]        With OutMail
[/COLOR]        With Sheets(7)
          .To = Range("S1").Value
            
            .CC = Join(Application.Transpose(Range("S2:S5").Value), ";")
            
            .BCC = ""
            .Subject = Zsubject
           .Body = ztext
          End With

            .Attachments.Add Destwb.FullName
            'You can add other files also like this
            '.Attachments.Add ("C:\test.txt")
            .Display  'or use .Display
 [COLOR=#574123]        End With[/COLOR]

with

Code:
    With OutMail
        .To = Sheets(7).Range("S1").Value
        .CC = Join(Application.Transpose(Sheets(7).Range("S2:S5").Value), ";")
        .BCC = ""
        .Subject = Zsubject
        .Body = ztext
        .Attachments.Add Destwb.FullName
        'You can add other files also like this
        '.Attachments.Add ("C:\test.txt")
        .Display  'or use .Send
    End With

Hope this helps!
 
Upvote 0
I've written it now so I'm posting it.

As I understand it references inside a With begin with a full stop so it indicates it refers to the With object. In this case Sheets(7).
Otherwise in your case when you use Range("S1").Value you refer to a range on the active worksheet and not the one specified as the With object.

Code:
With Sheets(7)
            .To = .Range("S1").Value     'refers to Sheets(7).Range("S1").Value      
            .CC = Join(Application.Transpose(.Range("S2:S5").Value), ";") ' as above
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,910
Messages
6,175,320
Members
452,635
Latest member
laura12345

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