Help needed to merge two VBA codes into one

antonchannn

New Member
Joined
Apr 17, 2017
Messages
2
Hi there! I am trying to combine two VBA codes i found online into one. However, I have been getting different errors msgs.

So far, this is what i have but i've been getting "File not found error message for 'Kill TempFilePath & TempFileName & FileExtStr":


Code:
<code style="margin: 0px; padding: 0px; font-style: inherit; font-weight: inherit; font-family: monospace; line-height: 12px;">Sub Mail_Sheets_Array()

Dim FileExtStr As String
Dim FileFormatNum As Long
Dim Sourcewb As Workbook
Dim Destwb As Workbook
Dim TempFilePath As String
Dim TempFileName As String
Dim OutApp As Object
Dim OutMail As Object
Dim sh As Worksheet
Dim TheActiveWindow As Window
Dim TempWindow As Window
Dim cell As Range

    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With

    Set Sourcewb = ActiveWorkbook


    With Sourcewb
        Set TheActiveWindow = ActiveWindow
        Set TempWindow = .NewWindow
        .Sheets(Array("OPF", "Leave")).Copy
    End With


    TempWindow.Close

    Set Destwb = ActiveWorkbook


    With Destwb
        If Val(Application.Version) < 12 Then

            FileExtStr = ".xls": FileFormatNum = -4143
        Else

            Select Case Sourcewb.FileFormat
                Case 51: FileExtStr = ".xlsx": FileFormatNum = 51
                Case 52:
                    If .HasVBProject Then
                        FileExtStr = ".xlsm": FileFormatNum = 52
                    Else
                        FileExtStr = ".xlsx": FileFormatNum = 51
                    End If
                Case 56: FileExtStr = ".xls": FileFormatNum = 56
                Case Else: FileExtStr = ".xlsb": FileFormatNum = 50
            End Select
        End If
    End With


    TempFilePath = Environ$("temp") & ""
    TempFileName = "Outprocessing Form" & Sourcewb.Name & " " & Format(Now, "dd-mmm-yy h-mm-ss")

    Set OutApp = CreateObject("Outlook.Application")

    For Each cell In Columns("B").Cells.SpecialCells(xlCellTypeConstants)
        If cell.Value Like "?*@?*.?*" And _
           LCase(Cells(cell.Row, "C").Value) = "yes" Then

            Set OutMail = OutApp.CreateItem(0)

            With Destwb
                .SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum
                On Error Resume Next
                With OutMail
                    .to = "cell.Value"
                    .CC = ""
                    .BCC = ""
                    .Subject = "This is the Subject line"
                    .Body = "Hi there"
                    .Attachments.Add Destwb.FullName
                    .Send
                End With
                On Error GoTo 0
                .Close savechanges:=False
            End With
        End If
    Next cell

    Kill TempFilePath & TempFileName & FileExtStr

    Set OutMail = Nothing
    Set OutApp = Nothing

    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
End Sub
</code>

These are the two original codes i am trying to merge:


1) First code
Code:
Sub Test1()
'For Tips see: [URL]http://www.rondebruin.nl/win/winmail/Outlook/tips.htm[/URL]
'Working in Office 2000-2016
    Dim OutApp As Object
    Dim OutMail As Object
    Dim cell As Range
    Application.ScreenUpdating = False
    Set OutApp = CreateObject("Outlook.Application")
    On Error GoTo cleanup
    For Each cell In Columns("B").Cells.SpecialCells(xlCellTypeConstants)
        If cell.Value Like "?*@?*.?*" And _
           LCase(Cells(cell.Row, "C").Value) = "yes" Then
            Set OutMail = OutApp.CreateItem(0)
            On Error Resume Next
            With OutMail
                .To = cell.Value
                .Subject = "Reminder"
                .Body = "Dear " & Cells(cell.Row, "A").Value _
                      & vbNewLine & vbNewLine & _
                        "Please contact us to discuss bringing " & _
                        "your account up to date"
                'You can add files also like this
                '.Attachments.Add ("C:\test.txt")
                .Send  'Or use Display
            End With
            On Error GoTo 0
            Set OutMail = Nothing
        End If
    Next cell
cleanup:
    Set OutApp = Nothing
    Application.ScreenUpdating = True
End Sub

2) Second code

Code:
Sub Mail_Sheets_Array()
'Working in Excel 2000-2016
'For Tips see: [URL]http://www.rondebruin.nl/win/winmail/Outlook/tips.htm[/URL]
    Dim FileExtStr As String
    Dim FileFormatNum As Long
    Dim Sourcewb As Workbook
    Dim Destwb As Workbook
    Dim TempFilePath As String
    Dim TempFileName As String
    Dim OutApp As Object
    Dim OutMail As Object
    Dim sh As Worksheet
    Dim TheActiveWindow As Window
    Dim TempWindow As Window
    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With
    Set Sourcewb = ActiveWorkbook
    'Copy the sheets to a new workbook
    'We add a temporary Window to avoid the Copy problem
    'if there is a List or Table in one of the sheets and
    'if the sheets are grouped
    With Sourcewb
        Set TheActiveWindow = ActiveWindow
        Set TempWindow = .NewWindow
        .Sheets(Array("Sheet1", "Sheet3")).Copy
    End With
    'Close temporary Window
    TempWindow.Close
    Set Destwb = ActiveWorkbook
    'Determine the Excel version and file extension/format
    With Destwb
        If Val(Application.Version) < 12 Then
            'You use Excel 97-2003
            FileExtStr = ".xls": FileFormatNum = -4143
        Else
            'You use Excel 2007-2016
            Select Case Sourcewb.FileFormat
            Case 51: FileExtStr = ".xlsx": FileFormatNum = 51
            Case 52:
                If .HasVBProject Then
                    FileExtStr = ".xlsm": FileFormatNum = 52
                Else
                    FileExtStr = ".xlsx": FileFormatNum = 51
                End If
            Case 56: FileExtStr = ".xls": FileFormatNum = 56
            Case Else: FileExtStr = ".xlsb": FileFormatNum = 50
            End Select
        End If
    End With
    '    'Change all cells in the worksheets to values if you want
    '    For Each sh In Destwb.Worksheets
    '        sh.Select
    '        With sh.UsedRange
    '            .Cells.Copy
    '            .Cells.PasteSpecial xlPasteValues
    '            .Cells(1).Select
    '        End With
    '        Application.CutCopyMode = False
    '        Destwb.Worksheets(1).Select
    '    Next sh
    'Save the new workbook/Mail it/Delete it
    TempFilePath = Environ$("temp") & ""
    TempFileName = "Part of " & Sourcewb.Name & " " & Format(Now, "dd-mmm-yy h-mm-ss")
    Set OutApp = CreateObject("Outlook.Application")
    Set OutMail = OutApp.CreateItem(0)
    With Destwb
        .SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum
        On Error Resume Next
        With OutMail
            .to = "ron@debruin.nl"
            .CC = ""
            .BCC = ""
            .Subject = "This is the Subject line"
            .Body = "Hi there"
            .Attachments.Add Destwb.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
    'Delete the file you have send
    Kill TempFilePath & TempFileName & FileExtStr
    Set OutMail = Nothing
    Set OutApp = Nothing
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
End Sub
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
If you can post your workbook on DropBox, or Amazon Cloud, or Google or someplace that it can be downloaded, that would save a ton of time.
It's difficult trying to recreate the same workbook you are using from only the code. There is no way to accurately determine what the data really looks like.

Don't included confidential material. Just plug in some dummy data for reference.
 
Last edited:
Upvote 0
If you can post your workbook on DropBox, or Amazon Cloud, or Google or someplace that it can be downloaded, that would save a ton of time.
It's difficult trying to recreate the same workbook you are using from only the code. There is no way to accurately determine what the data really looks like.

Don't included confidential material. Just plug in some dummy data for reference.

Hi there,

Thanks for willing to help! Here is the link to the excel example file i prepared:

https://drive.google.com/file/d/0B8BTJPRvmHh9b1kwUVdSNE1mMXM/view?usp=sharing
 
Upvote 0
Code:
[COLOR=darkblue]Sub[/COLOR] Mail_Sheets_Array()


[COLOR=darkblue]Dim[/COLOR] FileExtStr [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]String[/COLOR]
[COLOR=darkblue]Dim[/COLOR] FileFormatNum [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
[COLOR=darkblue]Dim[/COLOR] SourceWS [COLOR=darkblue]As[/COLOR] Worksheet
[COLOR=darkblue]Dim[/COLOR] TempFilePath [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]String[/COLOR]
[COLOR=darkblue]Dim[/COLOR] TempFileName [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]String[/COLOR]
[COLOR=darkblue]Dim[/COLOR] OutApp [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Object[/COLOR]
[COLOR=darkblue]Dim[/COLOR] OutMail [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Object[/COLOR]
[COLOR=darkblue]Dim[/COLOR] cell [COLOR=darkblue]As[/COLOR] Range
    
     [COLOR=darkblue]With[/COLOR] Application
         .ScreenUpdating = [COLOR=darkblue]False[/COLOR]
         .EnableEvents = [COLOR=darkblue]False[/COLOR]
     [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
    
     [COLOR=darkblue]Set[/COLOR] SourceWS = ActiveSheet  [COLOR=#008000]'Sheet with the emails[/COLOR]
    
     [COLOR=darkblue]If[/COLOR] Val(Application.Version) < 12 [COLOR=darkblue]Then[/COLOR]
         FileExtStr = ".xls": FileFormatNum = -4143
     [COLOR=darkblue]Else[/COLOR]
         [COLOR=darkblue]Select[/COLOR] [COLOR=darkblue]Case[/COLOR] ActiveWorkbook.FileFormat
             [COLOR=darkblue]Case[/COLOR] 51: FileExtStr = ".xlsx": FileFormatNum = 51
             [COLOR=darkblue]Case[/COLOR] 52:
                 [COLOR=darkblue]If[/COLOR] ActiveWorkbook.HasVBProject [COLOR=darkblue]Then[/COLOR]
                     FileExtStr = ".xlsm": FileFormatNum = 52
                 [COLOR=darkblue]Else[/COLOR]
                     FileExtStr = ".xlsx": FileFormatNum = 51
                 [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
             [COLOR=darkblue]Case[/COLOR] 56: FileExtStr = ".xls": FileFormatNum = 56
             [COLOR=darkblue]Case[/COLOR] Else: FileExtStr = ".xlsb": FileFormatNum = 50
         [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Select[/COLOR]
     [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
     
     TempFilePath = Environ$("temp") & ""
     TempFileName = "Outprocessing Form" & ActiveWorkbook.Name & " " & Format(Now, "dd-mmm-yy h-mm-ss")
     
     ActiveWorkbook.Sheets(Array("OPF", "Leave")).Copy
     ActiveWorkbook.SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=File[COLOR=darkblue]For[/COLOR]matNum
     ActiveWorkbook.Close SaveChanges:=[COLOR=darkblue]False[/COLOR]
     
     [COLOR=darkblue]Set[/COLOR] OutApp = CreateObject("Outlook.Application")
     
     For [COLOR=darkblue]Each[/COLOR] cell [COLOR=darkblue]In[/COLOR] SourceWS.Columns("B").Cells.SpecialCells(xlCellTypeConstants)
         [COLOR=darkblue]If[/COLOR] cell.Value [COLOR=darkblue]Like[/COLOR] "?*@?*.?*" And _
            LCase(cell.Offset(, 1).Value) = "yes" [COLOR=darkblue]Then[/COLOR]
            
             [COLOR=darkblue]Set[/COLOR] OutMail = OutApp.CreateItem(0)
             [COLOR=darkblue]With[/COLOR] OutMail
                 .To = cell.Value
                 .CC = ""
                 .BCC = ""
                 .Subject = "This is the [COLOR=darkblue]Sub[/COLOR]ject line"
                 .Body = "Hi there"
                 .Attachments.Add TempFilePath & TempFileName & FileExtStr
                 [COLOR=green]'.Send[/COLOR]
                 .Display
             [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
             
         [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
     [COLOR=darkblue]Next[/COLOR] cell
     
     [COLOR=darkblue]On[/COLOR] [COLOR=darkblue]Error[/COLOR] [COLOR=darkblue]Resume[/COLOR] [COLOR=darkblue]Next[/COLOR]
     Kill TempFilePath & TempFileName & FileExtStr
     [COLOR=darkblue]On[/COLOR] [COLOR=darkblue]Error[/COLOR] [COLOR=darkblue]GoTo[/COLOR] 0
    
     [COLOR=darkblue]Set[/COLOR] OutMail = [COLOR=darkblue]Nothing[/COLOR]
     [COLOR=darkblue]Set[/COLOR] OutApp = [COLOR=darkblue]Nothing[/COLOR]
    
     [COLOR=darkblue]With[/COLOR] Application
         .ScreenUpdating = [COLOR=darkblue]True[/COLOR]
         .EnableEvents = [COLOR=darkblue]True[/COLOR]
     [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
[COLOR=darkblue]End[/COLOR] Sub
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,183
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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