Consulting

Results 1 to 14 of 14

Thread: Solved: Email a worksheet

  1. #1
    VBAX Master paulked's Avatar
    Joined
    Apr 2006
    Posts
    1,007
    Location

    Exclamation Solved: Email a worksheet

    Can anyone please help?

    I am trying to send quotations by email direct from a worksheet without sending the whole workbook.

    I have tried the routine below, but it comes up with the error "Run-time error '438' Object doesn't support this property or method"

    [vba]Sub Email()
    Dim EAdd, Def, Prom, Tit

    Def = "paulked@o2.co.uk"
    Prom = "Email Address?"
    Tit = "Enter Email Recipient"

    Application.ScreenUpdating = False

    With Sheets("Email")
    .PageSetup.PrintArea = "C2:J57"

    If Range("F29").Value = 0 Then
    .Rows("29").Hidden = True 'discount
    .Rows("51:52").Hidden = True
    End If

    EAdd = InputBox(Prom, Tit, Def)

    .SendMail Recipients:=EAdd
    .Rows("29").Hidden = False
    .Rows("51:52").Hidden = False
    End With

    ActiveWindow.View = xlNormalView
    End Sub
    [/vba]

    I would appreciate any help whatsoever.

    Many thanks

    Paul

    Edited 10-Apr-06 by GeekGirlau. Reason: put code in VBA tags

  2. #2
    Administrator
    Chat VP
    VBAX Guru johnske's Avatar
    Joined
    Jul 2004
    Location
    Townsville, Australia
    Posts
    2,872
    Location
    Hi paulked, welcome to VBAX.

    Try this - Uses default email program to email active sheet with a message, deletes ws formulas, assumes the email addresses are on sheet1, A1 to A10 - modify to suit

    [vba]Option Explicit

    Sub EmailActiveSheetWithMessage()

    Dim ThisDate As String, Recipient(1 To 10) As String, N As Long

    ThisDate = Format(Date, "dd mmm yy")
    For N = 1 To 10
    'put your addies in Sheet1, A1:A10
    Recipient(N) = Sheet1.Range("A" & N)
    Next

    Application.ScreenUpdating = False

    ActiveSheet.Copy
    With Cells
    'get rid of formulas
    .Copy
    .PasteSpecial Paste:=xlPasteValues
    End With

    'Send the new workbook with a message
    ActiveWorkbook.HasRoutingSlip = True
    With ActiveWorkbook.RoutingSlip
    .Recipients = Recipient()
    .Subject = "Files for " & ThisDate
    'insert your own text below
    .Message = "Hi," & vbNewLine & _
    "" & vbNewLine & _
    "Attached files are for...blah blah..." & vbNewLine & _
    "...more blah here.... " & vbNewLine & _
    "" & vbNewLine & _
    "Regards," & vbNewLine & _
    "Your name" & vbNewLine & _
    "" & vbNewLine & _
    "" & vbNewLine & _
    "" & vbNewLine & _
    ""
    .Delivery = xlAllAtOnce
    .ReturnWhenDone = False
    End With

    With ActiveWorkbook
    .Route
    .Saved = True
    .Close False
    End With
    Application.ScreenUpdating = True

    'Let user know what's happened
    MsgBox "File sent by email ", , "Emailed..."
    Sheet1.Activate

    End Sub[/vba]
    You know you're really in trouble when the light at the end of the tunnel turns out to be the headlight of a train hurtling towards you

    The major part of getting the right answer lies in asking the right question...


    Made your code more readable, use VBA tags (this automatically inserts [vba] at the start of your code, and [/vba ] at the end of your code) | Help those helping you by marking your thread solved when it is.

  3. #3
    VBAX Master paulked's Avatar
    Joined
    Apr 2006
    Posts
    1,007
    Location
    Thanks for that, I'll give it a try although as we are sending quotations then the email address will be unknown until the request comes in.

    Tanks again

  4. #4
    VBAX Master paulked's Avatar
    Joined
    Apr 2006
    Posts
    1,007
    Location
    A nice bit of coding.

    I need to send the sheet as the body of an email rather than an attached file. The reasons are 1. Some people are blocked from receiving attachments and 2. If they update the information when opening the sheet they lose the data!

    Any ideas?

    Regards

    Paul

  5. #5
    Administrator
    Chat VP VBAX Guru johnske's Avatar
    Joined
    Jul 2004
    Location
    Townsville, Australia
    Posts
    2,872
    Location
    Why not use use the built-in functionality? Go to View > Toolbars > Customize > Commands > File, then put the 'Send Now' command on one of your toolbars.

    You then only need to click 'Send Now', type in the addy then click 'Send This Sheet'
    You know you're really in trouble when the light at the end of the tunnel turns out to be the headlight of a train hurtling towards you

    The major part of getting the right answer lies in asking the right question...


    Made your code more readable, use VBA tags (this automatically inserts [vba] at the start of your code, and [/vba ] at the end of your code) | Help those helping you by marking your thread solved when it is.

  6. #6
    VBAX Master paulked's Avatar
    Joined
    Apr 2006
    Posts
    1,007
    Location
    That's exactly what I want to do, thanks. But, to make things "office-proof", I have disabled all menus. Can this be done in VB?

    Appreciate your help, Best Regards

    Paul

  7. #7
    VBAX Master paulked's Avatar
    Joined
    Apr 2006
    Posts
    1,007
    Location
    BTW,

    This is the latest coding which sends out as an attached sheet:

    [VBA]
    Sub Email()
    Dim EAdd, Def, Prom, Tit
    Def = "paulked@o2.co.uk"
    Prom = "Email Address?"
    Tit = "Enter Email Recipient"
    Application.ScreenUpdating = False
    With Sheets("Email")
    .PageSetup.PrintArea = "C2:J57"
    If Range("F29").Value = 0 Then
    .Rows("29").Hidden = True 'discount
    .Rows("51:52").Hidden = True
    End If
    End With
    EAdd = InputBox(Prom, Tit, Def)
    With Sheets("EMail").Copy
    End With
    With ActiveWorkbook
    .Sheets(1).Name = "quotation"
    ActiveWorkbook.SendMail Recipients:=EAdd, Subject:="Quotation"
    ActiveWorkbook.Close False
    End With
    With Sheets("EMail")
    '.SendMail Recipients:=EAdd
    .Rows("29").Hidden = False
    .Rows("51:52").Hidden = False
    End With
    ActiveWindow.View = xlNormalView
    End Sub
    [/VBA]

  8. #8
    VBAX Master Norie's Avatar
    Joined
    Jan 2005
    Location
    Stirling, Scotland
    Posts
    1,831
    Location
    Paul

    If you want the spreadsheet in the body of the email you'll need code that is specific to your email client. eg Outlook

    Try a board search using the name of your email client.

  9. #9
    Administrator
    Chat VP VBAX Guru johnske's Avatar
    Joined
    Jul 2004
    Location
    Townsville, Australia
    Posts
    2,872
    Location
    I still think this is by far the easiest way for you to go...

    Quote Originally Posted by johnske
    Why not use use the built-in functionality? Go to View > Toolbars > Customize > Commands > File, then put the 'Send Now' command on one of your toolbars.

    You then only need to click 'Send Now', type in the addy then click 'Send This Sheet'
    This method requires you to use Outlook (which is OK if you use it as default, but not otherwise...), for more, go to http://www.rondebruin.nl/mail/folder3/mail2.htm
    [vba]Option Explicit

    Sub MailActiveSheetInBody()

    'from: http://www.rondebruin.nl/mail/folder3/mail2.htm
    Dim OutApp As Object
    Dim OutMail As Object

    Application.ScreenUpdating = False
    Set OutApp = CreateObject("Outlook.Application")
    Set OutMail = OutApp.CreateItem(0)

    With OutMail
    .To = "someone@somewhere.com"
    .CC = ""
    .BCC = ""
    .Subject = "This is the Subject line"
    .HTMLBody = SheetToHTML(ActiveSheet)
    .Send 'or use .Display
    End With

    Application.ScreenUpdating = True
    Set OutMail = Nothing
    Set OutApp = Nothing

    End Sub

    Public Function SheetToHTML(sh As Worksheet)

    'Function from Dick Kusleika his site
    'http://www.dicks-clicks.com/excel/sheettohtml.htm
    'Changed by Ron de Bruin 04-Nov-2003

    Dim TempFile As String
    Dim Nwb As Workbook
    Dim myshape As Shape
    Dim fso As Object
    Dim ts As Object

    sh.Copy
    Set Nwb = ActiveWorkbook

    For Each myshape In Nwb.Sheets(1).Shapes
    myshape.Delete
    Next

    TempFile = Environ$("temp") & "/" & _
    Format(Now, "dd-mm-yy h-mm-ss") & ".htm"
    Nwb.SaveAs TempFile, xlHtml
    Nwb.Close False

    Set fso = CreateObject("Scripting.FileSystemObject")
    Set ts = fso.GetFile(TempFile).OpenAsTextStream(1, -2)

    SheetToHTML = ts.ReadAll
    ts.Close

    Set ts = Nothing
    Set fso = Nothing
    Set Nwb = Nothing
    Kill TempFile

    End Function[/vba]
    You know you're really in trouble when the light at the end of the tunnel turns out to be the headlight of a train hurtling towards you

    The major part of getting the right answer lies in asking the right question...


    Made your code more readable, use VBA tags (this automatically inserts [vba] at the start of your code, and [/vba ] at the end of your code) | Help those helping you by marking your thread solved when it is.

  10. #10
    VBAX Master paulked's Avatar
    Joined
    Apr 2006
    Posts
    1,007
    Location

    Thumbs up

    Perfect !

    Thank you very much.

    Best regards

    Paul

  11. #11
    Administrator
    Chat VP VBAX Guru johnske's Avatar
    Joined
    Jul 2004
    Location
    Townsville, Australia
    Posts
    2,872
    Location
    So we can mark this solved?
    You know you're really in trouble when the light at the end of the tunnel turns out to be the headlight of a train hurtling towards you

    The major part of getting the right answer lies in asking the right question...


    Made your code more readable, use VBA tags (this automatically inserts [vba] at the start of your code, and [/vba ] at the end of your code) | Help those helping you by marking your thread solved when it is.

  12. #12
    VBAX Master paulked's Avatar
    Joined
    Apr 2006
    Posts
    1,007
    Location
    I'd be happy to... If only I knew how!

    Thanks again

  13. #13
    Administrator
    Chat VP VBAX Guru johnske's Avatar
    Joined
    Jul 2004
    Location
    Townsville, Australia
    Posts
    2,872
    Location
    That's temporarily out of action - I'll do it
    You know you're really in trouble when the light at the end of the tunnel turns out to be the headlight of a train hurtling towards you

    The major part of getting the right answer lies in asking the right question...


    Made your code more readable, use VBA tags (this automatically inserts [vba] at the start of your code, and [/vba ] at the end of your code) | Help those helping you by marking your thread solved when it is.

  14. #14
    VBAX Master Norie's Avatar
    Joined
    Jan 2005
    Location
    Stirling, Scotland
    Posts
    1,831
    Location
    Johnske

    I totally forgot about RoutingSlip.

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •