Copying worksheet programmatically causes run-time error 1004 in Excel (210684)
The information in this article applies to:
- Microsoft Office Excel 2003
- Microsoft Excel 2002
- Microsoft Excel 2000
- Microsoft Excel 97 for Windows
This article was previously published under Q210684 SYMPTOMS
In Microsoft Excel, when you run a macro that copies worksheets, and then places the worksheets into the same workbook that they originated from, you may receive the following (or similar) run-time error message:
1004: Copy Method of Worksheet Class failed
CAUSEMicrosoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.
This problem can occur when you give the workbook a defined name and then copy the worksheet several times without first saving and closing the workbook, as in the following sample code:
Sub CopySheetTest()
Dim iTemp As Integer
Dim oBook As Workbook
Dim iCounter As Integer
' Create a new blank workbook:
iTemp = Application.SheetsInNewWorkbook
Application.SheetsInNewWorkbook = 1
Set oBook = Application.Workbooks.Add
Application.SheetsInNewWorkbook = iTemp
' Add a defined name to the workbook
' that RefersTo a range:
oBook.Names.Add Name:="tempRange", _
RefersTo:="=Sheet1!$A$1"
' Save the workbook:
oBook.SaveAs "c:\test2.xls"
' Copy the sheet in a loop. Eventually,
' you get error 1004: Copy Method of
' Worksheet class failed.
For iCounter = 1 To 275
oBook.Worksheets(1).Copy After:=oBook.Worksheets(1)
Next
End Sub
RESOLUTIONMicrosoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.
To resolve this problem, save and close the workbook periodically while the copy process is occurring, as in the following sample code:
Sub CopySheetTest()
Dim iTemp As Integer
Dim oBook As Workbook
Dim iCounter As Integer
' Create a new blank workbook:
iTemp = Application.SheetsInNewWorkbook
Application.SheetsInNewWorkbook = 1
Set oBook = Application.Workbooks.Add
Application.SheetsInNewWorkbook = iTemp
' Add a defined name to the workbook
' that RefersTo a range:
oBook.Names.Add Name:="tempRange", _
RefersTo:="=Sheet1!$A$1"
' Save the workbook:
oBook.SaveAs "c:\test2.xls"
' Copy the sheet in a loop. Eventually,
' you get error 1004: Copy Method of
' Worksheet class failed.
For iCounter = 1 To 275
oBook.Worksheets(1).Copy After:=oBook.Worksheets(1)
'Uncomment this code for the workaround:
'Save, close, and reopen after every 100 iterations:
If iCounter Mod 100 = 0 Then
oBook.Close SaveChanges:=True
Set oBook = Nothing
Set oBook = Application.Workbooks.Open("c:\test2.xls")
End If
Next
End Sub
Note The number of times you can copy a worksheet before you must save the workbook varies with the size of the worksheet. WORKAROUND
To work around this problem, insert a new worksheet from a template instead of copying an existing worksheet. To do this:
- Create a new workbook, and then delete all of the worksheets except for one.
- Format the workbook and add any text, data, and charts that you must have in the template by default.
- Click File, and then click Save As.
- In the File name box, type the name that you want for the Excel template.
- In the Save as type list, click Template (*.xlt), and then click Save.
- To insert the template programmatically, use the following code:
Sheets.Add Type:=path\filename
where path\filename is a string that contains the full path and file name for your sheet template.
STATUSMicrosoft has confirmed that this is a problem in the Microsoft products that are listed in the "Applies to" section.
Modification Type: | Minor | Last Reviewed: | 10/11/2006 |
---|
Keywords: | kbbug kberrmsg kbpending KB210684 |
---|
|