Back to jkp-ads.com |
Ron de Bruin
|
Ron de Bruin decided to remove all Windows Excel content from his website for personal reasons. If you want to know why, head over to rondebruin.nl.
Luckily, Ron was kind enough to allow me to publish all of his Excel content here.
Most of these pages are slightly outdated and may contain links that don 't work. Please inform me if you find such an error and I'll try to fix it.
Kind regards
Jan Karel Pieterse
Important read this :
The code on this page is only working when you use Outlook as your mail
program.
Copy the code in a Standard module of your workbook, if you just
started with VBA see this page.
Where do I paste
the code that I find on the internet
Check out this Tip page for changing the code on this page.
Tips for changing the code examples
Important :
1) The
code is not working if your data is a List(Excel 2003) or Table(Excel
2007-2016)
2) The first row in the range must have
Headers
3) Turn off AutoFilter before you use the code
4) Be sure that the sheet with the data is the active
worksheet
In your worksheet you must have:
In column A
: Names of the students or ?
In column B:H :
Information about the student or ?
We filter the range A1:H? for
every unique name in the name column (column A in this example). For every
unique name we create a new mail with only the data of that person and send
it to the mail address it find with the VLookup function in the worksheet
"Mailinfo".
Important: You must create this
worksheet manual and add the names and mail addresses one time.
Add a
worksheet to your workbook with the name "Mailinfo" with in column A the
names
and in column B the mail addresses of every possible person in
your Name column..
How do I Change filter range and filter column? :
In this example I use the filter range A1:H? (we use all the rows on the
sheet)
You can change the filter range and filter column in this two code
lines in the macro.
Set FilterRange =
Ash.Range("A1:H" & Ash.Rows.Count)
FieldNum = 1 'Filter column = A
because the filter range start in A
Tip : For
testing I use .Display, change it to .Send if it is working OK.
Note: This example use the function RangetoHTML, copy this
function together
with the macro in a Standard module of your workbook.
You can find the
RangetoHTML function below the second example on this
page.
Sub Send_Row_Or_Rows_1() 'For Tips see: https://jkp-ads.com/rdb/win/winmail/Outlook/tips.htm 'Don't forget to copy the function RangetoHTML in the module. 'Working in Excel 2000-2016 Dim OutApp As Object Dim OutMail As Object Dim rng As Range Dim Ash As Worksheet Dim Cws As Worksheet Dim Rcount As Long Dim Rnum As Long Dim FilterRange As Range Dim FieldNum As Integer Dim mailAddress As String On Error GoTo cleanup Set OutApp = CreateObject("Outlook.Application") With Application .EnableEvents = False .ScreenUpdating = False End With 'Set filter sheet, you can also use Sheets("MySheet") Set Ash = ActiveSheet 'Set filter range and filter column (Column with names) Set FilterRange = Ash.Range("A1:H" & Ash.Rows.Count) FieldNum = 1 'Filter column = A because the filter range start in A 'Add a worksheet for the unique list and copy the unique list in A1 Set Cws = Worksheets.Add FilterRange.Columns(FieldNum).AdvancedFilter _ Action:=xlFilterCopy, _ CopyToRange:=Cws.Range("A1"), _ CriteriaRange:="", Unique:=True 'Count of the unique values + the header cell Rcount = Application.WorksheetFunction.CountA(Cws.Columns(1)) 'If there are unique values start the loop If Rcount >= 2 Then For Rnum = 2 To Rcount 'Filter the FilterRange on the FieldNum column FilterRange.AutoFilter Field:=FieldNum, _ Criteria1:=Cws.Cells(Rnum, 1).Value 'Look for the mail address in the MailInfo worksheet mailAddress = "" On Error Resume Next mailAddress = Application.WorksheetFunction. _ VLookup(Cws.Cells(Rnum, 1).Value, _ Worksheets("Mailinfo").Range("A1:B" & _ Worksheets("Mailinfo").Rows.Count), 2, False) On Error GoTo 0 If mailAddress <> "" Then With Ash.AutoFilter.Range On Error Resume Next Set rng = .SpecialCells(xlCellTypeVisible) On Error GoTo 0 End With Set OutMail = OutApp.CreateItem(0) On Error Resume Next With OutMail .to = mailAddress .Subject = "Test mail" .HTMLBody = RangetoHTML(rng) .Display 'Or use Send End With On Error GoTo 0 Set OutMail = Nothing End If 'Close AutoFilter Ash.AutoFilterMode = False Next Rnum End If cleanup: Set OutApp = Nothing Application.DisplayAlerts = False Cws.Delete Application.DisplayAlerts = True With Application .EnableEvents = True .ScreenUpdating = True End With End Sub
Important :
1) The
code is not working if your data is a List(Excel 2003) or Table(Excel
2007-2016)
2) The first row in the range must have
Headers
3) Turn off AutoFilter before you use the code
4) Be sure that the sheet with the data is the active
worksheet
In your worksheet you must have:
In column A
: Names of the students or ?
In column B : E-mail
addresses
In column C:H : Information about the student
or ?
Note: Every row must have a mail address in
column B
We filter the range A1:H? for every unique mail address in
column B.
For every unique mail address we create a new mail with only
the records
with that mail address and send it to that mail address.
How do I Change filter range and filter column? :
In this example I
use the filter range A1:H? (we use all the rows on the sheet)
You can
change the filter range and filter column in this two code lines in the
macro.
Set FilterRange = Ash.Range("A1:H" &
Ash.Rows.Count)
FieldNum = 2 'Filter column = B because the filter
range start in A
Tip : For testing I use .Display,
change it to .Send if it is working OK.
Note: This
example use the function RangetoHTML, copy this function together
with
the macro in a Standard module of your workbook. You can find the
RangetoHTML function below the example below.
Sub Send_Row_Or_Rows_2() 'For Tips see: https://jkp-ads.com/rdb/win/winmail/Outlook/tips.htm 'Don't forget to copy the function RangetoHTML in the module. 'Working in Excel 2000-2016 Dim OutApp As Object Dim OutMail As Object Dim rng As Range Dim Ash As Worksheet Dim Cws As Worksheet Dim Rcount As Long Dim Rnum As Long Dim FilterRange As Range Dim FieldNum As Integer On Error GoTo cleanup Set OutApp = CreateObject("Outlook.Application") With Application .EnableEvents = False .ScreenUpdating = False End With 'Set filter sheet, you can also use Sheets("MySheet") Set Ash = ActiveSheet 'Set filter range and filter column (column with e-mail addresses) Set FilterRange = Ash.Range("A1:H" & Ash.Rows.Count) FieldNum = 2 'Filter column = B because the filter range start in column A 'Add a worksheet for the unique list and copy the unique list in A1 Set Cws = Worksheets.Add FilterRange.Columns(FieldNum).AdvancedFilter _ Action:=xlFilterCopy, _ CopyToRange:=Cws.Range("A1"), _ CriteriaRange:="", Unique:=True 'Count of the unique values + the header cell Rcount = Application.WorksheetFunction.CountA(Cws.Columns(1)) 'If there are unique values start the loop If Rcount >= 2 Then For Rnum = 2 To Rcount 'Filter the FilterRange on the FieldNum column FilterRange.AutoFilter Field:=FieldNum, _ Criteria1:=Cws.Cells(Rnum, 1).Value 'If the unique value is a mail addres create a mail If Cws.Cells(Rnum, 1).Value Like "?*@?*.?*" Then With Ash.AutoFilter.Range On Error Resume Next Set rng = .SpecialCells(xlCellTypeVisible) On Error GoTo 0 End With Set OutMail = OutApp.CreateItem(0) On Error Resume Next With OutMail .to = Cws.Cells(Rnum, 1).Value .Subject = "Test mail" .HTMLBody = RangetoHTML(rng) .Display 'Or use Send End With On Error GoTo 0 Set OutMail = Nothing End If 'Close AutoFilter Ash.AutoFilterMode = False Next Rnum End If cleanup: Set OutApp = Nothing Application.DisplayAlerts = False Cws.Delete Application.DisplayAlerts = True With Application .EnableEvents = True .ScreenUpdating = True End With End Sub
If you want to add a few text lines above the HTML body you can add this
to the macro. Note: This is not working if Word is your mail editor in
Outlook 2000-2003, you can change this setting in Outlook:
Tools>Options>…Mail Format tab
Add this Dim line
Dim StrBody As String
Build the string you want to add
StrBody = "This is line 1" & "<br>" & _ "This is line 2" & "<br>" & _ "This is line 3" & "<br><br><br>"
Or use this for cell values from Sheet2
StrBody = Sheets("Sheet2").Range("A1").Value & "<br>" & _ Sheets("Sheet2").Range("A2").Value & "<br>" & _ Sheets("Sheet2").Range("A3").Value & "<br><br><br>"
And change the HTMLBody line to this
.HTMLBody = StrBody & RangetoHTML(rng)
Copy this function also in a standard module in your workbook, the macros will not work without it.
Function RangetoHTML(rng As Range) ' Changed by Ron de Bruin 28-Oct-2006 ' Working in Office 2000-2016 Dim fso As Object Dim ts As Object Dim TempFile As String Dim TempWB As Workbook TempFile = Environ$("temp") & "/" & Format(Now, "dd-mm-yy h-mm-ss") & ".htm" 'Copy the range and create a new workbook to past the data in rng.Copy Set TempWB = Workbooks.Add(1) With TempWB.Sheets(1) .Cells(1).PasteSpecial Paste:=8 .Cells(1).PasteSpecial xlPasteValues, , False, False .Cells(1).PasteSpecial xlPasteFormats, , False, False .Cells(1).Select Application.CutCopyMode = False On Error Resume Next .DrawingObjects.Visible = True .DrawingObjects.Delete On Error GoTo 0 End With 'Publish the sheet to a htm file With TempWB.PublishObjects.Add( _ SourceType:=xlSourceRange, _ Filename:=TempFile, _ Sheet:=TempWB.Sheets(1).Name, _ Source:=TempWB.Sheets(1).UsedRange.Address, _ HtmlType:=xlHtmlStatic) .Publish (True) End With 'Read all data from the htm file into RangetoHTML Set fso = CreateObject("Scripting.FileSystemObject") Set ts = fso.GetFile(TempFile).OpenAsTextStream(1, -2) RangetoHTML = ts.ReadAll ts.Close RangetoHTML = Replace(RangetoHTML, "align=center x:publishsource=", _ "align=left x:publishsource=") 'Close TempWB TempWB.Close savechanges:=False 'Delete the htm file we used in this function Kill TempFile Set ts = Nothing Set fso = Nothing Set TempWB = Nothing End Function
If you want to use the Intellisense help showing you the properties and
methods of the objects as you type you can use Early Binding.
Bit faster also when you run your code but you can have problems when you
distribute your workbooks. Excel will automatic update the reference number
to Outlook when you open your workbook in a higher version of Excel/Outlook
but not update it when you open it in a lower version of Excel/Outlook. With
Late Binding as I used in the macro examples you not have
this problem.
Add a reference to the Microsoft Outlook Library in
Excel
1) Go to the VBA editor with the shortcut
Alt - F11
2) Click on
Tools>References in the Menu bar
3) Place a
Checkmark before Microsoft Outlook ? Object Library
Where ? is the Outlook version number
Then replace
this three lines in the code
Dim OutApp As
Object
Dim OutMail As Object
Set OutMail = OutApp.CreateItem(0)
With this three lines
Dim OutApp As
Outlook.Application
Dim OutMail As Outlook.MailItem
Set OutMail =
OutApp.CreateItem(olMailItem)