Reducing a Selection by one cell.

teachman

Active Member
Joined
Aug 31, 2011
Messages
303
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
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
30,569
Office Version
365
Platform
Windows
Do you want to fill all blank cells in col A with the previous value?
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
7,977
Office Version
2007
Platform
Windows
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:

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
30,569
Office Version
365
Platform
Windows
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
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
35,442
Office Version
2010
Platform
Windows
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
 

teachman

Active Member
Joined
Aug 31, 2011
Messages
303
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
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
30,569
Office Version
365
Platform
Windows
Are there any blank cells between A20 & A30 etc?
If so how do you determine which blanks should be filled?
 

teachman

Active Member
Joined
Aug 31, 2011
Messages
303
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.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
30,569
Office Version
365
Platform
Windows
Glad we could help & thanks for the feedback
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
7,977
Office Version
2007
Platform
Windows
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.
 

Forum statistics

Threads
1,078,520
Messages
5,340,931
Members
399,399
Latest member
SravanaSandhya

Some videos you may like

This Week's Hot Topics

  • Problem with Radio Button's format control
    I am creating an employee evaluation template (a sample is below) Column A is the category Column B, C D, E and F will be ratings (unacceptable...
  • Last Display on userform to a Listbox
    [CODE=vba] lstdisplay.ColumnCount = 15 lstdisplay.RowSource = "A1:O600000" [/CODE] So when i do this it Displays everything on the sheet i am...
  • Rename and move files to a new location
    Dear all, I have an excel file with the following information. The actual file name is at column A but i want to rename it using the following...
  • Help with True/False Formula
    Hello! Am stumped how to fix this formula, in which my result returns 'True', but it should return False. =IF(AG2=True...
  • Clear extra characters from a provided range of cells
    Dear All, I have following code which gives me desired output to remove extra characters from a provided range. But it takes too much time when...
  • Help with Current and highest streaks
    Hi there, I've just joined the forum and this is my first post. I've already spent quite a bit of time searching the net and this forum for a...
Top