"Copy method of range class failed error"

Johnsie007

New Member
Joined
May 11, 2020
Messages
17
Office Version
  1. 2010
Platform
  1. Windows
Hi,

I am currently using a VBA macro to copy data from one worksheet into another workbook.

The VBA macro uses a loop as per the code below:

VBA Code:
Sub LooperOffline()

Dim Count As Integer
Dim FirstColNum As Integer
Dim LastColNum As Integer
Dim PasteRange As String
Dim FirstColLet As String
Dim LastColLet As String

FirstColNum = 1
LastColNum = 27

Do Until Count = 1825

Application.Wait (Now + TimeValue("00:00:02"))
FirstColLet = WorksheetFunction.Substitute(Workbooks("Returns.xlsx").Sheets("Test").Cells(1, FirstColNum).Address(RowAbsolute:=False, ColumnAbsolute:=False, External:=False), 1, "")
LastColLet = WorksheetFunction.Substitute(Workbooks("Returns.xlsx").Sheets("Test").Cells(1, LastColNum).Address(RowAbsolute:=False, ColumnAbsolute:=False, External:=False), 1, "")
PasteRange = FirstColLet & 1 & ":" & LastColLet & 59
Workbooks("(SmallOrds).xlsm").Sheets("Small Ords Portfolio").Range("A1:AA59").Copy Destination:=Workbooks("Returns.xlsx").Sheets("Test").Range(PasteRange)
Workbooks("Returns.xlsx").Sheets("Test").Range(PasteRange).Value = Workbooks("(SmallOrds).xlsm").Sheets("Small Ords Portfolio").Range("A1:AA59").Value
Workbooks("Returns.xlsx").Sheets("Test").Columns.AutoFit
Workbooks("Returns.xlsx").Sheets("Test").Rows.AutoFit
Workbooks("(SmallOrds).xlsm").Sheets("Data").Range("AN1").Value = Workbooks("(SmallOrds).xlsm").Sheets("Data").Range("AN1").Value + 1
Workbooks("Returns.xlsx").Sheets("Test").Columns.AutoFit
FirstColNum = FirstColNum + 27
LastColNum = LastColNum + 27
Count = Count + 1
Loop

End Sub

The macro works to begin with, however, it consistently displays the "Copy method of range class failed error" after approximately 400 loops.

The line which the macro fails is "Workbooks("(SmallOrds).xlsm").Sheets("Small Ords Portfolio").Range("A1:AA59").Copy Destination:=Workbooks("Returns.xlsx").Sheets("Test").Range(PasteRange)"

Can anyone please help me understand what is causing this error? Why does the macro work for 400 iterations before running into this error at the same point everytime?

Thanks,

Mike
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Hi & welcome to MrExcel.
Excel has 16,384 columns, but the loop is trying to copy up to columns 49,275
 
Upvote 0
Hi & welcome to MrExcel.
Excel has 16,384 columns, but the loop is trying to copy up to columns 49,275
Fluff,

Thanks for your help.

I thought this may have been part of the problem.

As a result I have restarted the loop, beginning from column A. The previous data remains on the worksheet in the cells below.

Unusually, the error occurs sooner on the second cycle. I.E. before the column issue would arise.

Is there a limit on the total data or size of an excel sheet that could be causing the issue?

Thanks again.
 
Upvote 0
Not that I can think of, what exactly are you trying to do?
 
Upvote 0
Not that I can think of, what exactly are you trying to do?

Copy a snapshot of one worksheet and then paste this into another workbook.

Each snapshot represents a share portfolio on a particular date.

The loop then moves to the next day and repeats the process.

I want each day pasted next to each other on the seperate workbook.

The existing code works, however I keep running into the error explained above. It seems as though I am reaching some kind of limitation within excel, although the amount of data doesn't seem at all extreme?

The data includes formatting, so i am not sure if the extra formatting is creating an issue?

The total file size when the error is received is only about 80MB so not very large. Is there a limit on excel file sizes?

Thanks.
 
Upvote 0
But you are copying the same range everytime.
 
Upvote 0
Yes. Each cycle of the loop represents a new day.

The values within the range change each loop, depending upon the stock valuations for each day.
 
Upvote 0
No sure if this will help.
VBA Code:
Sub LooperOffline()
   Dim i As Long
   With Workbooks("Returns.xlsx").Sheets("Test")
      .UsedRange.Delete
      For i = 1 To 16200 Step 27
         Application.Wait (Now + TimeValue("00:00:02"))
         .Cells(1, i).Resize(59, 27).Value = Workbooks("(SmallOrds).xlsm").Sheets("Small Ords Portfolio").Range("A1:AA59").Value
         .Columns.AutoFit
         .Rows.AutoFit
         Workbooks("(SmallOrds).xlsm").Sheets("Data").Range("AN1").Value = Workbooks("(SmallOrds).xlsm").Sheets("Data").Range("AN1").Value + 1
      Next i
   End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,565
Messages
6,120,254
Members
448,952
Latest member
kjurney

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