Hello Josh,
No disrespect to John but I have never seen any code to do what you want. The attached workbook is an automated version of your original based on your requirements.
I have added a second sheet that contains a list of the reps and their email addresses. There is a button on this sheet that will send an email to each rep in the list after the first sheet is filtered by the rep's name.
You will need to change the subject line of the email macro "SendEmails" to what you want. It is highlighted in blue font. Here are the macros that have been added to the attached workbook.
Sub EmailFilteredRange(ByVal Recipient As String, ByVal Subject As String)
' Written: October 24, 2013
' Author: Leith Ross
' Summary: Emails a filtered range in HTML format using Outlook.
Dim Area As Range
Dim cnt As Long
Dim Data() As Byte
Dim HTMLcode As String
Dim olApp As Object
Dim Rng As Range
Dim TempFile As String
Dim Wks As Worksheet
' Get all of the cells in the filter area.
Set Rng = Sheet1.Range("A1").CurrentRegion
' Include the sub total row.
Set Rng = Rng.Resize(Rng.Rows.Count + 2)
' Get cells only filtered cells and sub total row.
Set Rng = Intersect(Rng, Sheet1.Cells.SpecialCells(xlCellTypeVisible))
' Copy the worksheet to create a new workbook.
Sheet1.Copy
Set Wks = ActiveSheet
' Turn off the AutoFilters.
Wks.AutoFilterMode = False
' Clear the new worksheet except for the header row.
Wks.UsedRange.Offset(1, 0).ClearContents
' Create a contiguous range on the new worksheet to be emailed.
For Each Area In Rng.Areas
Wks.Range("A1").Offset(cnt, 0).Resize(Area.Rows.Count, Area.Columns.Count).Value = Area.Value
cnt = cnt + Area.Rows.Count
Next Area
' This is the contiguous range of cells to email.
Set Rng = Wks.Range("A1").CurrentRegion
Set Rng = Rng.Resize(RowSize:=Rng.Rows.Count + 2)
' The new workbook will be saved to the user's Temp directoy
TempFile = Environ("Temp") & "\" & Wks.Name & ".htm"
' If a file by this exists then delete it
If Dir(TempFile) <> "" Then Kill TempFile
' Convert the new worksheet into an HTML file.
With Wks.Parent.PublishObjects
.Add(SourceType:=xlSourceRange, _
Filename:=TempFile, Sheet:=Wks.Name, _
Source:=Rng.Address, HtmlType:=xlHtmlStatic) _
.Publish Create:=True
End With
' Read the TempFile back as a byte array.
Open TempFile For Binary Access Read As #1
ReDim Data(LOF(1))
Get #1, , Data
Close #1
' Convert the byte array into a VBA string.
HTMLcode = StrConv(Data, vbUnicode)
' Close the new workbook.
Wks.Parent.Close SaveChanges:=False
' Change the HTML code to align the output on the left side of the page.
HTMLcode = VBA.Replace(HTMLcode, "align=center x:publishsource=", "align=left x:publishsource=")
' Start Outlook and send the email.
Set olApp = CreateObject("Outlook.Application")
olApp.Session.GetDefaultFolder (6)
With olApp.CreateItem(0)
.To = Recipient
.Subject = Subject
.BodyFormat = 2
.HTMLBody = HTMLcode
.Send
End With
End Sub
Sub SendEmails()
Dim Cell As Range
Dim Rng As Range
Dim Subj As String
Dim Wks As Worksheet
' Change this to what you want the subject line to be.
Subj = "This is subject line of the email."
Set Wks = Sheet2
Wks.AutoFilterMode = False
Set Rng = Wks.Range("A2")
LastRow = Wks.Cells(Rows.Count, "A").End(xlUp).Row
If LastRow < Rng.Row Then Exit Sub
Set Rng = Rng.Resize(RowSize:=LastRow - Rng.Row + 1)
For Each Cell In Rng
If Cell.Offset(0, 1) <> "" Then
Sheet1.AutoFilterMode = False
Sheet1.UsedRange.AutoFilter Field:=1, Criteria1:=Cell.Value, VisibleDropDown:=True
Call EmailFilteredRange(Cell.Offset(0, 1).Text, Subj)
Else
MsgBox Cell & " has No Email Address.", vbExclamation
End If
Next Cell
End Sub
Bookmarks