referencing a named range in an external worksheet

rsclark

Board Regular
Joined
May 7, 2004
Messages
101
Hi Guys. Hope this is an easy one.

In my spreadsheet i want to create a macro that will copy in the contents of a named range in an external workbook (preferably without opening the external workbook). I cannot seem to be able to get the notation right to even access the external named range - i get the #name error.
my external sheet is called 'BANKSORTER.XLS' and the named range is called 'W2DATA' which is a range of about 1000 cells.

Thanks in anticipation!
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Assume you wish to copy the named range W2DATA in a sheet named 'MySheet' starting from cell G2
Assume the Source Workbook is C:\My Documents\BANKSORTER.XLS
Copy the following code to a module in the destination workbook
Modify the code as required in respect of SourceBook name and TopLeftCell of the destination range address
The code does open the workbook but with ScrUpdt off, this actvity is not visible

Code:
Sub CopyW2DATA()
  Dim SourceBook As Workbook, CopyFrom As Range, CopyTo As Range
  Set CopyTo = Worksheets("MySheet").Range("G2")
  Application.ScreenUpdating = False
  Set SourceBook = Workbooks.Open("C:\My Documents\BANKSORTER.XLS")
  Set CopyFrom = Range("W2Data")
  CopyFrom.Copy CopyTo
  SourceBook.Close False
  Application.ScreenUpdating = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,522
Messages
6,114,112
Members
448,549
Latest member
brianhfield

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