Consulting

Results 1 to 10 of 10

Thread: Blank Cells and Filling Down R[-1]C

  1. #1
    VBAX Regular
    Joined
    Feb 2009
    Posts
    29
    Location

    Blank Cells and Filling Down R[-1]C

    Hi, I have an example workbook that demonstrates what my issue is. I need to fill the names in Col A down for the blank cells underneath each 'Vendor' so that I may go back and perform a lookup/index/match later on the data next to it (the names in red show what I need). I attempted to use the following code, but received an error stating the "Object doesn't support this property or method". Any ideas?

    With Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row)
        .xlCellTypeBlanks.FormulaR1C1 = "=R[-1]C"
        .Value = .Value
    End With
    Thanks for your help!
    Last edited by Aussiebear; 04-24-2023 at 04:58 AM. Reason: Adjusted the code tags

  2. #2
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Try this array formula

    PHP Code:
    =IF(C2="",SUM(D3:INDEX(D320,MIN(IF(B3:B20<>"",ROW(B3:B20)-MIN(ROW(B3:B20))+1)))),""
    Last edited by Aussiebear; 04-24-2023 at 04:58 AM. Reason: Added code tags
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  3. #3
    VBAX Regular
    Joined
    Aug 2005
    Posts
    42
    Location
    Your attached doesn't show any names in red, so I assume that you want
    to fill in the blanks from the value above in Col A.

    You don't need a macro or formula to do this

    1) Select the range, A2 to A20 in your example
    2) Press Ctrl+G
    3) Click Special in the Go To box
    4) Select Blanks option
    5) Click Ok
    6) In the formula bar, type =A2
    7) Press Ctrl + Enter
    8) Reselect the range and Edit >> Copy
    9) Edit >> Paste Special >> Value >> OK

    HTH
    Our Greatest Glory is not in never falling, but in rising every time we fall

    There is great satisfaction in building good tools for others to use

  4. #4
    Mac Moderator VBAX Guru mikerickson's Avatar
    Joined
    May 2007
    Location
    Davis CA
    Posts
    2,778
    With Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row)
        On Error Resume Next
        .SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        On Error Goto 0
        .Value = .Value 
    End With
    Last edited by Aussiebear; 04-24-2023 at 04:59 AM. Reason: Adjusted the code tags

  5. #5
    VBAX Regular
    Joined
    Nov 2008
    Location
    Cedar Creek, Texas
    Posts
    95
    Location
    Hi All,

    I just found this site and this code that Mikeerickson posted does what I wish on a spreadsheet.

    With Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row) 
            On Error Resume Next 
        .SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C" 
            On Error Goto 0 
        .Value = .Value 
    End With
    I wish to go a step further and looking for assistance.

    The cells that were blank that were filled in from the cell above, "How do I color and Bold the filled in cells only"?
    So, when I look at the column that was filled in where the blanks were, I can check to make sure everyting is in order!

    Thanks

    James Niven
    Last edited by Aussiebear; 04-24-2023 at 05:00 AM. Reason: Adjusted the code tags

  6. #6
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    With Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row)
        On Error Resume Next
        .SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
        On Error GoTo 0
        .Value = .Value
        .Font.Bold = True
        .Interior.ColorIndex = 38
    End With
    Last edited by Aussiebear; 04-24-2023 at 05:00 AM. Reason: Adjusted the code tags
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  7. #7
    VBAX Regular
    Joined
    Nov 2008
    Location
    Cedar Creek, Texas
    Posts
    95
    Location
    XLD,

    Thanks for you reply, to tell you the truth, I was close myself to what you had in the code below, I kept getting "Object Required" error, I forgot the = true part of the code.

    With Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row) 
            On Error Resume Next 
        .SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C" 
            On Error Goto 0 
        .Value = .Value 
        .Font.Bold = True 
        .Interior.ColorIndex = 38 
    End With
    Ok, what you have done is highlight the columns which were filled in and made them bold, wonderful, this will work for me!!

    Thanks for your input, I am learning this new language, always willing to learn!!
    I see you're also in Texas, what town?

    Thanks

    James Niven
    Cedar Creek.
    Last edited by Aussiebear; 04-24-2023 at 05:02 AM. Reason: Adjusted the code tags

  8. #8
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Quote Originally Posted by James Niven
    I see you're also in Texas, what town?
    Check that flag again.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  9. #9
    VBAX Regular
    Joined
    Nov 2008
    Location
    Cedar Creek, Texas
    Posts
    95
    Location
    Thanks XLD, wow you're right, very close to the Texas state flag, Chile OK.

    I need to adjust my glasses.


    Thanks

  10. #10
    I'll be damned. I thought that was Texas also.

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •