Email VBA Code/Break Link

~Scorpion~

New Member
Joined
Mar 11, 2015
Messages
9
I currently am using this VBA code below to email a single sheet from my workbook, however when the end user opens the attachment it keeps asking to edit links. What can I add to this code so that it breaks the link upon emailing so they don't get the prompt?



Sub Mail_ActiveSheet()
' Works in Excel 2000, Excel 2002, Excel 2003, Excel 2007, Excel 2010, Outlook 2000, Outlook 2002, Outlook 2003, Outlook 2007, Outlook 2010
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

' Next, copy the sheet to a new workbook.
' You can also use the following line, instead of using the ActiveSheet object,
' if you know the name of the sheet you want to mail :
' Sheets("Sheet5").Copy
ActiveSheet.Copy
Set Destwb = ActiveWorkbook

' Determine the Excel version, and file extension and format.
With Destwb
If Val(Application.Version) < 12 Then
' For Excel 2000-2003
FileExtStr = ".xls": FileFormatNum = -4143
Else
' For Excel 2007-2010, exit the subroutine if you answer
' NO in the security dialog that is displayed when you copy
' a sheet from an .xlsm file with macros disabled.
If Sourcewb.Name = .Name Then
With Application
.ScreenUpdating = True
.EnableEvents = True
End With
MsgBox "You answered NO in the security dialog."
Exit Sub
Else
FileExtStr = ".xlsm": FileFormatNum = 52
End If
End If
End With

' You can use the following statements to change all cells in the
' worksheet to values.
' With Destwb.Sheets(1).UsedRange
' .Cells.Copy
' .Cells.PasteSpecial xlPasteValues
' .Cells(1).Select
' End With
' Application.CutCopyMode = False

' Save the new workbook, mail, and then delete it.
TempFilePath = Environ$("temp") & "\"
TempFileName = ""

Set OutApp = CreateObject("Outlook.Application")

Set OutMail = OutApp.CreateItem(0)

With Destwb
.SaveAs TempFilePath & TempFileName & FileExtStr, _
FileFormat:=FileFormatNum
On Error Resume Next
' Change the mail address and subject in the macro before
' running the procedure.
With OutMail
.To = ""
.CC = ""
.BCC = ""
.Subject = ""
.Body = ""
.Attachments.Add Destwb.FullName
' You can add other files by uncommenting the following statement.
'.Attachments.Add ("C:\test.txt")
' In place of the following statement, you can use ".Display" to
' display the mail.
.Display
End With
On Error GoTo 0
.Close SaveChanges:=False
End With

' Delete the file after sending.
Kill TempFilePath & TempFileName & FileExtStr

Set OutMail = Nothing
Set OutApp = Nothing

With Application
.ScreenUpdating = True
.EnableEvents = True

End With
End Sub
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
Try this...

Code:
    [color=green]' Next, copy the sheet to a new workbook.[/color]
    [color=green]' You can also use the following line, instead of using the ActiveSheet object,[/color]
    [color=green]' if you know the name of the sheet you want to mail :[/color]
    [color=green]' Sheets("Sheet5").Copy[/color]
    ActiveSheet.Copy
    [color=darkblue]Set[/color] Destwb = ActiveWorkbook
    
[B]    [color=darkblue]Dim[/color] Link [color=darkblue]As[/color] [color=darkblue]Variant[/color]
    [color=darkblue]If[/color] [color=darkblue]Not[/color] IsEmpty(Destwb.LinkSources(xlExcelLinks)) [color=darkblue]Then[/color]
        [color=darkblue]For[/color] [color=darkblue]Each[/color] Link [color=darkblue]In[/color] Destwb.LinkSources(Type:=xlLinkTypeExcelLinks)
            Destwb.BreakLink _
                    Name:=Link, _
                    Type:=xlLinkTypeExcelLinks
        [color=darkblue]Next[/color] Link
    [color=darkblue]End[/color] [color=darkblue]If[/color][/B]
 
Last edited:
Upvote 0
When I ran this I got a error code 400. Just to make sure I inserted correctly below is how it looks after I added what you wrote.


Sub Mail_ActiveSheet()
' Works in Excel 2000, Excel 2002, Excel 2003, Excel 2007, Excel 2010, Outlook 2000, Outlook 2002, Outlook 2003, Outlook 2007, Outlook 2010
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

' Next, copy the sheet to a new workbook.
' You can also use the following line, instead of using the ActiveSheet object,
' if you know the name of the sheet you want to mail :
' Sheets("Sheet5").Copy
ActiveSheet.Copy
Set Destwb = ActiveWorkbook

Dim Link As Variant
If Not IsEmpty(Destwb.LinkSources(xlExcelLinks)) Then
For Each Link In Destwb.LinkSources(Type:=xlLinkTypeExcelLinks)
Destwb.BreakLink _
Name:=Link, _
Type:=xlLinkTypeExcelLinks
Next Link
End If
' Determine the Excel version, and file extension and format.
With Destwb
If Val(Application.Version) < 12 Then
' For Excel 2000-2003
FileExtStr = ".xls": FileFormatNum = -4143
Else
' For Excel 2007-2010, exit the subroutine if you answer
' NO in the security dialog that is displayed when you copy
' a sheet from an .xlsm file with macros disabled.
If Sourcewb.Name = .Name Then
With Application
.ScreenUpdating = True
.EnableEvents = True
End With
MsgBox "You answered NO in the security dialog."
Exit Sub
Else
FileExtStr = ".xlsm": FileFormatNum = 52
End If
End If
End With

' You can use the following statements to change all cells in the
' worksheet to values.
' With Destwb.Sheets(1).UsedRange
' .Cells.Copy
' .Cells.PasteSpecial xlPasteValues
' .Cells(1).Select
' End With
' Application.CutCopyMode = False

' Save the new workbook, mail, and then delete it.
TempFilePath = Environ$("temp") & "\"
TempFileName = ""

Set OutApp = CreateObject("Outlook.Application")

Set OutMail = OutApp.CreateItem(0)

With Destwb
.SaveAs TempFilePath & TempFileName & FileExtStr, _
FileFormat:=FileFormatNum
On Error Resume Next
' Change the mail address and subject in the macro before
' running the procedure.
With OutMail
.To = ""
.CC = ""
.BCC = ""
.Subject = ""
.Body = ""
.Attachments.Add Destwb.FullName
' You can add other files by uncommenting the following statement.
'.Attachments.Add ("C:\test.txt")
' In place of the following statement, you can use ".Display" to
' display the mail.
.Display
End With
On Error GoTo 0
.Close SaveChanges:=False
End With

' Delete the file after sending.
Kill TempFilePath & TempFileName & FileExtStr

Set OutMail = Nothing
Set OutApp = Nothing

With Application
.ScreenUpdating = True
.EnableEvents = True

End With
End Sub
 
Last edited:
Upvote 0
See my signature block below about the use of CODE tags. It makes reading your code much easier.

It looks like you implemented it correctly.

What line of code is highlighted when you click the Debug button on the error dialog? What is the error description?

If you comment out the newly added code block, does the error go away?
 
Upvote 0
Ok, I see why it gave me the code, it is because my sheet is a protected sheet if I unprotect it will let me email and not get the code, however I still get the edit link prompt upon opening.
 
Upvote 0
Try this...

Code:
    [COLOR=green]' Next, copy the sheet to a new workbook.[/COLOR]
    [COLOR=green]' You can also use the following line, instead of using the ActiveSheet object,[/COLOR]
    [COLOR=green]' if you know the name of the sheet you want to mail :[/COLOR]
    [COLOR=green]' Sheets("Sheet5").Copy[/COLOR]
    ActiveSheet.Copy
    [COLOR=darkblue]Set[/COLOR] Destwb = ActiveWorkbook
    
[B]    [COLOR=darkblue]Dim[/COLOR] Link [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR], vType [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]For[/COLOR] [COLOR=darkblue]Each[/COLOR] vType [COLOR=darkblue]In[/COLOR] Array(xlLinkTypeExcelLinks, xlOLELinks, xlPublishers, xlSubscribers)
        [COLOR=darkblue]If[/COLOR] [COLOR=darkblue]Not[/COLOR] IsEmpty(Destwb.LinkSources(Type:=vType)) [COLOR=darkblue]Then[/COLOR]
            [COLOR=darkblue]For[/COLOR] [COLOR=darkblue]Each[/COLOR] Link [COLOR=darkblue]In[/COLOR] Destwb.LinkSources(Type:=vType)
                Destwb.BreakLink _
                        Name:=Link, _
                        Type:=vType
            [COLOR=darkblue]Next[/COLOR] Link
        [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
    [COLOR=darkblue]Next[/COLOR] vType
    Destwb.UpdateLinks = xlUpdateLinksNever[/B]
 
Upvote 0
Works perfect!! What can be added so it allows me to send with it being a protected sheet because with this code added it will not let me send in protected mode, and I really prefer leave in protected mode?
 
Upvote 0
Works perfect!! What can be added so it allows me to send with it being a protected sheet because with this code added it will not let me send in protected mode, and I really prefer leave in protected mode?

You're welcome.

Change the password to suit.

Code:
    [color=darkblue]Dim[/color] Link [color=darkblue]As[/color] [color=darkblue]Variant[/color], vType [color=darkblue]As[/color] [color=darkblue]Variant[/color]
    [B]Destwb.Sheets(1).Unprotect Password:="Secret"[/B]
    [color=darkblue]For[/color] [color=darkblue]Each[/color] vType [color=darkblue]In[/color] Array(xlLinkTypeExcelLinks, xlOLELinks, xlPublishers, xlSubscribers)
        [color=darkblue]If[/color] [color=darkblue]Not[/color] IsEmpty(Destwb.LinkSources(Type:=vType)) [color=darkblue]Then[/color]
            [color=darkblue]For[/color] [color=darkblue]Each[/color] Link [color=darkblue]In[/color] Destwb.LinkSources(Type:=vType)
                Destwb.BreakLink _
                        Name:=Link, _
                        Type:=vType
            [color=darkblue]Next[/color] Link
        [color=darkblue]End[/color] [color=darkblue]If[/color]
    [color=darkblue]Next[/color] vType
    Destwb.UpdateLinks = xlUpdateLinksNever
    [B]Destwb[B].Sheets(1)[/B].Protect Password:="Secret"[/B]
 
Upvote 0
Sweeeet, works perfect!! I have one last dilemma hopefully you can help with, using this same code when I email my other macros that are within this sheet being emailed does not work on the end user that opens it, for example I have a date picker macro and the calendar does not work when sent through email using this macro, any ideas?
 
Upvote 0
I forgot to say the other macros I have assign to a object and that object no longer has the macro assigned to it after emailing
 
Upvote 0

Forum statistics

Threads
1,214,649
Messages
6,120,728
Members
448,987
Latest member
marion_davis

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