XL: Automation Example with Microsoft Word and Microsoft Outlook (213712)



The information in this article applies to:

  • Microsoft Office Excel 2003
  • Microsoft Excel 2002
  • Microsoft Excel 2000
  • Microsoft Excel 97 for Windows

This article was previously published under Q213712

SUMMARY

It is possible to create a Visual Basic for Applications macro that uses data from a Microsoft Word document and a Microsoft Excel workbook to send messages from Microsoft Outlook. This article contains an example of one way that you can do this.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals 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 needs. If you have limited programming experience, you may want to contact a Microsoft Certified Partner or the Microsoft fee-based consulting line at (800) 936-5200. For more information about Microsoft Certified Partners, please visit the following Microsoft Web site: For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
The following example assumes that there are two defined names in the worksheet:
  • The first defined name, "subjectcell", refers to a cell that contains the message subject line (for example, "This is a test message.").
  • The second defined name, "tolist", refers to the first cell in the horizontal list that contains a list of recipients (for example, "John Doe", "Jane Doe", and so forth).
You must also have a Microsoft Word document. The text of this document is used by the macro as the message body of your mail message.

Sub SendOutlookMessages()

 'Dimension variables.
 Dim OL As Object, MailSendItem As Object
 Dim W As Object
 Dim MsgTxt As String, SendFile As String
 Dim ToRangeCounter As Variant

 'Identifies Word file to send
 SendFile = Application.GetOpenFilename(Title:="Select MS Word " & _
     "file to mail, then click 'Open'", buttontext:="Send", _
     MultiSelect:=False)

 'Starts Word session
 Set W = GetObject(SendFile)

 'Pulls text from file for message body
 MsgTxt = W.Range(Start:=W.Paragraphs(1).Range.Start, _
    End:=W.Paragraphs(W.Paragraphs.Count).Range.End)

 'Ends Word session
 Set W = Nothing

 'Starts Outlook session
 Set OL = CreateObject("Outlook.Application")
 Set MailSendItem = OL.CreateItem(olMailItem)

 ToRangeCounter = 0

 'Identifies number of recipients for To list.
 For Each xCell In ActiveSheet.Range(Range("tolist"), _
     Range("tolist").End(xlToRight))
     ToRangeCounter = ToRangeCounter + 1
 Next xCell

 If ToRangeCounter = 256 Then ToRangeCounter = 1

 'Creates message
 With MailSendItem
     .Subject = ActiveSheet.Range("subjectcell").Text
     .Body = MsgTxt

     'Creates "To" list
     For Each xRecipient In Range("tolist").Resize(1, ToRangeCounter)
         RecipientList = RecipientList & ";" & xRecipient
     Next xRecipient

     .To = RecipientList
     .Send
 End With

 'Ends Outlook session
 Set OL = Nothing

End Sub
				

Modification Type:MajorLast Reviewed:5/4/2005
Keywords:kbhowto kbinterop kbProgramming KB213712