VBA: Copy data range and paste every nth row and fill in the blanks

tommiexboi

New Member
Joined
Apr 24, 2017
Messages
24
Office Version
  1. 365
Platform
  1. Windows
Hello,

Need help! I tried searching google and the forums, but for the life of me I can't seem to find what I'm trying to look for.

I have a list of data in sheet1 and I'm trying to copy/paste each line into sheet2 on every 3rd row and then fill down the blanks. The list of data changes daily so I need it to loop until it reaches the end.
I created an example below.

I want to create a macro that can do this, your help will be greatly appreciated!!

Thanks,


EXAMPLE

Current (Sheet1)
CustomerItemType
PineappleCupBeverage
BananaBowlMeal
StrawberryPlateMeal
MangoSpoonMeal

<tbody>
</tbody>

Need (Sheet2)
CustomerItemType
PineappleCupBeverage
PineappleCupBeverage
PineappleCupBeverage
BananaBowlMeal
BananaBowlMeal
BananaBowlMeal
StrawberryPlateMeal
StrawberryPlateMeal
StrawberryPlateMeal
MangoSpoonMeal
MangoSpoonMeal
MangoSpoonMeal

<tbody>
</tbody>
 
Last edited:

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
This assumes your sheet tab names are Sheet1 and Sheet2 and that sheet2 already has the headers in place. Header "Customer" is assumed to be in cell A1 on both sheets.
Code:
Sub tommiexboy()
Dim R As Range, Rw As Range, lR As Long
Application.ScreenUpdating = False
Set R = Sheets("Sheet1").Range("A2:C" & Sheets("Sheet1").Cells(Rows.Count, "A").End(xlUp).Row)
Sheets("Sheet2").Range("A2:C" & Sheets("Sheet2").Cells(Rows.Count, "A").End(xlUp).Row + 1).ClearContents
For Each Rw In R.Rows
    Rw.Copy Sheets("Sheet2").Range("A" & Sheets("Sheet2").Cells(Rows.Count, "A").End(xlUp).Row + 1).Resize(3, 3)
Next Rw
Application.ScreenUpdating = True
End Sub
 
Upvote 0
Here is another macro (no loops) for you to consider...
Code:
[table="width: 500"]
[tr]
	[td]Sub tommiexboi()
  Dim Data As Variant
  Data = Split(Join(Application.Transpose(Evaluate(Replace("Sheet1!A2:A#&""|""&Sheet1!B2:B#&""|""&Sheet1!C2:C#", "#", Sheets("Sheet1").Cells(Rows.Count, "A").End(xlUp).Row))), "***"), "*")
  With Sheets("Sheet2")
    .Columns("A:C").Clear
    .Range("A1:C1").Value = Array("Customer", "Item", "Type")
    .Range("A2").Resize(UBound(Data) + 1) = Application.Transpose(Data)
    With .Range("A2:A" & UBound(Data) + 4)
      .SpecialCells(xlBlanks).FormulaR1C1 = "=R[-1]C"
      .Value = .Value
    End With
    .Columns("A").TextToColumns , xlDelimited, , , False, False, False, False, True, "|"
  End With
End Sub[/td]
[/tr]
[/table]
 
Upvote 0
Thank you JoeMo! This worked flawlessly! Had to tweak it just a little bit to suit my data, however; it worked completely fine!

Thank you Rick! This also worked well!

I owe you guys a beer! Cheers!
 
Upvote 0

Forum statistics

Threads
1,215,343
Messages
6,124,400
Members
449,156
Latest member
LSchleppi

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