Something fishy in my VBA code, please help

FelixSall

New Member
Joined
Aug 20, 2018
Messages
6
Hi,

Im trying to Email 16 different email addresses a copy of a specific sheet from my workbook.
I've almost suceeded in that sense that i've managed to create 16 emails and attach 16 different sheets.

However it wont Add my address list to the "To" field in outlook....
I've now been staring at the code for a while and gotten abit blind.

My address list is located in Sheet6 starting from A2.. and I just want it to paste A3:s address on the next email.
But I seem to get the same address on alla my emails generated (?)

I've highligted the code where I think the problem lies

(part of this code is from ronn de bruinn)

Rich (BB code):
Sub Mail_ActiveSheet()

row_number = 1


    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 Address As Object



    Set Address = Sheets(6).Range("A2")



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



    Set Sourcewb = ActiveWorkbook




    Do Until (row_number = 3)

    row_number = row_number + 1
    Sheets(5 + row_number).Copy


    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 worksheet to values if you want
    '    With Destwb.Sheets(1).UsedRange
    '        .Cells.Copy
    '        .Cells.PasteSpecial xlPasteValues
    '        .Cells(1).Select
    '    End With
    '    Application.CutCopyMode = False

    '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 = Address & row_number
            .CC = ""
            .BCC = ""
            .Subject = "Lojalitetsbonus"
            .Body = "Hej, här kommer ert distrikts lojalitetsbonus per butik. Se bifogad excel."
            .Attachments.Add Destwb.FullName
            'You can add other files also like this
            '.Attachments.Add ("C:\test.txt")
            .Display 'Eller .Send för att det skall skickas automatiskt


        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


    Loop


End Sub
 
Last edited by a moderator:

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
Not sure I understand what the row_number variable is for, but assuming your mail to list is in A2 and down col A and holds full email addresses you might try something like this:
First, change the definition of Address to:
Code:
Set Address = Sheets(6).Range("A2:A" & Cells(Rows.Count, "A").End(xlUp).Row)
Then replace the Outlook block with this:
Code:
With OutMail
    For i = 1 To Address.Rows.Count
        If Address(i) <> "" Then
            .to = Address(i)
            .CC = ""
            .BCC = ""
            .Subject = "Lojalitetsbonus"
            .Body = "Hej, här kommer ert distrikts lojalitetsbonus per butik. Se bifogad excel."
            .Attachments.Add Destwb.FullName
            'You can add other files also like this
            '.Attachments.Add ("C:\test.txt")
            .Display 'Eller .Send för att det skall skickas automatiskt
        End If
    Next i
End With
I haven't tested this so may need some tweaking. Also, I haven't looked closely at the Do loop and don't really understand what its intended to accomplish so can't comment on that.
 
Upvote 0
Code:
  .To = Worksheets(6).Range("A2").Offset(rownumber).Value
 
Upvote 0
Hi,

Thanks for all fast replys!! :) managed either way!! with
.To = Address
and also Set Address = sheets(6).range("A" & row_number + 1) .... I think I placed the set address statement to far up.
I moved it below the "Do Until"

However works like a charm now :) So freakin relieved ;)

Thanks again everyone!
 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,287
Members
452,631
Latest member
a_potato

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