VBA Range Offset error

drluke

Active Member
Joined
Apr 17, 2014
Messages
312
Office Version
  1. 365
Platform
  1. Windows
I want to fill every blank cell in my range with data from the cell above, including one row below the last row. I thought that I could achieve this with range offset but I get "Object required" error.
VBA Code:
Sub fillBlanks()

    Dim lrow As Long
    Dim ws As Worksheet
    Dim rng As Range
    
    Set ws = ThisWorkbook.Worksheets("Journal")
    
    lrow = ws.Range("A" & Rows.Count).End(xlUp).Row
    
    Set rng = ws.Range("A2:A" & lrow)
    
        With rng.Offset(1, 0)
            On Error Resume Next
            Set myRange = .SpecialCells(xlCellTypeBlanks)
            On Error GoTo 0
            If Not myRange Is Nothing Then
            myRange.FormulaR1C1 = "=R[-1]C"
            .Value = .Value
            End If
            End With
            
End Sub

Any advice?
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
MAybe this way...
VBA Code:
Sub fillBlanks()
    Dim myrange As Range
    With Range("A2:A" & Range("A" & Rows.Count).End(xlUp).Row)
            On Error Resume Next
            Set myrange = .SpecialCells(xlCellTypeBlanks)
            myrange.FormulaR1C1 = "=R[-1]C"
            .Value = .Value
           End With
End Sub
 
Upvote 0
MAybe this way...
VBA Code:
Sub fillBlanks()
    Dim myrange As Range
    With Range("A2:A" & Range("A" & Rows.Count).End(xlUp).Row)
            On Error Resume Next
            Set myrange = .SpecialCells(xlCellTypeBlanks)
            myrange.FormulaR1C1 = "=R[-1]C"
            .Value = .Value
           End With
End Sub
Thanks for this Michael. The row below the last row still remains empty. It should be filled with the values in the last row.
 
Upvote 0
Rich (BB code):
Sub fillBlanks()
    Dim myrange As Range
    With Range("A2:A" & Range("A" & Rows.Count).End(xlUp).Row)+1
            On Error Resume Next
            Set myrange = .SpecialCells(xlCellTypeBlanks)
            myrange.FormulaR1C1 = "=R[-1]C"
            .Value = .Value
           End With
End Sub
 
Upvote 0
Solution
Rich (BB code):
Sub fillBlanks()
    Dim myrange As Range
    With Range("A2:A" & Range("A" & Rows.Count).End(xlUp).Row)+1
            On Error Resume Next
            Set myrange = .SpecialCells(xlCellTypeBlanks)
            myrange.FormulaR1C1 = "=R[-1]C"
            .Value = .Value
           End With
End Sub
Amazing! Thank you.
 
Upvote 0
Amazing! Thank you.
I don't think either of you actually tested that code. ;)
It should be
Rich (BB code):
With Range("A2:A" & Range("A" & Rows.Count).End(xlUp).Row + 1)

You should also note that it will not guarantee to fill the row below the bottom row with anything. If the bottom row of column A happens to be the bottom row of the sheet's used "UsedRange" then nothing will go into that next row. To be sure, you would need something like this.

VBA Code:
Sub Fill_Blanks()
  With Range("A2", Range("A" & Rows.Count).End(xlUp))
    On Error Resume Next
    .SpecialCells(xlBlanks).FormulaR1C1 = "=R[-1]C"
    On Error GoTo 0
    .Value = .Value
    .Cells(.Count + 1).Value = .Cells(.Count).Value
  End With
End Sub
 
Upvote 0
I don't think either of you actually tested that code. ;)
It should be
Rich (BB code):
With Range("A2:A" & Range("A" & Rows.Count).End(xlUp).Row + 1)

You should also note that it will not guarantee to fill the row below the bottom row with anything. If the bottom row of column A happens to be the bottom row of the sheet's used "UsedRange" then nothing will go into that next row. To be sure, you would need something like this.

VBA Code:
Sub Fill_Blanks()
  With Range("A2", Range("A" & Rows.Count).End(xlUp))
    On Error Resume Next
    .SpecialCells(xlBlanks).FormulaR1C1 = "=R[-1]C"
    On Error GoTo 0
    .Value = .Value
    .Cells(.Count + 1).Value = .Cells(.Count).Value
  End With
End Sub
Thank you Peter
 
Upvote 0

Forum statistics

Threads
1,213,552
Messages
6,114,278
Members
448,560
Latest member
Torchwood72

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