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
This procedure will mail every Worksheet
with an address in cell A1. It does this by
cycling through each
worksheet in the workbook and checking cell A1 for the @ character. If
found, a copy of the worksheet is made and saved with a date/time stamp, and
then sent by e-mail to the address in cell A1. And finally, the file is
deleted from your hard disk
Note: Copy this macro in
a standard module of the file with the sheets you want to send.
Important: Read also the information below the macro
Sub Mail_Every_Worksheet() 'Working in Excel 2000-2016 'For Tips see: https://jkp-ads.com/rdb/win/winmail/Outlook/tips.htm Dim sh As Worksheet Dim wb As Workbook Dim FileExtStr As String Dim FileFormatNum As Long Dim TempFilePath As String Dim TempFileName As String Dim OutApp As Object Dim OutMail As Object TempFilePath = Environ$("temp") & "\" If Val(Application.Version) < 12 Then 'You use Excel 97-2003 FileExtStr = ".xls": FileFormatNum = -4143 Else 'You use Excel 2007-2016 FileExtStr = ".xlsm": FileFormatNum = 52 End If With Application .ScreenUpdating = False .EnableEvents = False End With Set OutApp = CreateObject("Outlook.Application") For Each sh In ThisWorkbook.Worksheets If sh.Range("A1").Value Like "?*@?*.?*" Then sh.Copy Set wb = ActiveWorkbook TempFileName = "Sheet " & sh.Name & " of " _ & ThisWorkbook.Name & " " & Format(Now, "dd-mmm-yy h-mm-ss") Set OutMail = OutApp.CreateItem(0) With wb .SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum On Error Resume Next With OutMail .to = sh.Range("A1").Value .CC = "" .BCC = "" .Subject = "This is the Subject line" .Body = "Hi there" .Attachments.Add wb.FullName 'You can add other files also like this '.Attachments.Add ("C:\test.txt") .Send 'or use .Display End With On Error GoTo 0 .Close savechanges:=False End With Set OutMail = Nothing Kill TempFilePath & TempFileName & FileExtStr End If Next sh Set OutApp = Nothing With Application .ScreenUpdating = True .EnableEvents = True End With End Sub
In the macro you see that if
Val(Application.Version) < 12 is True that I
use
FileExtStr = ".xls": FileFormatNum = -4143
This is the normal Excel workbook format in 97-2003
If you run the
code in Excel 2007-2016 it will save the new file as xlsm
But you can
change that if you want
Options for all Excel versions :
Save
the one sheet workbook to csv, txt or prn.
FileExtStr = ".csv": FileFormatNum = 6
FileExtStr = ".txt": FileFormatNum
= -4158
FileExtStr = ".prn": FileFormatNum = 36
Options
only for Excel 2007-2016 :
This are the main formats :
51 =
xlOpenXMLWorkbook (without macro's in 2007-2016, xlsx)
52 =
xlOpenXMLWorkbookMacroEnabled (with or without macro's in 2007-2016, xlsm)
50 = xlExcel12 (Excel Binary Workbook in 2007-2016 with or without macro’s,
xlsb)
56 = xlExcel8 (97-2003 format in Excel 2007-2016, xls)
FileExtStr = ".xlsb": FileFormatNum = 50
FileExtStr = ".xlsx": FileFormatNum = 51
FileExtStr = ".xlsm":
FileFormatNum = 52
FileExtStr = ".xls": FileFormatNum = 56
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)