assign array from a sheet to an array variable without selecting the sheet that contains the data for the array.

Shodi

Board Regular
Joined
May 24, 2016
Messages
51
Hi, I am trying to assign an array that in stored in Sheet1 Range("A1:D102"), to the variable 'tarr' and then populate the same data "Sheet2" starting with cell "C2". But when I reach
"tarr = sh1.Range("A1", Range("A1").Offset(vc - 1, hc - 1))" it gives me the error "Method 'Range' of object '_Worksheet' failed

If I add "sh1.Select" before assigning the array variable then it works.
Same issue with "sh2.Range("C2", Range("C2").Offset(vc - 1, hc - 1)) = tarr".
If I add sh2.select then it works fine.

I have Worksheet_SelectionChange(ByVal Target As Range) active in Sheet 2 and this cannot be disabled. It fires every time the sheet gets selected.

Is there a way around this?

VBA Code:
Public tarr() As Variant, sh1 As Worksheet, sh2 As Worksheet
Sub verifyarr()
Dim vc As Long, hc As Long

Set sh1 = ThisWorkbook.Worksheets("Sheet1")
Set sh2 = ThisWorkbook.Worksheets("Sheet2")

vc = sh1.Range("A" & Rows.Count).End(xlUp).Row
hc = sh1.Cells(1, Cells.Columns.Count).End(xlToLeft).Column
sh1.Select
tarr = sh1.Range("A1", Range("A1").Offset(vc - 1, hc - 1))

sh2.Range("C2", Range("C2").Offset(vc - 1, hc - 1)) = tarr

End Sub
 

Some videos you may like

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
55,411
Office Version
  1. 365
Platform
  1. Windows
You need to qualify both ranges like
VBA Code:
sh2.Range("C2", sh2.Range("C2").Offset(vc - 1, hc - 1)) = tarr
Or just
VBA Code:
sh2.Range("C2").Resize(vc, hc) = tarr
 
Solution

Shodi

Board Regular
Joined
May 24, 2016
Messages
51
Thanks a lot Fluff. It works.
Could you also be kind enough to answer my previous question?
Forever grateful.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
55,411
Office Version
  1. 365
Platform
  1. Windows
You're welcome & thanks for the feedback.
 

Watch MrExcel Video

Forum statistics

Threads
1,127,314
Messages
5,623,945
Members
416,001
Latest member
teabag

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
Top