combing OFFSET with LASTROW efficiently

heathball

Board Regular
Joined
Apr 6, 2017
Messages
130
Office Version
  1. 365
Platform
  1. Windows
VBA Code:
Dim AC As Integer
Dim myc As range
Set myc = activecell
AC = activecell.Column

'if i have identified the active cell, then i can use the LR to autofill to last row like this
VBA Code:
 LR = ActiveSheet.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
range(myc, Cells(LR, AC)) = "=IFERROR(IF(RC[-3]=1,RC[-1]-RC[-14],""#""),""#"")"

'BUT
'if i am using offset ...
'i cannot see a way to identify the cell or range to be able to use the "LR" autofill

VBA Code:
myc.Offset(0, 12).Formula = "=IFERROR(IF(RC[-3]=1,RC[-1]-RC[-14],""#""),""#"")"

'unless i do this first
VBA Code:
myc.Offset(0, 12).Select
'then call in a seperate autofill macro, which slows down the time of the long macro with 600,000 rows
VBA Code:
Call autofill_downcol_lastrow_v2

(which operates from a selection and works fine, but a little slow)

'is there a way to combine OFFSET with "LASTROW type coding" which keeps it efficient, and not requiring multiple extra lines of code?
'which may look something like this.but not exactly this....

VBA Code:
range((myc,Offset(0, 12)) Cells(LR, AC)) = "=IFERROR(IF(RC[-3]=1,RC[-1]-RC[-14],""#""),""#"")"

'or is it not possible?
 
Last edited:

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
You could do something like this:

VBA Code:
Dim FR As Long, LR As Long
Dim myc As Range

Set myc = ActiveCell
FR = myc.Row
LR = ActiveSheet.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row

myc.Offset(, 12).Resize(LR - FR + 1).Formula = "=IFERROR(IF(RC[-3]=1,RC[-1]-RC[-14],""#""),""#"")"

But it's not clear why your formula is using column references relative to ActiveCell? This relies on ActiveCell being in the correct column. Why not just reference the correct columns directly?
 
Upvote 1
Solution
You could do something like this:

VBA Code:
Dim FR As Long, LR As Long
Dim myc As Range

Set myc = ActiveCell
FR = myc.Row
LR = ActiveSheet.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row

myc.Offset(, 12).Resize(LR - FR + 1).Formula = "=IFERROR(IF(RC[-3]=1,RC[-1]-RC[-14],""#""),""#"")"

But it's not clear why your formula is using column references relative to ActiveCell? This relies on ActiveCell being in the correct column. Why not just reference the correct columns directly?
Thanks, Stephen, that seems to work very well. I will check out more about "RESIZE"

I am using relative references as it is for testing, which occurs anywhere on any sheet, and refers to the dynamic first starting column of any test.
 
Upvote 0

Forum statistics

Threads
1,216,728
Messages
6,132,374
Members
449,722
Latest member
Martyn TEL

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