VBA - User defined type not defined error

ssh99

New Member
Joined
Oct 25, 2020
Messages
36
Office Version
  1. 2010
Platform
  1. Windows
  2. MacOS
My query for automating emails is coming up with the following error: User defined type not defined. I have the right object libraries selected in the References so am not sure how to fix this. The code is below. I can send a copy of the spreadsheet as well if that would help.

VBA code:
Sub sendemail()

Dim OutApp As New Outlook.Application
Dim OutMail As MailItem

LR = Cells(Rows.Count, "B").End(xlUp).Row
bodySignature = "Kind regards," & vbLf & "Quality Assurance Team"

For r = 2 To LR
Set OutMail = OutApp.CreateItem(olMailItem)

With OutMail
.To = Range("C" & r).Value
.Subject = Range("D" & r).Value
bodyHeader = "Dear " & Range("B" & r).Value & ","
bodyMain = Range("E" & r).Value
.Body = bodyHeader & vbLf & bodyMain & vbLf & bodySignature
.Attachments.Add Range("F" & r).Value
.Display
End With
Next r

Set OutMail = Nothing
Set OutApp = Nothing

End Sub
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
You must select the Microsoft Outlook ## Object Library reference, In the VBA Tools menu, Reference
Change ## by the version number that appears


1721236635201.png
 
Upvote 0
You must select the Microsoft Outlook ## Object Library reference, In the VBA Tools menu, Reference
Change ## by the version number that appears


View attachment 114197
The MIcrosoft Outlook object library is ticked in references already (see below). Not sure why this error is still coming up.
1721245019886.png
 
Upvote 0
Use the following code:

VBA Code:
Sub sendemail()
  Dim OutApp As Object
  Dim OutMail As Object
  Dim lr As Long
  
  Set OutApp = CreateObject("Outlook.Application")

  lr = Cells(Rows.Count, "B").End(xlUp).Row
  bodySignature = "Kind regards," & vbLf & "Quality Assurance Team"
  
  For r = 2 To lr
    Set OutMail = OutApp.CreateItem(olMailItem)
    
    With OutMail
      .To = Range("C" & r).Value
      .Subject = Range("D" & r).Value
      bodyHeader = "Dear " & Range("B" & r).Value & ","
      bodyMain = Range("E" & r).Value
      .Body = bodyHeader & vbLf & bodyMain & vbLf & bodySignature
      .Attachments.Add Range("F" & r).Value
      .Display
    End With
  Next r
  
  Set OutMail = Nothing
  Set OutApp = Nothing
End Sub
 
Upvote 0
Solution
Use the following code:

VBA Code:
Sub sendemail()
  Dim OutApp As Object
  Dim OutMail As Object
  Dim lr As Long
 
  Set OutApp = CreateObject("Outlook.Application")

  lr = Cells(Rows.Count, "B").End(xlUp).Row
  bodySignature = "Kind regards," & vbLf & "Quality Assurance Team"
 
  For r = 2 To lr
    Set OutMail = OutApp.CreateItem(olMailItem)
   
    With OutMail
      .To = Range("C" & r).Value
      .Subject = Range("D" & r).Value
      bodyHeader = "Dear " & Range("B" & r).Value & ","
      bodyMain = Range("E" & r).Value
      .Body = bodyHeader & vbLf & bodyMain & vbLf & bodySignature
      .Attachments.Add Range("F" & r).Value
      .Display
    End With
  Next r
 
  Set OutMail = Nothing
  Set OutApp = Nothing
End Sub
That works perfectly. Thank you so much!
 
Upvote 0

Forum statistics

Threads
1,224,737
Messages
6,180,653
Members
452,992
Latest member
TokugawaIesuma

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