XL2000: How to Send Form Mail That Uses Excel Data

Article translations Article translations
Article ID: 241498 - View products that this article applies to.
This article was previously published under Q241498
Expand all | Collapse all

SUMMARY

This article contains a Microsoft Visual Basic for Applications macro for Excel that uses Microsoft Outlook 2000 to generate and send a form e-mail to individuals that are listed in an Excel worksheet.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements. This macro assumes the following:
  • E-mail addresses are in column A.
  • Names are in column B.
  • Cells A1 and B1 contain headers.
To create the macro:
  1. Start Excel. Create a new workbook, and open the Visual Basic editor (press ALT+F11).
  2. On the Insert menu, click Module.
  3. On the Tools menu, click References.
  4. In the Available References list, click to select the Microsoft Outlook 9.0 Object Library check box. Click OK.
  5. Type the following code into the code module:
    '--- Set up the Outlook objects.
    Dim objOutlook As Outlook.Application
    Dim objOutlookMsg As Outlook.MailItem
    Dim objOutlookRecip As Outlook.Recipient
    Dim objOutlookAttach As Outlook.Attachment
    
    '--- Declare our global variables to be used in each subroutine.
    Dim CustomerAddress As String
    Dim CustomerMessage As String
    
    Sub MailItNow()
    
    '--- Declare our variables.
    Dim X As Integer
    Dim TempCustomerAddress As String
    
    '--- Prevent screen redraws until the macro is finished.
    Application.ScreenUpdating = False
    
    '--- Sort the addresses and names alphabetically, by the e-mail address.
    '--- This is REQUIRED to prevent any duplicate addresses from
    '    receiving more than one e-mail.
     
    Columns("A:B").Select
    Selection.Sort Key1:=Range("A2"), Order1:=xlAscending, Header:=xlGuess, _
        OrderCustom:=1, MatchCase:=False, Orientation:=xlTopToBottom
    
    '--- Sets which row to start searching for e-mail addresses and names.
    X = 2
    
    '--- Begin looping through all the e-mail addresses in column A until
    '    a blank cell is hit.
    While Range("A" & X).Text <> ""
    
        '--- These variables will be used to search for duplicates.
        CustomerAddress = Range("A" & X).Text
        TempCustomerAddress = CustomerAddress
           
        '--- Increment X until a different e-mail address is found.
        While TempCustomerAddress = CustomerAddress
            X = X + 1
            CustomerAddress = Range("A" & X).Text
        Wend
        
        '--- Add the e-mail address to a global variable.
        CustomerAddress = Range("A" & X - 1).Text
        '--- Add a message with the user's name to the e-mail.
        '--- Customize your own message and closing here.
        CustomerMessage = Range("B" & X - 1).Text & "," & vbCrLf & vbCrLf _
           & "Thank you for trying our product!" & vbCrLf & vbCrLf & _
           "Sincerely," & vbCrLf & "ProductCo Inc."
            
        '--- Run the subroutine to send the message.
        Call SendMessage
    
    Wend
    
    End Sub
    
    Sub SendMessage(Optional AttachmentPath)
        
        '--- This is required to prevent a name which does not resolve to
        '    an e-mail address from hanging the app.
        On Error Resume Next
        
        ' Create the Outlook session.
        Set objOutlook = CreateObject("Outlook.Application")
        
        ' Create the message.
        Set objOutlookMsg = objOutlook.CreateItem(olMailItem)
        
        With objOutlookMsg
            ' Add the To recipient(s) to the message.
            Set objOutlookRecip = .Recipients.Add(CustomerAddress)
            objOutlookRecip.Type = olTo
            
            ' Set the Subject, Body, and Importance of the message.
            .Subject = "Thank You!"
            .Body = CustomerMessage
            .Importance = olImportanceHigh  'High importance
            
            ' Add attachments to the message.
            If Not IsMissing(AttachmentPath) Then
                Set objOutlookAttach = .Attachments.Add(AttachmentPath)
            End If
            
            ' Resolve each Recipient's name.
            For Each objOutlookRecip In .Recipients
                objOutlookRecip.Resolve
                If Not objOutlookRecip.Resolve Then
                Exit Sub
            End If
            Next
            .Send '--- Send the message.
        
        End With
        
        '--- Remove the message and Outlook application from memory.
        Set objOutlookMsg = Nothing
        Set objOutlook = Nothing
    End Sub
    
    					
  6. On the File menu, click Close and Return to Microsoft Excel.
  7. To run the code, make sure the address database sheet is active. On the Tools menu, point to Macro, and click Macros. Click MailItNow, and then click Run.

REFERENCES

For more information about how to use the sample code in this article, click the article number below to view the article in the Microsoft Knowledge Base:
212536 OFF2000: How to Run Sample Code from Knowledge Base Articles

Properties

Article ID: 241498 - Last Review: October 11, 2006 - Revision: 4.2
APPLIES TO
  • Microsoft Excel 2000 Standard Edition
Keywords: 
kbdtacode kbhowto KB241498

Give Feedback

 

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com