Reducing a Selection by one cell.

teachman

Active Member
Joined
Aug 31, 2011
Messages
321
Hello,

Today is just one of those days that Excel just keeps beating my butt. After an hour of trying to write a simple three line code and getting nowhere I have come to the experts.

The background is that I have a string in cell A10, ten blank cells (going down the column), and then a string in cell A21.

What I'm trying to do is Select A10 and all the blank cells in A2:A20. Do a fill down (Cntl-D) then moving to the next cell down.

I can do this using Record Macro by.

Cell A10 is the active cell
Range(Selection, Selection.End(xlDown).Select
With A10 still the active cell I hold down the Shft Key and press the End key then press the DownArrow key.
This selects all the cells from A10 to A20. This includes A20 - which has a value already in it.
Since I only want cells A10 through A19 selected I continue holding down Shft Key and then press the UpArrow key once.
This leaves A10 through A19 selected.
Now to copy the value in A10 down through A19 I press the Ctrl and DownArrow keys.
This results in all cells between A10 and through A19 have the same value.

All of the above steps are done in the Macro Recorder, resulting in the VBA code of:

Range(Selection, Selection.End(xlDown)).Select
Range("A10:A19").Select
Application.CutCopyMode = False
Selection.FillDown

Since I want to do this process multiple times in the spreadsheet with different cell addresses, this code doesn't work because the UpArrow key is translated into an actual cell address.

I've tried replacing the second line with ActiveCell.Offset(-1,0) to move up one cell. Well, it does move up one cell, but to one cell above A10, i.e. A9 and turns the selection process.

Any help is most welcome.

Thanks

George Teachman
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Do you want to fill all blank cells in col A with the previous value?
 
Upvote 0
Try this

Change B to the column that contains more rows with data
Code:
Sub Macro3()
    With Range("A10:A" & Range("[B]B[/B]" & Rows.Count).End(xlUp).Row)
      .SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=R[-1]C"
      .Value = .Value
  End With
End Sub
 
Last edited:
Upvote 0
If the answer is yes try
Code:
Sub teachman()
   With Range("A10", Range("B" & Rows.Count).End(xlUp).Offset(, -1))
      .SpecialCells(xlBlanks).FormulaR1C1 = "=r[-1]c"
      .Value = .Value
   End With
End Sub
This will "fill down" to the end of column B
 
Upvote 0
Does this macro do what you want...
Code:
Sub FillBlanksFromAbove()
  Dim LastRow As Long
  LastRow = Cells.Find("*", , xlValues, , xlRows, xlPrevious).Row
  Application.ScreenUpdating = False
  On Error GoTo NoBlanks
  With Range("A10:A" & LastRow)
    .SpecialCells(xlBlanks).FormulaR1C1 = "=R[-1]C"
    .Value = .Value
  End With
NoBlanks:
  Application.ScreenUpdating = True
End Sub
 
Upvote 0
Cell A10's value should be entered into cells A11 to A19.
Cell A30's value should be entered into cells A31 to A45.
Cell A76's value should be entered into cells A77 to A99.
etc.

Thanks,

George Teachman
 
Upvote 0
Are there any blank cells between A20 & A30 etc?
If so how do you determine which blanks should be filled?
 
Upvote 0
DanteAmor,

Wow, that went through all records (> 28,000) so fast, I thought it hadn't worked. But it did.

Mr Rothstein's suggestion also worked.
Fluff's suggestion also worked.

All were very fast and used slightly different approaches which just reinforces my belief that there is always more than 1 way to get the same result.

Thank you all for your time and effort. I will be studying each suggestion.

I've said it before, but I'll say it again. This is the best forum I've ever been involved in. You all are very patient and I've always gotten help/answers with any questions I've asked.

Thanks,

George Teachman

All the other suggestions worked as well.
 
Upvote 0
Glad we could help & thanks for the feedback
 
Upvote 0
DanteAmor,

Wow, that went through all records (> 28,000) so fast, I thought it hadn't worked. But it did.


Thanks,

George Teachman

All the other suggestions worked as well.


I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,406
Messages
6,119,330
Members
448,888
Latest member
Arle8907

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