• Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  • When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

Help with Macro

Ketan Mehta

New Member
Hi

Grateful for assistance regarding the below.

The code below works which saves and emails the active excel worksheet when a button is pressed on the excel sheet, what I would like to do is to add a message box in the code below which tells the user that the form has been submitted when this button has been pressed. Any ideas?

I did try to add a code for a message box but it is being created as a seperate sub routine and message does not appear. Just need a simple message that says "Your form has been submitted, thank you"

<<< use code -tags >>>
Code:
Sub Mail_ActiveSheet()
    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

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

    Set Sourcewb = ActiveWorkbook

    'Copy the ActiveSheet to a new workbook
    ActiveSheet.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 = ""
            .CC = ""
            .BCC = ""
            .Subject = "Order Form"
            .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
 
Last edited by a moderator:
Code:
With Application
.ScreenUpdating = True
.EnableEvents = True
End With

MsgBox "Email sent.", vbinformation, "Completed"

End Sub
 
Hi Logit

That has worked thanks, can I please ask, is there a code I can add that clears the data that is entered on the speadsheet after submission, at the minute, if somebody clicks on save on the excel spreadsheet, it saves the data they have entered and the next user will see this data. I did save the file as read only but user can bypass this by clicking on no.

Many thanks
 
The following will clear EVERYTHING from Sheet1 :

Code:
Sub clrSht()
    Sheet1.Range("A:Z").Value = ""
End Sub

You can add a line to your macro like so :

Code:
With Application
.ScreenUpdating = True
.EnableEvents = True
End With

clrSht

MsgBox "Email sent.", vbinformation, "Completed"

That will run the clear sheet macro immediately prior to displaying the MsgBox. Keep in mind though, that command will clear EVERYTHING from the sheet, including any headers or lables you have entered into any cells.

If you want to avoid having a completely empty sheet, it would help to know how your sheet is laid out.

Attach a copy for review.
 
Back
Top