Auto fill for variable lengths using a macro

etpeterson

New Member
Joined
Jan 19, 2005
Messages
18
I have to do an auto fill of a formula I copy to a cell inside of a macro. I pre recorded the macro so the code looks like this,

Selection.AutoFill Destination:=Range("I24:I123")

This code needs to execute on different worksheets that will be different lengths. My "selection" changes properly depending on what worksheet I am in, but the range of the auto fill does not. What should I do?

Thanks,
Eric
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Hi Eric,

You need to establish the end of the data range that you are autofilling against. Then use this as the endpoint of the destination range. You must also include your start point as the start of the destination range.

The following simple example fills down the formulas in B1 and C1 based upon the data in column A.
Code:
Sub AutoFillIt()
    Dim rngData As Range, rngFormula As Range
    
    With ThisWorkbook.Worksheets("Sheet1")
        Set rngData = .Range("A1:A" & .Cells(.Rows.Count, "A").End(xlUp).Row)
        Set rngFormula = .Range("B1:C1")
        rngFormula.AutoFill _
            Destination:=.Range(rngFormula, _
            .Cells(rngData.Rows(rngData.Rows.Count).Row, rngFormula.Column))
    End With
    
End Sub
HTH
 
Upvote 0
Hi Richie!

I was trying a different approach on this, trying to base it solely off of the selected area...but it wouldn't work. It's getting the correct range that I have selected (verified by the commented-out msgbox line), but it won't work with the autofill.

Any ideas why? Can you not use 'selection' with Autofill and I'm not aware of it or something?

<font face=Tahoma><SPAN style="color:#00007F">Sub</SPAN> test()

<SPAN style="color:#00007F">Dim</SPAN> fillrange <SPAN style="color:#00007F">As</SPAN> Range

<SPAN style="color:#00007F">Set</SPAN> fillrange = Range(Selection.Cells(1, 1), _
    Selection.Cells(Selection.Cells.Count, 1))

<SPAN style="color:#007F00">'MsgBox fillrange.Address</SPAN>

Selection.AutoFill Destination:=fillrange

<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN></FONT>
 
Upvote 0
Richie, your method works great. However, I need to change it just a bit. I want to do the fill in column I and K based on the length of H. I modified your code to say:

Sub AutoFillIt()
Dim rngData As Range, rngFormula As Range

With ActiveSheet
Set rngData = .Range("H24:H" & .Cells(.Rows.Count, "H").End(xlUp).Row)
Set rngFormula = .Range("I24")
rngFormula.AutoFill _
Destination:=.Range(rngFormula, _
.Cells(rngData.Rows(rngData.Rows.Count).Row, rngFormula.Column))
End With

End Sub

Which fills I starting at 24 and goes until the end of H. How do I add K? I tried changing:

Set rngFormula = .Range("I24" & "K24") but it didn't like it. I'm so close, what more should I do? Thanks so much. :pray:

Eric
 
Upvote 0
Never mind, I think I figured it out. I just added this:

Set rngFormula = .Range("K24")
rngFormula.AutoFill _
Destination:=.Range(rngFormula, _
.Cells(rngData.Rows(rngData.Rows.Count).Row, rngFormula.Column))

I have it in there twice, once for I and once for K.

Thanks Again!!
 
Upvote 0
Hi Kristy,

How ya doin'? :)

Was this what you had in mind?

<font face=Courier New><SPAN style="color:#00007F">Sub</SPAN> test()
    <SPAN style="color:#00007F">Dim</SPAN> fillrange <SPAN style="color:#00007F">As</SPAN> Range
    
    <SPAN style="color:#00007F">Set</SPAN> fillrange = Range(Selection.Cells(1, 1), _
        Selection.Cells(Selection.Cells.Count, 1))
    
    Selection.Cells(1, 1).AutoFill Destination:=fillrange

<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN></FONT>

Hi Eric,

Glad you got it sorted.
 
Upvote 0
Ah, ok. So it's being tetchy. Apparently that's the one thing I *didn't* try. Thanks, Richie :)
 
Upvote 0
hey i tried the sam e thing but got stuck

Windows("Book1").Activate
Range("B12").Select
Selection.Copy
Windows("Book2.xls").Activate
ActiveSheet.paste
Set rngData = .Range("C6:C" & .Cells(.Rows.Count, "C").End(xlUp).Row)
Set rngFormula = .Range("B6")
rngFormula.AutoFill _
Destination:=.Range(rngFormula, _
.Cells(rngData.Rows(rngData.Rows.Count).Row, rngFormula.Column)):eek:
 
Upvote 0

Forum statistics

Threads
1,214,523
Messages
6,120,028
Members
448,940
Latest member
mdusw

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