Code Optimisation

JackDanIce

Well-known Member
Joined
Feb 3, 2010
Messages
9,922
Office Version
  1. 365
Platform
  1. Windows
Hi,

Inherited some code that I'm working through to optimise and update e.g.

Rich (BB code):
Sheet1.Range("A1:A200").Copy
Sheet2.Range("B1:B200").Pastespecial Paste:=xlPasteValues
Application.CutCopyMode = False
Can be replaced by:
Rich (BB code):
Sheet2.Range("B1:B200").Value = Sheet1.Range("A1:A200").Value

However, what I'd like to know is how to apply this, when you don't know the last row number and the starting row number is different in each sheet e.g.
Rich (BB code):
Dim i as Long
i = Sheet1.Range("A" & Rows.Count).End(xlUp).Row
Sheet2.Range("K1").Value = Sheet1.Range("A30:B" & i).Value
With this example, Sheet2.K1 is given the value of Sheet1.A1 i.e. not what I want

This works but it's not quite what I want:
Rich (BB code):
Dim i as Long
i = Sheet1.Range("A" & Rows.Count).End(xlUp).Row
Sheet2.Range("K1:L" & i - 29).Value = Sheet1.Range("A30:B" & i).Value
I have a feeling .Resize may be the answer and ashamed to say, I've still not got around to understanding exactly how this property works.

Any comments, suggestions?

Thanks,
Jack
 

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
Given that you are hardcoding a start range on both sides, why is the i - 29 version not OK?

You could use something like:
Code:
Dim varData
varData = Sheet1.Range("A30:B" & i).Value2
Sheet2.Range("K1").Resize(ubound(vardata, 1), Ubound(vardata, 2)).Value2 = vardata
 
Upvote 0
Thanks Rory, reason it's not ok is because the data may not always start at row 30 and I was hoping to avoid going through the code and hardcoding the relative references everywhere

I think your suggestion is closer to what I had in mind but can you explain please what ".Value2" is, why vardata is a variant variable and say not a range variable and the use of Ubound?

PS Nice signature, hadn't noticed it before!
 
Upvote 0
varData is a variant so that you can just dump the values into it and get an array. Value2 is like Value except that it uses Doubles instead of Date (and therefore usually safer for us non-US personnel) or Currency data, and is a bit faster. Because you have an array, you need Ubound to work out how many rows/columns it has in order to resize the output range.
 
Upvote 0
Thats great and gives me some options to work with. Thank you
 
Upvote 0

Forum statistics

Threads
1,214,584
Messages
6,120,385
Members
448,956
Latest member
JPav

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