Modify formula to apply to range row 2 to the last row in a column

abberyfarm

Well-known Member
Joined
Aug 14, 2011
Messages
733
Hi,

I recorded the macro below which applies a formula to range in Col C.

Would anybody know how I can modify it to apply the formula down as far as the last used row in Col B? As the formula uses values from Column B.

Appreciate any help

Thanks


Code:
Range("C2").Select
    Selection.FormulaArray = _
        "=IF(LEFT(TEXT(RC[-2],""dd/mm/yyyy hh:mm""),13)=LEFT(TEXT(R[1]C[-2],""dd/mm/yyyy hh:mm""),13),"""",AVERAGE(IF(LEFT(TEXT(R2C1:R[COLOR=#00ff00]10463[/COLOR]C1,""dd/mm/yyyy hh:mm""),13)=LEFT(TEXT(RC[-2],""dd/mm/yyyy hh:mm""),13),R2C2:R[COLOR=#00ff00]10463[/COLOR]C2)))"
    Selection.AutoFill Destination:=Range("C2:C[COLOR=#00ff00]10463[/COLOR]")
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop

VoG

Legend
Joined
Jun 19, 2002
Messages
63,650
Try

Code:
Dim LR As Long
LR = Range("B" & Rows.Count).End(xlUp).Row
Range("C2").FormulaArray = _
        "=IF(LEFT(TEXT(RC[-2],""dd/mm/yyyy hh:mm""),13)=LEFT(TEXT(R[1]C[-2],""dd/mm/yyyy hh:mm""),13),"""",AVERAGE(IF(LEFT(TEXT(R2C1:R10463C1,""dd/mm/yyyy hh:mm""),13)=LEFT(TEXT(RC[-2],""dd/mm/yyyy hh:mm""),13),R2C2:R10463C2)))"
Range("C2").AutoFill Destination:=Range("C2:C" & LR)
 

abberyfarm

Well-known Member
Joined
Aug 14, 2011
Messages
733
Thanks for you help.

I also need to change the "R10463C1" part of the code to go down to the lastrow in column A but not sure how you do this in the R1C1 format?

Thanks



 

VoG

Legend
Joined
Jun 19, 2002
Messages
63,650
Try (untested)

Code:
Dim LR As Long, LRA As Long
LR = Range("B" & Rows.Count).End(xlUp).Row
LRA = Range("A" & Rows.Count).End(xlUp).Row
Range("C2").FormulaArray = _
        "=IF(LEFT(TEXT(RC[-2],""dd/mm/yyyy hh:mm""),13)=LEFT(TEXT(R[1]C[-2],""dd/mm/yyyy hh:mm""),13),"""",AVERAGE(IF(LEFT(TEXT(R2C1:R" & LRA & "C1,""dd/mm/yyyy hh:mm""),13)=LEFT(TEXT(RC[-2],""dd/mm/yyyy hh:mm""),13),R2C2:R" & LRA & "C2)))"
Range("C2").AutoFill Destination:=Range("C2:C" & LR)
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,651
Messages
5,838,586
Members
430,557
Latest member
MK15

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