Code is not working

abeed

Board Regular
Joined
Nov 19, 2005
Messages
79
Hi:
The following code giving application error:

rs.Range(Cells(sr, 2), Cells(sr, 13)).Value = ds.Range(Cells(tr, cn), Cells(tr, cn + 11)).Value

--
rs is my rport shhet,ds is my data sheet in 2 different workbook. I am trying to copy from ds to rs.
at the first loop iteration:
sr =10,tr=10,cn=2

--Thanks in advance
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Excel does not like it when you try to set a multiple cell range equal to another multiple cell range.

Here are two solutions:
1. Write a loop (probably not that efficient)
2. Use Copy & Paste macro (see below)

Code:
    rs.Activate
    Range(Cells(sr, 2), Cells(sr, 13)).Copy
    ds.Activate
    Cells(tr, cn).Select
    ActiveSheet.Paste
    Application.CutCopyMode = False
 
Upvote 0
Hi Jmiskey:

The code working fine if I dont use any variable(like sr, tr etc).
For example,
rs.Range("b2:b13").Value = ds.Range("b10:b21")).Value

Thanks
 
Upvote 0
abeed,

I stand corrected.

That behavior is strange indeed. It seems that if you do not have a direct range reference, VBA does not like it unless you first activate the second worksheet.

Here is a solution I hope you will find acceptable.
Code:
    Dim Range1 As Range
    Dim Range2 As Range
    
    Set Range1 = rs.Range(Cells(sr, 2), Cells(sr, 13))
    ds.Activate
    Set Range2 = ds.Range(Cells(tr, cn), Cells(tr, cn + 11))
    
    Range1.Value = Range2.Value
 
Upvote 0
Hi Jmiskey:

Oaah. Its working man. I got all my data brought into my report sheet. Thanks thanks a lot. I will get back to you soon with other issues.

You people are cool!!
 
Upvote 0
Glad to help.

If you have other issues (not related to this one), be sure to post them in a new thread. That way you will get the benefit of more people looking at it as an "unanswered" post.
 
Upvote 0
This seems to work

<font face=Courier New><SPAN style="color:#00007F">Sub</SPAN> foo()
<SPAN style="color:#00007F">Dim</SPAN> rs <SPAN style="color:#00007F">As</SPAN> Worksheet, ds <SPAN style="color:#00007F">As</SPAN> Worksheet, sr <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>, tr <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>, cn <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>
<SPAN style="color:#00007F">Set</SPAN> rs = Worksheets("Sheet1")
<SPAN style="color:#00007F">Set</SPAN> ds = Worksheets("Sheet2")
sr = 10
tr = 10
cn = 2
rs.Range(rs.Cells(sr, 2), rs.Cells(sr, 13)).Value = ds.Range(ds.Cells(tr, cn), ds.Cells(tr, cn + 11)).Value
<SPAN style="color:#00007F">Set</SPAN> rs = <SPAN style="color:#00007F">Nothing</SPAN>
<SPAN style="color:#00007F">Set</SPAN> ds = <SPAN style="color:#00007F">Nothing</SPAN>
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN>
</FONT>
 
Upvote 0
Thanks jon. I learned something new today.

It looks like the key is that you have to preface EVERY range reference with the Worksheet variable; not just the ones that start RANGE, but also the ones that start CELLS. I guess the reference in front of RANGE doesn't carry over all the way through.
 
Upvote 0
jmiskey said:
Thanks jon. I learned something new today.

It looks like the key is that you have to preface EVERY range reference with the Worksheet variable; not just the ones that start RANGE, but also the ones that start CELLS. I guess the reference in front of RANGE doesn't carry over all the way through.

Not sure, this is behavior I'm not familiar with - the structure

Workshee('ref1").Range(Cells(rowref, colref), Cells(RowRef, ColRef)) = ...

should be sufficient as the period should bind the Range to the Worksheet, no?

I'm just not seeing the obvious...
 
Upvote 0
I agree. I thought it should work, but apparently it doesn't, as we have shown that:

rs.Range(rs.Cells(sr, 2), rs.Cells(sr, 13)).Value = ds.Range(ds.Cells(tr, cn), ds.Cells(tr, cn + 11)).Value

works and

rs.Range(Cells(sr, 2), Cells(sr, 13)).Value = ds.Range(Cells(tr, cn), Cells(tr, cn + 11)).Value

does not work.

Seems a little redudant to have to put the Sheet references on everything inside the RANGE reference, but maybe it is just one of those Excel/VBA things.
 
Upvote 0

Forum statistics

Threads
1,213,532
Messages
6,114,177
Members
448,554
Latest member
Gleisner2

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