Trouble populating email from Userform

Andyjk1984

New Member
Joined
May 17, 2019
Messages
10
morning guys

got myself a little stuck with this

so I have created a userform that once populated with the relevant info fills a log on sheet1, I then want It to email the data that was entered to myself.

where am I going wrong, I have bitten off more than I am capable of

Code:
Private Sub BUTTON1_Click()
Dim iRow As Long
Dim ws As Worksheet
Set ws = Worksheets("LOG")

'find first empty row in database
iRow = ws.Cells.Find(What:="*", SearchOrder:=xlRows, _
    SearchDirection:=xlPrevious, LookIn:=xlValues).Row + 1
'check for date
If Trim(Me.TextBox1.Value) = "" Then
  Me.TextBox1.SetFocus
  MsgBox "Please enter Date"
  Exit Sub
End If
'copy the data to the database
'use protect and unprotect lines,
'     with your password
'     if worksheet is protected
With ws
'  .Unprotect Password:="password"
  .Cells(iRow, 1).Value = Me.TextBox1.Value
  .Cells(iRow, 2).Value = Me.TextBox2.Value
  .Cells(iRow, 3).Value = Me.TextBox14.Value
  .Cells(iRow, 4).Value = Me.TextBox3.Value
  .Cells(iRow, 5).Value = Me.TextBox4.Value
  .Cells(iRow, 6).Value = Me.TextBox5.Value
  .Cells(iRow, 7).Value = Me.TextBox6.Value
  .Cells(iRow, 8).Value = Me.TextBox7.Value
  .Cells(iRow, 9).Value = Me.TextBox8.Value
  .Cells(iRow, 10).Value = Me.TextBox9.Value
  .Cells(iRow, 11).Value = Me.TextBox10.Value
  .Cells(iRow, 12).Value = Me.TextBox11.Value
  .Cells(iRow, 13).Value = Me.TextBox12.Value
  .Cells(iRow, 14).Value = Me.TextBox13.Value
'  .Protect Password:="password"
End With
'clear the data
Me.TextBox4.Value = ""
Me.TextBox3.Value = ""
Me.TextBox6.Value = ""
Me.TextBox5.Value = ""
Me.TextBox7.Value = ""
Me.TextBox8.Value = ""
Me.TextBox9.Value = ""
Me.TextBox10.Value = ""
Me.TextBox11.Value = ""
Me.TextBox12.Value = ""
Me.TextBox13.Value = ""
Me.TextBox1.SetFocus

'Send Email automatically
Dim oOLook As Object
Dim oEMail As Object
Dim sMessage As String
Set oOLook = CreateObject("Outlook.Application")
oOLook.Session.Logon
Set oEMail = oOLook.CreateItem(0)
oEMail.display
 
 'Compile the message body:
    sMessage = "This is an automated email:" & vbCrLf
    sMessage = sMessage & "Route Re-String:" & vbCrLf
    sMessage = sMessage & TextBox3 & vbCrLf
    sMessage = sMessage & "" & TextBox4 & vbCrLf
    sMessage = sMessage & "" & TextBox5 & vbCrLf


On Error Resume Next
With oEMail
.To = "[EMAIL="user@email.com"]user@email.com[/EMAIL]"
.CC = ""
.BCC = ""
.Subject = " Changes"
.Body = sMessage

.send
End With
Set outmail = Nothing
Set outapp = Nothing

End Sub
 

Some videos you may like

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.

Norie

Well-known Member
Joined
Apr 28, 2004
Messages
75,459
Office Version
365
Platform
Windows
Eh, can you tell us where things are going wrong/not working?:)
 

Andyjk1984

New Member
Joined
May 17, 2019
Messages
10
apologies

its the email that gets sent, it only shows

This is an automatedemail:
Route Re-String:


 

Norie

Well-known Member
Joined
Apr 28, 2004
Messages
75,459
Office Version
365
Platform
Windows
Either move this section of the code after the part that does the email,
Code:
'clear the data
Me.TextBox4.Value = ""
Me.TextBox3.Value = ""
Me.TextBox6.Value = ""
Me.TextBox5.Value = ""
Me.TextBox7.Value = ""
Me.TextBox8.Value = ""
Me.TextBox9.Value = ""
Me.TextBox10.Value = ""
Me.TextBox11.Value = ""
Me.TextBox12.Value = ""
Me.TextBox13.Value = ""
Me.TextBox1.SetFocus
or create a separate sub for the email in the userform module, something like this,
Code:
Sub SendEmail()
'Send Email automatically
Dim oOLook As Object
Dim oEMail As Object
Dim sMessage As String

    Set oOLook = CreateObject("Outlook.Application")
    oOLook.Session.Logon
    Set oEMail = oOLook.CreateItem(0)
    oEMail.display
     
     'Compile the message body:
    sMessage = "This is an automated email:" & vbCrLf
    sMessage = sMessage & "Route Re-String:" & vbCrLf
    sMessage = sMessage & TextBox3 & vbCrLf
    sMessage = sMessage & "" & TextBox4 & vbCrLf
    sMessage = sMessage & "" & TextBox5 & vbCrLf
        
    On Error Resume Next
    With oEMail
        .To = "user@email.com"
        .CC = ""
        .BCC = ""
        .Subject = " Changes"
        .Body = sMessage
        .send
    End With
    
    Set outmail = Nothing
    Set outapp = Nothing

End Sub
and call that sub before clearing the userform.

If you chose the latter option the code would look something like this.
Code:
Private Sub BUTTON1_Click()
Dim iRow As Long
Dim ws As Worksheet
Set ws = Worksheets("LOG")
    
    'find first empty row in database
    iRow = ws.Cells.Find(What:="*", SearchOrder:=xlRows, _
        SearchDirection:=xlPrevious, LookIn:=xlValues).Row + 1
    'check for date
    If Trim(Me.TextBox1.Value) = "" Then
      Me.TextBox1.SetFocus
      MsgBox "Please enter Date"
      Exit Sub
    End If
    'copy the data to the database
    'use protect and unprotect lines,
    '     with your password
    '     if worksheet is protected
    With ws
    '  .Unprotect Password:="password"
      .Cells(iRow, 1).Value = Me.TextBox1.Value
      .Cells(iRow, 2).Value = Me.TextBox2.Value
      .Cells(iRow, 3).Value = Me.TextBox14.Value
      .Cells(iRow, 4).Value = Me.TextBox3.Value
      .Cells(iRow, 5).Value = Me.TextBox4.Value
      .Cells(iRow, 6).Value = Me.TextBox5.Value
      .Cells(iRow, 7).Value = Me.TextBox6.Value
      .Cells(iRow, 8).Value = Me.TextBox7.Value
      .Cells(iRow, 9).Value = Me.TextBox8.Value
      .Cells(iRow, 10).Value = Me.TextBox9.Value
      .Cells(iRow, 11).Value = Me.TextBox10.Value
      .Cells(iRow, 12).Value = Me.TextBox11.Value
      .Cells(iRow, 13).Value = Me.TextBox12.Value
      .Cells(iRow, 14).Value = Me.TextBox13.Value
    '  .Protect Password:="password"
    End With
    
    Call SendMail
    
    'clear the data
    Me.TextBox4.Value = ""
    Me.TextBox3.Value = ""
    Me.TextBox6.Value = ""
    Me.TextBox5.Value = ""
    Me.TextBox7.Value = ""
    Me.TextBox8.Value = ""
    Me.TextBox9.Value = ""
    Me.TextBox10.Value = ""
    Me.TextBox11.Value = ""
    Me.TextBox12.Value = ""
    Me.TextBox13.Value = ""
    Me.TextBox1.SetFocus
    
End Sub

Sub SendEmail()
'Send Email automatically
Dim oOLook As Object
Dim oEMail As Object
Dim sMessage As String

    Set oOLook = CreateObject("Outlook.Application")
    oOLook.Session.Logon
    Set oEMail = oOLook.CreateItem(0)
    oEMail.display
     
     'Compile the message body:
    sMessage = "This is an automated email:" & vbCrLf
    sMessage = sMessage & "Route Re-String:" & vbCrLf
    sMessage = sMessage & TextBox3 & vbCrLf
    sMessage = sMessage & "" & TextBox4 & vbCrLf
    sMessage = sMessage & "" & TextBox5 & vbCrLf
        
    On Error Resume Next
    With oEMail
        .To = "user@email.com"
        .CC = ""
        .BCC = ""
        .Subject = " Changes"
        .Body = sMessage
        .send
    End With
    
    Set outmail = Nothing
    Set outapp = Nothing

End Sub
 

Andyjk1984

New Member
Joined
May 17, 2019
Messages
10
that has done the trick, and upon reflection seems so obvious

thank you for your time

much appreciated
 

Forum statistics

Threads
1,089,467
Messages
5,408,423
Members
403,204
Latest member
pth

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top