filling in columns with cells above

keeper85

New Member
Joined
Jun 10, 2011
Messages
15
I have the following code that fills in the empty cells with the value of the cells above. This is done for columns B,L,C and G and the reference column used for the length of the range is column F. The code works fine as long as I have the book "Posbook" and the "PosSheet" open, however, it does not work if I view any other sheet. Can someone explain me why this is the case? I suspect that it has something to do with the Offset property. Can someone modify me this code so that PosBook does not always have to be the active sheet in order to work? Thanks!

HTML:
On Error Resume Next
    With Workbooks(PosBook).Worksheets(PosSheet)
        .Range("f5", Range("f" & Rows.Count).End(xlUp)).Offset(, -4).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        .Range("b5:b" & [f65536].End(xlUp).Row).Copy
        .Range("B5").PasteSpecial (xlPasteAll)
        Application.CutCopyMode = False
        .Range("f5", Range("f" & Rows.Count).End(xlUp)).Offset(, 6).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        .Range("l5:l" & [f65536].End(xlUp).Row).Copy
        .Range("L5").PasteSpecial (xlPasteAll)
        Application.CutCopyMode = False
        .Range("f5", Range("f" & Rows.Count).End(xlUp)).Offset(, -3).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        .Range("c5:c" & [f65536].End(xlUp).Row).Copy
        .Range("c5").PasteSpecial (xlPasteAll)
        Application.CutCopyMode = False
        .Range("f5", Range("f" & Rows.Count).End(xlUp)).Offset(, 1).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        .Range("g5:g" & [f65536].End(xlUp).Row).Copy
        .Range("g5").PasteSpecial (xlPasteAll)
        Application.CutCopyMode = False
    End With
 

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
I would say your "Rows.Count" references need to have the Worksheet name included.
If you are on a worksheet other than the one you want to copy/paste, then you need the worksheet name to be included or referenced.
 
Upvote 0
Thanks for your input, John, however, it does not solve the problem. Do you have any other suggestions?
 
Upvote 0
I finally figured it out. Actually you were almost correct (and on the right path. Here is the corrected code:
HTML:
On Error Resume Next
    With Workbooks(PosBook).Worksheets(PosSheet)
        .Range("f5", .Range("f" & .Rows.Count).End(xlUp)).Offset(, -4).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        .Range("b5:b" & [f65536].End(xlUp).Row).Copy
        .Range("B5").PasteSpecial (xlPasteAll)
        Application.CutCopyMode = False
        .Range("f5", .Range("f" & .Rows.Count).End(xlUp)).Offset(, 6).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        .Range("l5:l" & [f65536].End(xlUp).Row).Copy
        .Range("L5").PasteSpecial (xlPasteAll)
        Application.CutCopyMode = False
        .Range("f5", .Range("f" & .Rows.Count).End(xlUp)).Offset(, -3).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        .Range("c5:c" & [f65536].End(xlUp).Row).Copy
        .Range("c5").PasteSpecial (xlPasteAll)
        Application.CutCopyMode = False
        .Range("f5", .Range("f" & .Rows.Count).End(xlUp)).Offset(, 1).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        .Range("g5:g" & [f65536].End(xlUp).Row).Copy
        .Range("g5").PasteSpecial (xlPasteAll)
        Application.CutCopyMode = False
    End With
 
Upvote 0

Forum statistics

Threads
1,224,513
Messages
6,179,214
Members
452,895
Latest member
BILLING GUY

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