Results 1 to 10 of 10

Thread: Macro For Sending Multiple Attachments In Bulk Mail Via Outlook

  1. #1
    Junior Member
    Join Date
    Oct 2013
    Posts
    5
    Rep Power
    0

    Macro For Sending Multiple Attachments In Bulk Mail Via Outlook

    Hi,

    I am using the macro file where it is possible to send bulk mails along with multiple attachement.

    I am getting error while sending multiple attachments while it is working fine if i am attaching only one file.

    Somebody Pl help.

    Regatds,
    Amandeep Singh
    Attached Files Attached Files

  2. #2
    Administrator Excel Fox's Avatar
    Join Date
    Mar 2011
    Posts
    1,402
    Rep Power
    10
    Option Explicit

    Code:
    Function SendMessage(strTo As String, Optional strCC As String, Optional strBCC As String, Optional strSubject As String, Optional strMessage As String, Optional rngToCopy As Range, Optional strAttachmentPath As String, Optional blnShowEmailBodyWithoutSending As Boolean = False, Optional blnSignature As Boolean)
         
        Dim objOutlook As Object 'Outlook.Application
        Dim objOutlookMsg As Object 'Outlook.MailItem
        Dim objOutlookRecip As Object 'Outlook.Recipient
        Dim objOutlookAttach As Object 'Outlook.Attachment
        Dim lngLoop As Long
        Dim strSignature As String
         
        If Trim(strTo) & Trim(strCC) & Trim(strBCC) = "" Then
            MsgBox "Please provide a mailing address!", vbInformation + vbOKOnly, "Missing mail information"
            Exit Function
        End If
        
        'Create the Outlook session.
        On Error Resume Next
        Set objOutlook = GetObject(, "Outlook.Application." & Val(Application.Version))
        Err.Clear: On Error GoTo -1: On Error GoTo 0
        If objOutlook Is Nothing Then
            Set objOutlook = CreateObject("Outlook.Application." & Val(Application.Version))
        End If
         
        'Create the message.
        Set objOutlookMsg = objOutlook.CreateItem(0)
    
    
        With objOutlookMsg
            
            'Add the To recipient(s) to the message.
            For lngLoop = LBound(Split(strTo, ";")) To UBound(Split(strTo, ";"))
                If Trim(Split(strTo, ";")(lngLoop)) <> "" Then
                    Set objOutlookRecip = .Recipients.Add(Trim(Split(strTo, ";")(lngLoop)))
                    objOutlookRecip.Type = 1 'olTO
                End If
            Next lngLoop
             
            'Add the CC recipient(s) to the message.
            For lngLoop = LBound(Split(strCC, ";")) To UBound(Split(strCC, ";"))
                If Trim(Split(strCC, ";")(lngLoop)) <> "" Then
                    Set objOutlookRecip = .Recipients.Add(Trim(Split(strCC, ";")(lngLoop)))
                    objOutlookRecip.Type = 2 'olCC
                End If
            Next lngLoop
             
            'Add the BCC recipient(s) to the message.
            For lngLoop = LBound(Split(strBCC, ";")) To UBound(Split(strBCC, ";"))
                If Trim(Split(strBCC, ";")(lngLoop)) <> "" Then
                    Set objOutlookRecip = .Recipients.Add(Trim(Split(strBCC, ";")(lngLoop)))
                    objOutlookRecip.Type = 3 'olBCC
                End If
            Next lngLoop
             
            'Set the Subject, Body, and Importance of the message.
            If strSubject = "" Then
                strSubject = "This is an Automation test with Microsoft Outlook"
            End If
            .Subject = strSubject
            If strMessage = "" Then
                strMessage = "This is the body of the message." & vbCrLf & vbCrLf
            End If
            .Importance = 2 'High importance
            If Not strMessage = "" Then
                .Body = strMessage & vbCrLf & vbCrLf
            End If
            
            If Not rngToCopy Is Nothing Then
                .HTMLBody = .Body & RangetoHTML(rngToCopy)
            End If
             
            'Add attachments to the message.
            For lngLoop = LBound(Split(strAttachmentPath, "|")) To UBound(Split(strAttachmentPath, "|"))
            If Not strAttachmentPath = "" Then
                If Len(Dir(Trim(Split(strAttachmentPath, "|")(lngLoop)))) <> 0 Then
                    Set objOutlookAttach = .Attachments.Add(Trim(Split(strAttachmentPath, "|")(lngLoop)))
                Else
                    MsgBox "Unable to find the specified attachment '" & Trim(Split(strAttachmentPath, "|")(lngLoop)) & "'. Sending mail anyway."
                End If
            End If
            Next lngLoop
            
            If blnSignature Then
                'Win XP
                strSignature = Environ("USERPROFILE") & "\Application Data\Microsoft\Signatures\*.htm"
                strSignature = Environ("USERPROFILE") & "\Application Data\Microsoft\Signatures\" & Dir(strSignature)
                If Dir(strSignature) = "" Then
                'Win 7
                    strSignature = Environ("USERPROFILE") & "\AppData\Roaming\Microsoft\Signatures\*.htm"
                    strSignature = Environ("USERPROFILE") & "\AppData\Roaming\Microsoft\Signatures\" & Dir(strSignature)
                End If
            End If
             
            If Dir(strSignature) <> "" Then
                strSignature = GetBoiler(strSignature)
            Else
                strSignature = ""
            End If
            
            'MsgBox .htmlbody
            .HTMLBody = .HTMLBody & strSignature
                
            'Resolve each Recipient's name.
            For Each objOutlookRecip In .Recipients
                objOutlookRecip.Resolve
            Next
             
            'Should we display the message before sending?
            If blnShowEmailBodyWithoutSending Then
                .Display
            Else
                .Display
                .Save
                .Send
            End If
        End With
         
        Set objOutlook = Nothing
        Set objOutlookMsg = Nothing
        Set objOutlookAttach = Nothing
        Set objOutlookRecip = Nothing
         
    End Function
    
    
    Function RangetoHTML(rng As Range)
    
    
        'Works in Excel 2000, Excel 2002, Excel 2003, Excel 2007, Excel 2010, Outlook 2000, Outlook 2002, Outlook 2003, Outlook 2007, and Outlook 2010.
        Dim strTempFile As String
        Dim wbkTemp As Workbook
    
    
        strTempFile = Environ$("temp") & Application.PathSeparator & Format(Now, "dd-mm-yy h-mm-ss") & ".htm"
     
        'Copy the range and create a workbook to receive the data.
        rng.Copy
        Set wbkTemp = Workbooks.Add(1)
        With wbkTemp.Sheets(1)
            With .Cells(1)
                .PasteSpecial Paste:=8
                .PasteSpecial xlPasteValues, , False, False
                .PasteSpecial xlPasteFormats, , False, False
                .Select
            End With
            Application.CutCopyMode = False
            On Error Resume Next
                .DrawingObjects.Visible = True
                .DrawingObjects.Delete
            Err.Clear: On Error GoTo 0
        End With
     
        'Publish the sheet to an .htm file.
        With wbkTemp.PublishObjects.Add( _
             SourceType:=xlSourceRange, _
             Filename:=strTempFile, _
             Sheet:=wbkTemp.Sheets(1).Name, _
             Source:=wbkTemp.Sheets(1).UsedRange.Address, _
             HtmlType:=xlHtmlStatic)
            .Publish (True)
        End With
     
        'Read all data from the .htm file into the RangetoHTML subroutine.
        RangetoHTML = GetBoiler(strTempFile)
        RangetoHTML = Replace(RangetoHTML, "align=center x:publishsource=", _
                              "align=left x:publishsource=")
     
        'Close wbkTemp
        wbkTemp.Close savechanges:=False
     
        'Delete the htm file.
        Kill strTempFile
     
        Set wbkTemp = Nothing
        
    End Function
    
    
    Function GetBoiler(ByVal strFile As String) As String
    
    
        'May not be supported in MAC
        Dim objFSO As Object
        Dim objTextStream As Object
        On Error Resume Next
        Set objFSO = CreateObject("Scripting.FileSystemObject")
        Set objTextStream = objFSO.GetFile(strFile).OpenAsTextStream(1, -2)
        GetBoiler = objTextStream.ReadAll
        objTextStream.Close
        
        Set objFSO = Nothing
        Set objTextStream = Nothing
        
    End Function
    Last edited by Excel Fox; 10-17-2013 at 11:42 AM. Reason: Edit: Note the red pipes
    A dream is not something you see when you are asleep, but something you strive for when you are awake.

    It's usually a bad idea to say that something can't be done.

    The difference between dream and aim, is that one requires soundless sleep to see and the other requires sleepless efforts to achieve

    Join us at Facebook

  3. #3
    Junior Member
    Join Date
    Oct 2013
    Posts
    5
    Rep Power
    0
    Not working. Same Error.

  4. #4
    Administrator Excel Fox's Avatar
    Join Date
    Mar 2011
    Posts
    1,402
    Rep Power
    10
    What have you used in Range E2?
    A dream is not something you see when you are asleep, but something you strive for when you are awake.

    It's usually a bad idea to say that something can't be done.

    The difference between dream and aim, is that one requires soundless sleep to see and the other requires sleepless efforts to achieve

    Join us at Facebook

  5. #5
    Junior Member
    Join Date
    Oct 2013
    Posts
    5
    Rep Power
    0
    Sir,

    There is one folder in D Drive "TEST"

    In this folder there are 2 files:

    Manoj.xlsx
    Aman.xlsx

    in e2 i m putting manoj.xlsx,aman.xlsx (without any space)

  6. #6
    Administrator Excel Fox's Avatar
    Join Date
    Mar 2011
    Posts
    1,402
    Rep Power
    10
    And what's the result of the formula in F2?
    A dream is not something you see when you are asleep, but something you strive for when you are awake.

    It's usually a bad idea to say that something can't be done.

    The difference between dream and aim, is that one requires soundless sleep to see and the other requires sleepless efforts to achieve

    Join us at Facebook

  7. #7
    Administrator Excel Fox's Avatar
    Join Date
    Mar 2011
    Posts
    1,402
    Rep Power
    10
    Made some modification to the code above.. try it now.
    A dream is not something you see when you are asleep, but something you strive for when you are awake.

    It's usually a bad idea to say that something can't be done.

    The difference between dream and aim, is that one requires soundless sleep to see and the other requires sleepless efforts to achieve

    Join us at Facebook

  8. #8
    Junior Member
    Join Date
    Oct 2013
    Posts
    5
    Rep Power
    0
    Thanks Sir,

    Now its working fine. One more requirement.

    Whatever i am writing in message box, it comes in one line.

    Can we make the changes in macro so that "Dear Sir" reflect in 1st line. after that it takes enter then the message in next line and so on..

  9. #9
    Administrator Excel Fox's Avatar
    Join Date
    Mar 2011
    Posts
    1,402
    Rep Power
    10
    Why don't you enter a line between in the cell itself? Use ALT+ENTER to enter a line.
    A dream is not something you see when you are asleep, but something you strive for when you are awake.

    It's usually a bad idea to say that something can't be done.

    The difference between dream and aim, is that one requires soundless sleep to see and the other requires sleepless efforts to achieve

    Join us at Facebook

  10. #10
    Junior Member
    Join Date
    Oct 2013
    Posts
    5
    Rep Power
    0
    I have already made the ALT + Enter but it is not working.

    It is showing in single line only.

Similar Threads

  1. Replies: 26
    Last Post: 10-22-2019, 02:39 PM
  2. Replies: 5
    Last Post: 06-11-2013, 08:15 PM
  3. Replies: 4
    Last Post: 03-01-2013, 10:48 PM
  4. Replies: 2
    Last Post: 01-07-2013, 04:34 PM
  5. Replies: 7
    Last Post: 05-09-2012, 11:34 PM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •