Message Box Pop up twice while closing workbook event

Negi1984

Board Regular
Joined
May 6, 2011
Messages
198
Hi All,

I am using below code to save the current file in another location and also want a pop up message if user want to save a copy of file or not ?
but every time I am closing the workbook the message box pop up twice.
Can anybody help me out what mistake I am doing ?

HTML:
Private Sub Workbook_BeforeClose(Cancel As Boolean)

       Dim MyFile As String

         'On Error GoTo Error_handler:
         
       MyFile = ActiveWorkbook.Name
       ' Do not display the message about overwriting the existing file.
       Application.DisplayAlerts = False
       
Dim Connection As Variant
For Each Connection In ActiveWorkbook.Connections
    Connection.OLEDBConnection.BackgroundQuery = False
Next Connection
       
       ActiveWorkbook.RefreshAll

       ActiveWorkbook.Save
              

Dim UserAnswer As Long
UserAnswer = MsgBox("Would you like to save file in Network drive ?", vbYesNo, "Save?")

If UserAnswer = vbYes Then
       ActiveWorkbook.SaveAs Filename:="C:\Users\abc\Documents" & MyFile
       ' Close the workbook by using the following.
       
       MsgBox "File Saved in Network Drive"

       ActiveWorkbook.Close
 
Else
      ActiveWorkbook.Save
      ActiveWorkbook.Close

End If
'Error_handler:
'MsgBox "Auto Save Cancelled"

End Sub
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Try this, I fixed the code and removed the ActiveWorkbook.Close lines

Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
  Dim MyFile As String
  Dim UserAnswer As Long
  Dim Connection As Variant
  MyFile = ActiveWorkbook.Name
  ' Do not display the message about overwriting the existing file.
  Application.DisplayAlerts = False
  For Each Connection In ActiveWorkbook.Connections
    Connection.OLEDBConnection.BackgroundQuery = False
  Next Connection
  ActiveWorkbook.RefreshAll
  ActiveWorkbook.Save
  UserAnswer = MsgBox("Would you like to save file in Network drive ?", vbYesNo, "Save?")
  If UserAnswer = vbYes Then
    ActiveWorkbook.SaveCopyAs Filename:="C:\Users\abc\Documents\" & MyFile
    MsgBox "File Saved in Network Drive"
  Else
    ActiveWorkbook.Save
  End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,538
Messages
6,114,220
Members
448,554
Latest member
Gleisner2

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