Please Help - "Copy method of worksheet class failed."

hehanhan

New Member
Joined
Apr 14, 2016
Messages
47
Hello all the masters in VBA, this is my first post to ask question, but this site is not new to me. I have been absorbing knowledge from all your master posts for very long time. I greatly appreciate all your time and hard work to help people like me who know very very little about VBA code. Without your help, our life will be so painful. I really mean it.

Ok. Here comes with my first question for the form. I "built" a userform for people to fill up some information. The way I designed is that they are able to "merge" data from "sheet2" to a "Master" sheet and then Email the "Master" sheet to via outlook.

However, it is not working the way I wanted. The error message "Copy method of worksheet class failed" keeps coming up... when I clicked "Debug", the following highlighted - Sheets("Master").Copy
I tried many solutions via Google around and search into this site. None of them is working. So please help me! I really appreciate your time for this.
Code:
Private Sub EmailCommandButton_Click()
  
'Working in Excel 2000-2013
'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 Sheets("Master") to a new workbook
    Sheets("Master").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-2013
            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 = "Response of " & Sourcewb.Name
    
     ' in case date and time is required
    '& " " & 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 = "abc@hotmail.ca"
             .CC = ""
             .BCC = ""
             .Subject = "Pothole Repair Log - Cold Mix Asphalt" & Space(5) & Me.tbDate
             .Body = "Hi there, please find enclosed pothole repair log dated" & vbNewLine & vbNewLine
          
             .Attachments.Add Destwb.FullName
          
             'You can add other files also like this
            '.Attachments.Add ("C:\test.txt")
            .Display  'or use .Display or Send
        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
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Hello all the masters in VBA, this is my first post to ask question, but this site is not new to me. I have been absorbing knowledge from all your master posts for very long time. I greatly appreciate all your time and hard work to help people like me who know very very little about VBA code. Without your help, our life will be so painful. I really mean it.

Ok. Here comes with my first question for the form. I "built" a userform for people to fill up some information. The way I designed is that they are able to "merge" data from "sheet2" to a "Master" sheet and then Email the "Master" sheet to via outlook.

However, it is not working the way I wanted. The error message "Copy method of worksheet class failed" keeps coming up... when I clicked "Debug", the following highlighted - Sheets("Master").Copy
I tried many solutions via Google around and search into this site. None of them is working. So please help me! I really appreciate your time for this.
Code:
Private Sub EmailCommandButton_Click()
  
'Working in Excel 2000-2013
'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 Sheets("Master") to a new workbook
    Sheets("Master").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-2013
            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 = "Response of " & Sourcewb.Name
    
     ' in case date and time is required
    '& " " & 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 = "abc@hotmail.ca"
             .CC = ""
             .BCC = ""
             .Subject = "Pothole Repair Log - Cold Mix Asphalt" & Space(5) & Me.tbDate
             .Body = "Hi there, please find enclosed pothole repair log dated" & vbNewLine & vbNewLine
          
             .Attachments.Add Destwb.FullName
          
             'You can add other files also like this
            '.Attachments.Add ("C:\test.txt")
            .Display  'or use .Display or Send
        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
Does Master sheet exists? If so, are you sure it doesn't have blanks among the name?
If the statement above it's true, it should be because the sheet "Master" is hidden, copy command won't work for hidden sheets, make it visible prior to this:
Code:
Sheets("Master").Visible = True
 
Last edited:
Upvote 0
Thank you very much for the quick response. The Master sheet does exist and it does not contain blanks.
 
Upvote 0
WOW! That works!! Thank you Sgdva!!
May I ask you, how do I keep the "Master" sheet hidden in this case. I noticed, once I click email, the sheet become visible. Thank you!!
 
Upvote 0
After its copied, set it to False again
Code:
Sheets("Master").Visible = True
'... your stuff here
Sheets("Master").Visible = False
 
Upvote 0
I think we first must understand WHY it failed when the sheet was hidden.

A book MUST have at least 1 visible sheet.
So Doing Sheets("xx").Copy is creating a New book using that sheet.
But if that sheet was hidden, then it's attempting to create a New book with 0 visible sheets - Error.


I suggest create the new book FIRST, it will already have at least 1 visible sheet.
THEN you can copy the hidden sheet to the new book without error.


Set Destwb = Workbooks.Add
Sourcewb.Sheets("Master").Copy Before:=Destwb.Sheets(1)
 
Last edited:
Upvote 0
I think we first must understand WHY it failed when the sheet was hidden.

A book MUST have at least 1 visible sheet.
So Doing Sheets("xx").Copy is creating a New book using that sheet.
But if that sheet was hidden, then it's attempting to create a New book with 0 visible sheets - Error.


I suggest create the new book FIRST, it will already have at least 1 visible sheet.
THEN you can copy the hidden sheet to the new book without error.


Set Destwb = Workbooks.Add
Sourcewb.Sheets("Master").Copy Before:=Destwb.Sheets(1)
Though, that "dummy" sheet would need to be deleted later too, or it will be sent within the archive.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,614
Messages
6,120,519
Members
448,968
Latest member
Ajax40

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