Macro button to send sheets in an email

XL Bruiser

New Member
Joined
Feb 8, 2017
Messages
6
Hello,

I have a workbook that I am creating for Work orders for our business. There are about 6 sheets that have different templates for different repairs. IE sheet one - Heater repairs, sheet two - plumbing repairs, etc.

The goal is to be able to fill out these sheets and then hit the send email macro button and have it generate an email in outlook with those specific sheets attached.

The issue im having is that I don't want to send ALL sheets at once, just the ones that are filled out with the maintenance requests. So we need to be able to specify which sheets are to be attached each time we hit the macro.

Any help is appreciated! :)

-Excel noob
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Rich (BB code):
Private Sub CommandButton1_Click()
    On Error GoTo ErrHandler
    
    ' SET Outlook APPLICATION OBJECT.
    Dim objOutlook As Object
    Set objOutlook = CreateObject("Outlook.Application")
    
    ' CREATE EMAIL OBJECT.
    Dim objEmail As Object
    Set objEmail = objOutlook.CreateItem(olMailItem)

    With objEmail
        .to = "XXXXXX@XXXXXX.com"
        .Subject = "Test"
        .Body = "Test"
        .Attachments.Add Application.ActiveWorkbook.FullName
        .Display           ' DISPLAY MESSAGE.
    End With
    
    ' CLEAR.
    Set objEmail = Nothing:    Set objOutlook = Nothing
        
ErrHandler:
    '
End Sub
 
Last edited:
Upvote 0
Make a control sheet, say column A with the sheet names in it A2 through to A7 and then have in column B either Yes or No, indicating if you want to create an email for that tab. The following code checks to see if there is a yes next to the tabname and if so, creates a file with just that tab in it, saves it to a temp drive and then puts it in an email as per your code - with the small change of where the attachment comes from. It then moves on to the next tabname as per your control sheet until the row number = 8.

Code:
Private Sub CommandButton1_Click(tabname)
    On Error GoTo ErrHandler
    
    ' SET Outlook APPLICATION OBJECT.
    Dim objOutlook As Object
    Set objOutlook = CreateObject("Outlook.Application")
    
    ' CREATE EMAIL OBJECT.
    Dim objEmail As Object
    Set objEmail = objOutlook.CreateItem(olMailItem)

    With objEmail
        .to = "XXXXXX@XXXXXX.com"
        .Subject = "Test"
        .Body = "Test"
        .Attachments.Add (Environ("temp") & "\" & tabname & ".xlsx")
        .Display           ' DISPLAY MESSAGE.
    End With
    
    ' CLEAR.
    Set objEmail = Nothing:    Set objOutlook = Nothing
        
ErrHandler:
    '
End Sub


Sub CreateSendFile()


Rownum = 2  '''This is where you should list your filenames

Do Until Rownum = 8

tabname = Worksheets("Sheet1").Cells(Rownum, 1).Value
SendFile = Worksheets("Sheet1").Cells(Rownum, 2).Value


If SendFile = "Yes" Then
    Sheets(tabname).Copy
    MailName = ActiveWorkbook.Name
    ActiveWorkbook.SaveCopyAs Environ("temp") & "\" & tabname & ".xlsx"
    
    Call CommandButton1_Click(tabname)
    
    Workbooks(ThisWorkbook.Name).Activate
    Sheets("Sheet1").Select

    Else
End If

Rownum = Rownum + 1
Loop

End Sub

Will all of the emails go to the same person?
 
Upvote 0

Forum statistics

Threads
1,216,105
Messages
6,128,859
Members
449,472
Latest member
ebc9

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top