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]")
 

Some videos you may like

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying

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)
 

Watch MrExcel Video

Forum statistics

Threads
1,109,436
Messages
5,528,758
Members
409,834
Latest member
vexceled

This Week's Hot Topics

  • Change military grades into rank
    Afternoon all Need help with formula that will change military rank (i.e. 1, 2, 3 into Amn, A1C, SrA). Running IF formula that does not work...
  • VBA COUNTIF SOLUTION
    Hi The following are the errors spread across the several columns from E to Q ie. 13 columns across several sheets with more than 500 rows per...
  • INSERT ROW WITH SPECIFIS TEXT IN A COLUMN
    Hi All! How can identify that that the row to be inserted has to be inserted before 1st row with specific text in column F. If I record the...
  • Auto-Create a monthly Sign in sheet for preschool students
    The image below is what each page looks like. Above is space for the "Child Name" "Month" "Class" School days are obviously Monday-Friday but...
  • VBA vlookup multiple results
    Hi folks, Hopefully someone out there can help. I have a list to vlookup which works (ish). the lookup only picks up the first instance of the...
  • Extract values for earliest/latest times
    I am trying to put together a formula to get the earliest start time, the latest end time from column A for each person in Column B-F without the...
Top