Help with application-defined or object-defined error

JARichard74

Board Regular
Joined
Dec 16, 2019
Messages
114
Office Version
  1. 365
Platform
  1. Windows
Get the error on this line wb.Worksheets("Bids").Range("A1:RZ100").Value = wb2.Worksheets("All").Range("A1:RZ100").Value. Copying a range but could be copying the entire sheet

VBA Code:
Option Explicit

Sub FetchMERX_WF()
    Dim wb As Workbook, wb2 As Workbook
    Dim ws As Worksheet
    Dim vFile As Variant
    Dim xRng As Range
    Dim xLastRow As Long
    Dim xLastRow2 As Long
    Dim i As Integer
    
    Application.ScreenUpdating = False
    Application.AutoCorrect.AutoFillFormulasInLists = False

    'Set destination workbook
    Set wb = ActiveWorkbook
    
    'Open the source workbook from MERX
    If MsgBox("In the next step, select the Excel file you downloaded from MERX", vbOKCancel + vbInformation) = vbCancel Then Exit Sub
    vFile = Application.GetOpenFilename("Excel-files,*.xls", _
        1, "Select One File To Open", , False)
    'if the user didn't select a file, exit sub
    If TypeName(vFile) = "Boolean" Then Exit Sub
    Workbooks.Open vFile
    
    'Set source workbook
    Set wb2 = ActiveWorkbook

    'Copy data from the source workbook to destination workbook
    wb.Worksheets("Bids").Range("A1:RZ100").Value = wb2.Worksheets("All").Range("A1:RZ100").Value
    ActiveWorkbook.Close SaveChanges:=False
    Set wb = ActiveWorkbook
    wb.Worksheets("Bids").Activate
    
'Setup the Price sheet
Call Module18.GetBids

' Clears the imported data in the and Bids sheet
ThisWorkbook.Sheets("Bids").Cells.Clear

' Reinstate the protection
ThisWorkbook.Worksheets("Prep").Protect Password:="", Contents:=True
ThisWorkbook.Worksheets("Prep").EnableSelection = xlUnlockedCells

Application.ScreenUpdating = True
Application.CutCopyMode = False
End Sub
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
Hi,

Please make sure the specified range "RZ100" exists in the sheet.

If you are coping the content please check below:

VBA Code:
wb2.Worksheets("All").Range("A1:RZ100").Copy Destination:=wb.Worksheets("Bids").Range("A1")
 
Upvote 0
Hi,

Please make sure the specified range "RZ100" exists in the sheet.

If you are coping the content please check below:

VBA Code:
wb2.Worksheets("All").Range("A1:RZ100").Copy Destination:=wb.Worksheets("Bids").Range("A1")
I checked the source sheet and the columns stop at IV for some reason. What would be the code to copy the entire sheet
 
Upvote 0
I checked the source sheet and the columns stop at IV for some reason.
The reason is that the file that you are opening (wb2) is *.xls format which always only goes to column IV
vFile = Application.GetOpenFilename("Excel-files,*.xls", _ 1, "Select One File To Open", , False)

What would be the code to copy the entire sheet
Untested, but try
Rich (BB code):
wb.Worksheets("Bids").Range("A1:RZ100").Value = wb2.Worksheets("All").Range("A1:RZ100").Value
wb2.Worksheets("All").UsedRange.Copy
wb.Worksheets("Bids").Range("A1").PasteSpecial xlPasteValues
 
Upvote 0
The reason is that the file that you are opening (wb2) is *.xls format which always only goes to column IV



Untested, but try
Rich (BB code):
wb.Worksheets("Bids").Range("A1:RZ100").Value = wb2.Worksheets("All").Range("A1:RZ100").Value
wb2.Worksheets("All").UsedRange.Copy
wb.Worksheets("Bids").Range("A1").PasteSpecial xlPasteValues
I used
VBA Code:
wb2.Worksheets("All").Cells.Copy Destination:=wb.Worksheets("Bids").Range("A1")
Which seems to work
 
Upvote 0
I used
VBA Code:
wb2.Worksheets("All").Cells.Copy Destination:=wb.Worksheets("Bids").Range("A1")
Which seems to work
That would work but I would still use UsedRange as it seems pointless copying nearly 17,000,000 cells when I am sure you are not using anything like that many.
Also, I thought from your earlier code that you only wanted values copied, not formulas, formatting, conditional formatting, data validation etc hence my 2-line suggestion.
If copy/paste is fine then I would use

Rich (BB code):
wb2.Worksheets("All").UsedRange.Copy Destination:=wb.Worksheets("Bids").Range("A1")
 
Upvote 0
Solution
That would work but I would still use UsedRange as it seems pointless copying nearly 17,000,000 cells when I am sure you are not using anything like that many.
Also, I thought from your earlier code that you only wanted values copied, not formulas, formatting, conditional formatting, data validation etc hence my 2-line suggestion.
If copy/paste is fine then I would use

Rich (BB code):
wb2.Worksheets("All").UsedRange.Copy Destination:=wb.Worksheets("Bids").Range("A1")
Thanks Peter, marked as solution.
 
Upvote 0

Forum statistics

Threads
1,213,562
Messages
6,114,326
Members
448,564
Latest member
ED38

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