PDA

View Full Version : [SOLVED:] Code is dropped when sheet is copied and emailed



Sully1440
06-03-2018, 04:07 PM
Hey All,
I'm having difficulties emailing a sheet using a macro. When the new sheet is copied and emailed, the macro for "return survey" still refers or is linked to the original file. When someone opens the new file, they won't have access to the original file and the link won't be available to run the macro. How can I make sure the code is carried over as well?
Sorry, I' didn't put any code tags below. Any help would be appreciated. I attached the file.


Sub Launch_Survey()

'Working in Excel 2000-2016
'For Tips see: http://www.rondebruin.nl/win/winmail/Outlook/tips.htm
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 Destwb.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
FileExtStr = ".xlsm": FileFormatNum = 52

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 = Sourcewb.Name & " " & Format(Now, "dd-mmm-yy h-mm-ss")

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

CurrentUser = Application.UserName '.Session.CurrentUser

With Destwb
.SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum
On Error Resume Next
With OutMail
.To = Range("G3").Text
.CC = Range("G4").Text
.BCC = ""
.Subject = Range("G5").Text
.Body = CurrentUser + " " & vbNewLine & vbNewLine & Range("G6").Value
.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 If
End Sub

mancubus
06-04-2018, 12:55 AM
?

copy below code to a standard code module


Sub vbax_62882_email_active_sht_with_code_mocules()
'http://www.vbaexpress.com/forum/showthread.php?62882-Code-is-dropped-when-sheet-is-copied-and-emailed

Dim EmailSht As String, AttFileName As String
Dim i As Long

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

With ThisWorkbook
EmailSht = .ActiveSheet.Name
AttFileName = Environ("temp") & "\" & Replace(.Name, ".xlsm", " " & Format(Now, "dd-mmm-yy h-mm-ss")) & ".xlsm"
.SaveCopyAs AttFileName
End With

Workbooks.Open AttFileName
With ActiveWorkbook
For i = .Sheets.Count To 1 Step -1
If .Worksheets(i).Name <> EmailSht Then .Worksheets(i).Delete
Next i
.Close True
End With

With CreateObject("Outlook.Application")
With .CreateItem(olMailItem)
.To = Range("G3").Text
.CC = Range("G4").Text
.BCC = ""
.Subject = Range("G5").Text
.Body = Application.UserName & vbNewLine & vbNewLine & Range("G6").Value
.Attachments.Add AttFileName
.Display
End With
End With

Kill AttFileName

With Application
.EnableEvents = False
End With

End Sub

mancubus
06-04-2018, 01:08 AM
or, as an alternative, you can copy below code to "ActiveSheet"s code module:



Sub vbax_62882_email_active_sht_with_code_mocules()
'http://www.vbaexpress.com/forum/showthread.php?62882-Code-is-dropped-when-sheet-is-copied-and-emailed

Dim EmailSht As String, AttFileName As String
Dim i As Long

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

With ThisWorkbook
AttFileName = Environ("temp") & "\" & Replace(.Name, ".xlsm", " " & Format(Now, "dd-mmm-yy h-mm-ss")) & ".xlsm"
.ActiveSheet.Copy
End With

With ActiveWorkbook
.SaveAs AttFileName, 52
.Close False
End With


With CreateObject("Outlook.Application")
With .CreateItem(olMailItem)
.To = Range("G3").Text
.CC = Range("G4").Text
.BCC = ""
.Subject = Range("G5").Text
.Body = Application.UserName & vbNewLine & vbNewLine & Range("G6").Value
.Attachments.Add AttFileName
.Display
End With
End With

Kill AttFileName

With Application
.EnableEvents = False
End With


End Sub

Sully1440
06-04-2018, 12:16 PM
Thank you. Works perfectly.

:friends: