VBA code for inserting multiple rows, copying and transposing data

Barry NP

New Member
Joined
Jul 18, 2017
Messages
24
Hi all,


I am hoping that the following is possible to be done with vba code. I have searched but am struggling to find code to cover all of this. I have broken this down into 3 separate stages below.


I have a set of data in an excel spreadsheet that runs from column A to Column K and 6000 rows. The columns will always be the same, but the rows can increase over time. A snapshot example of data below.


ABCDEFGHIJK
DavidJones10.020182019202020212022202320242025
SteveDavies10.020182019202020212022202320242025
BarryRoberts10.020182019202020212022202320242025
MarkNesling10.020182019202020212022202320242025
DereckRoberts10.020192019202020212022202320242025
AshelyRoberts10.020182019202020212022202320242025
ReeceRoberts10.020182019202020212022202320242025
TonyDavies10.020182019202020212022202320242025
MaryDavies10.020182019202020212022202320242025

<tbody>
</tbody>


What I am looking at achieving is this (probably with a separate macro for each part):


1) Firstly I need 7 rows inserted between each line so that for e.g. Row 1 will have David Jones, followed by 7 blank rows and on row 9 will be Steve Davies and so on to the last row of data (circa 6000 rows).



2) I then need the newly inserted 7 blank rows to be auto filled with the data of the row above for columns A to C only, so for e.g rows 2 to 8 will show David Jones 10.00 for columns A to C. Then row 9 will show Steve Davies 10.00 and I then need rows 9 to 16 to also show Steve Davies 10.00 and so on. I need this to be done for all data rows to the last row of data. Columns D to K do not need to be auto-filled with the years in the newly inserted blank rows.



3) The last part that I am hoping to achieve is to cut and transpose the years for each row in columns D to K and to paste down in column D.


This needs to be done to the last row of data.


So what I would expect to see is the e.g. below with no data in columns E to K and years in column D.



ABCDEFGHIJK
DavidJones10.02018
DavidJones10.02019
DavidJones10.02020
DavidJones10.02021
DavidJones10.02022
DavidJones10.02023
DavidJones10.02024
DavidJones10.02025
SteveDavies10.02018
SteveDavies10.02019
SteveDavies10.02020
SteveDavies10.02021
SteveDavies10.02022
SteveDavies10.02023
SteveDavies10.02024
SteveDavies10.02025

<tbody>
</tbody>



This is a work project, so any help on this would be very, very gratefully received. I am an intermediate user of VBA and this has so far stumped me.


Keeping my fingers crossed on this one, so if you can assist it would be a massive help to me.


If you need any further clarification, please let me know.


Many thanks,


Barry.
 
No probs. That would be great if you would be able to take a look. No rush now as it's the weekend so I won't be looking at this again until Monday. Many thanks for all you help with this. It is greatly appreciated. Barry.
 
Upvote 0

Excel Facts

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.
This will transfer all formatting from source to destination. However, be warned, it will take several minutes to run for the amount of data you have so you might want to make a cup of tea while it runs. :)
Code:
Sub Rearrange_v2()
  Dim i As Long, nr As Long
  
  nr = 2
  Application.ScreenUpdating = False
  For i = 2 To Range("A" & Rows.Count).End(xlUp).Row
    Cells(i, 1).Resize(, 3).Copy Destination:=Cells(nr, "N").Resize(8)
    Cells(i, 4).Resize(, 8).Copy
    Cells(nr, "Q").PasteSpecial Paste:=xlPasteAll, Transpose:=True
    nr = nr + 8
  Next i
  Application.ScreenUpdating = True
  MsgBox "Done"
End Sub



This will run much faster (about 1 second for me), but only looks for, and transfers, red font in the 'Year' columns to the 4th column of the results.
Code:
Sub Rearrange_v3()
  Dim a As Variant, b As Variant
  Dim i As Long, j As Long, k As Long
  
  With Range("A2", Range("K" & Rows.Count).End(xlUp))
    a = .Value
    ReDim b(1 To 8 * UBound(a), 1 To 4)
    For i = 1 To UBound(a)
      For j = 4 To 11
        k = k + 1
        b(k, 1) = a(i, 1): b(k, 2) = a(i, 2): b(k, 3) = a(i, 3): b(k, 4) = a(i, j)
        If .Cells(i, j).Font.Color = vbRed Then b(k, 4) = b(k, 4) & "#"
      Next j
    Next i
  End With
  Application.ScreenUpdating = False
  Range("N2").Resize(UBound(b), 4).Value = b
  With Columns("Q")
    On Error Resume Next
    .SpecialCells(xlConstants, xlTextValues).Font.Color = vbRed
    On Error GoTo 0
    .Replace What:="#", Replacement:="", LookAt:=xlPart
  End With
  Application.ScreenUpdating = True
End Sub
 
Upvote 0
That's fantastic. I will use this today and will let you know if all ok. Many thanks for this. Thus is that last part that is required. I will use the latter code hoping it will run quickly. I will confirm back to you once I have given it a go.
 
Upvote 0
That's fantastic. I will use this today and will let you know if all ok. Many thanks for this. Thus is that last part that is required. I will use the latter code hoping it will run quickly. I will confirm back to you once I have given it a go.
You're welcome. Look forward to hearing how it goes for you.
 
Upvote 0
Hi Peter. Just to let you know the code worked like a dream. I used the second code which only took a few seconds longer to run and it did show the data in red font as required. Many thanks for this. It's been a great help. Barry.
 
Upvote 0
Hi Peter. Just to let you know the code worked like a dream. I used the second code which only took a few seconds longer to run and it did show the data in red font as required. Many thanks for this. It's been a great help. Barry.
Cheers. Thanks for the confirmation. Glad it worked as required. :)
 
Upvote 0

Forum statistics

Threads
1,215,374
Messages
6,124,566
Members
449,171
Latest member
jominadeo

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