VBA - loop thru column, find 2 consecutive empty rows, combine data in row below thru n rows before next 2 consecutive empty rows

gratefuljames

New Member
Joined
Nov 2, 2020
Messages
4
Office Version
  1. 365
Platform
  1. Windows
Greetings,

I would like to get help to create a loop in VBA that will do the following in Excel Office 365:

- loop down entire column and find 2 consecutive empty rows in column A
- combine data from last empty row +2 rows down thru last row with data before the next 2 consecutive empty rows, including any empty row, in the same layout
- paste the combined data into column B, on the row where the 1st row with data appears for each block between consecutive empty rows
- delete empty rows in column B

Below is a sample data:
excel 1.jpg


Below is what it should look like after combining the data and pasting
excel 2.jpg


Below is after deletion of empty rows in column B
excel 3.jpg



I appreciate any help.

Thanks,
James
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
How about
VBA Code:
Sub gratefuljames()
   Dim i As Long
   Dim Ar As Areas
   Dim Rng As Range
   
   Set Ar = Range("A:A").SpecialCells(xlBlanks).Areas
   For i = 1 To Ar.Count
      If Ar(i).Count = 2 Then
         If Rng Is Nothing Then
            Set Rng = Ar(i).Offset(3)(1)
         Else
            Rng.Offset(-1, 1).Value = Join(Application.Transpose(Range(Rng, Ar(i).Offset(-1)(1))), vbLf)
            Set Rng = Ar(i).Offset(3)(1)
         End If
      End If
   Next i
   Rng.Offset(-1, 1).Value = Join(Application.Transpose(Range(Rng, Range("A" & Rows.Count).End(xlUp))), vbLf)
   Range(Range("B1").End(xlDown), Range("B" & Rows.Count)).SpecialCells(xlBlanks).EntireRow.Delete
End Sub
 
Upvote 0
Solution
Hi Fluff, your solution works perfectly for my requirement. Thank you for the quick response.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0
hi Fluff,

I have a data set in which the consecutive empty rows vary from 2 to 3 rows. Is there a way to account for this?

Thanks,
James
 
Upvote 0
How about
VBA Code:
Sub gratefuljames()
   Dim i As Long
   Dim Ar As Areas
   Dim Rng As Range
   
   Set Ar = Range("A:A").SpecialCells(xlBlanks).Areas
   For i = 1 To Ar.Count
      If Ar(i).Count >= 2 Then
         If Rng Is Nothing Then
            Set Rng = Ar(i).Offset(Ar(i).Count + 1)(1)
         Else
            Rng.Offset(-1, 1).Value = Join(Application.Transpose(Range(Rng, Ar(i).Offset(-1)(1))), vbLf)
            Set Rng = Ar(i).Offset(Ar(i).Count + 1)(1)
         End If
      End If
   Next i
   Rng.Offset(-1, 1).Value = Join(Application.Transpose(Range(Rng, Range("A" & Rows.Count).End(xlUp))), vbLf)
   Range(Range("B1").End(xlDown), Range("B" & Rows.Count)).SpecialCells(xlBlanks).EntireRow.Delete
End Sub
 
Upvote 0
Hi Fluff,

It works as expected. Thank you for taking the time to make the updates.

James
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,485
Messages
6,113,931
Members
448,533
Latest member
thietbibeboiwasaco

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