Can you dynamically copy rows and paste them into new rows without blanks?

c.clavin

Board Regular
Joined
Mar 22, 2011
Messages
123
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
Hi guys, I'm trying to do the below, basically working from column A, and I want to output it to column B without the spaces in the rows. Is this possible? Thanks.

ApplesApples
OrangesOranges
PearsPears
Strawberries
StrawberriesCherries
Cherries
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Hi c.clavin,

Try this:

VBA Code:
Option Explicit
Sub Macro1()

    Dim ws As Worksheet
    Dim i As Long, j As Long
    
    Application.ScreenUpdating = False
    
    Set ws = ThisWorkbook.Sheets("Sheet1") '<-Sheet name containing data. Change to suit if necessary.
    j = 2
    
    For i = 2 To ws.Cells(Rows.Count, "A").End(xlUp).Row
        If Len(ws.Range("A" & i)) > 0 Then
            ws.Range("B" & j) = ws.Range("A" & i)
            j = j + 1
        End If
    Next i
    
    Application.ScreenUpdating = True

End Sub

Regards,

Robert
 
Upvote 0
You could also use a formula
+Fluff 1.xlsm
AB
1ApplesApples
2OrangesOranges
3PearsPears
4Strawberries
5StrawberriesCherries
6
7Cherries
8
Data
Cell Formulas
RangeFormula
B1:B5B1=FILTER(A1:A100,A1:A100<>"")
Dynamic array formulas.
 
Upvote 0
Thanks very much. Is there a way to make the formula reference non-consecutive rows? Like A1:A5 and A7 without breaking the formula?
 
Upvote 0
How about
Excel Formula:
=FILTER(INDEX((A1:A5,A7:A8),),INDEX((A1:A5,A7:A8),)<>"")
 
Upvote 0
Here's a more efficient macro than my earlier one should you opt for a code solution:

VBA Code:
Option Explicit
Sub Macro2()

    Dim ws As Worksheet
    Dim i As Long
    
    Application.ScreenUpdating = False
    
    Set ws = ThisWorkbook.Sheets("Sheet1") '<-Sheet name containing data. Change to suit if necessary.
    
    i = ws.Cells(Rows.Count, "A").End(xlUp).Row
    ws.Range("A1:A" & i).AutoFilter Field:=1, Criteria1:="<>"
    ws.Range("A1:A" & i).SpecialCells(xlCellTypeVisible).Copy Destination:=ws.Range("B1")
    If ws.AutoFilterMode Then ws.AutoFilterMode = False
    
    Application.ScreenUpdating = True

End Sub
 
Upvote 0
How about
Excel Formula:
=FILTER(INDEX((A1:A5,A7:A8),),INDEX((A1:A5,A7:A8),)<>"")
The formula doesnt seem to be working on from my linked sheet. It's dropping off the entries in the last 2 referenced cells. Any idea why? Tried it on cells on the same sheet, the formula doesnt seem to be working

=FILTER(INDEX(('Fruits'!H16:H26,'Fruits'!H28:H29),),INDEX(('Fruits'!H16:H26,'Fruits'!H28:H29),)<>"")
 
Upvote 0
You're right it doesn't work.
The easiest option is to filter-out whatever is in H27
Like
Excel Formula:
=FILTER(Fruits!H16:H29,(Fruits!H16:H29<>"")*(Fruits!H16:H29<>Fruits!H27))
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,256
Members
448,557
Latest member
richa mishra

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