Insert blank rows based on a number, then copy/paste values

BigBee11

New Member
Joined
Mar 28, 2018
Messages
3
Hello Excel Pros,

I've somewhat unique excel problem and it's taking a lot of my time because I do it pretty much manually. I'm asking all the pros to help me figure out a quicker way to get this done. Below is how I get data in excel sheet:

company1Baton Rouge, LouisianaNew Orleans, LouisianaShreveport, LouisianaLake Charles, Louisiana
company2Chicago, ILDurham, NC
company3Miami, FloridaTampa, FloridaFort Lauderdale, FloridaOrlando, FloridaJacksonville, FloridaKingston, JamaicaNassau, The Bahamas

<colgroup><col style="mso-width-source:userset;mso-width-alt:9472;width:194pt" width="259"> <col style="width:48pt" span="36" width="64"> </colgroup><tbody>
[TD="width: 259"]company[/TD]
[TD="width: 64"] #of fices[/TD]
[TD="width: 64"]city1[/TD]
[TD="width: 64"]city2[/TD]
[TD="width: 64"]city3[/TD]
[TD="width: 64"]city4[/TD]
[TD="width: 64"]city5[/TD]
[TD="width: 64"]city6[/TD]
[TD="width: 64"]city7[/TD]
[TD="width: 64"]city1-PR[/TD]
[TD="width: 64"]city1-NP[/TD]
[TD="width: 64"]city1-AS[/TD]
[TD="width: 64"]city1-OL[/TD]
[TD="width: 64"]city2-PR[/TD]
[TD="width: 64"]city2-NP[/TD]
[TD="width: 64"]city2-AS[/TD]
[TD="width: 64"]city2-OL[/TD]
[TD="width: 64"]city3-PR[/TD]
[TD="width: 64"]city3-NP[/TD]
[TD="width: 64"]city3-AS[/TD]
[TD="width: 64"]city3-OL[/TD]
[TD="width: 64"]city4-PR[/TD]
[TD="width: 64"]city4-NP[/TD]
[TD="width: 64"]city4-AS[/TD]
[TD="width: 64"]city4-OL[/TD]
[TD="width: 64"]city5-PR[/TD]
[TD="width: 64"]city5-NP[/TD]
[TD="width: 64"]city5-AS[/TD]
[TD="width: 64"]city5-OL[/TD]
[TD="width: 64"]city6-PR[/TD]
[TD="width: 64"]city6-NP[/TD]
[TD="width: 64"]city6-AS[/TD]
[TD="width: 64"]city6-OL[/TD]
[TD="width: 64"]city7-PR[/TD]
[TD="width: 64"]city7-NP[/TD]
[TD="width: 64"]city7-AS[/TD]
[TD="width: 64"]city7-OL[/TD]

[TD="align: right"]5[/TD]

[TD="colspan: 3"]South Baton Rouge, Louisiana [/TD]
[TD="align: right"]62[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]36[/TD]
[TD="align: right"]9[/TD]
[TD="align: right"]17[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]15[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]6[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]

[TD="align: right"]3[/TD]

[TD="colspan: 2"]Mountain View, CA[/TD]

[TD="align: right"]39[/TD]
[TD="align: right"]21[/TD]
[TD="align: right"]21[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]

[TD="align: right"]7[/TD]

[TD="align: right"]2[/TD]
[TD="align: right"]13[/TD]
[TD="align: right"]10[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]4[/TD]
[TD="align: right"]5[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]

</tbody>


And how the final output would look:

[TABLE="width: 769"]
<colgroup><col><col><col><col><col><col></colgroup><tbody>[TR]
[TD]Company[/TD]
[TD]CITY[/TD]
[TD]PR[/TD]
[TD]NP[/TD]
[TD]AS[/TD]
[TD]OL[/TD]
[/TR]
[TR]
[TD]company1[/TD]
[TD]Baton Rouge, Louisiana[/TD]
[TD="align: right"]62[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]36[/TD]
[TD="align: right"]9[/TD]
[/TR]
[TR]
[TD]company1[/TD]
[TD]New Orleans, Louisiana[/TD]
[TD="align: right"]17[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]15[/TD]
[TD="align: right"]2[/TD]
[/TR]
[TR]
[TD]company1[/TD]
[TD]Shreveport, Louisiana[/TD]
[TD="align: right"]6[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]company1[/TD]
[TD]Lake Charles, Louisiana[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]company1[/TD]
[TD]South Baton Rouge, Louisiana [/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]company2[/TD]
[TD]Chicago, IL[/TD]
[TD="align: right"]39[/TD]
[TD="align: right"]21[/TD]
[TD="align: right"]21[/TD]
[TD="align: right"]2[/TD]
[/TR]
[TR]
[TD]company2[/TD]
[TD]Durham, NC[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]company2[/TD]
[TD]Mountain View, CA[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]company3[/TD]
[TD]Miami, Florida[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]13[/TD]
[TD="align: right"]10[/TD]
[TD="align: right"]2[/TD]
[/TR]
[TR]
[TD]company3[/TD]
[TD]Tampa, Florida[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]4[/TD]
[TD="align: right"]5[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]company3[/TD]
[TD]Fort Lauderdale, Florida[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]company3[/TD]
[TD]Orlando, Florida[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]company3[/TD]
[TD]Jacksonville, Florida[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]company3[/TD]
[TD]Kingston, Jamaica[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[/TR]
[TR]
[TD]company3[/TD]
[TD]Nassau, The Bahamas[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[/TR]
</tbody>[/TABLE]

I need to insert blank rows based on #of offices and copy/paste each city data per row. what would be the best/easiest way to do this? Thanks in advance for your help!
 

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).
Hi & welcome to MrExcel.

How about this, it will put the data on a new sheet.
Code:
Sub RearrangeData()

   Dim i As Long, j As Long, k As Long
   Dim Rws As Long
   Dim NxtRw As Long
   Dim Ws As Worksheet
   
   Set Ws = Sheets("[COLOR=#ff0000]Output[/COLOR]")
   Ws.Range("A1:F1").Value = Array("Company", "CITY", "PR", "NP", "AS", "OL")
   With Sheets("[COLOR=#ff0000]Sheet1[/COLOR]")
      For i = 2 To .Range("A" & Rows.Count).End(xlUp).Row
         Rws = .Range("B" & i).Value
         NxtRw = Ws.Range("A" & Rows.Count).End(xlUp).Offset(1).Row
         Ws.Range("A" & NxtRw).Resize(1 * Rws).Value = .Range("A" & i).Value
         Ws.Range("B" & NxtRw).Resize(Rws).Value = Application.Transpose(.Range("C" & i).Resize(, Rws))
         k = 10
         For j = 1 To Rws
            Ws.Range("C" & Rows.Count).End(xlUp).Offset(1).Resize(, 4).Value = .Cells(i, k).Resize(, 4).Value
            k = k + 4
         Next j
      Next i
   End With
End Sub
Change sheet names in red to suit
 
Upvote 0
Thank you very much. I have data in more than 300 rows and 400 columns with many blanks cells. When I tried this, I didn't correctly copies and pasted the values. How can I modify this to work for large number of rows and columns. Thanks!

Hi & welcome to MrExcel.

How about this, it will put the data on a new sheet.
Code:
Sub RearrangeData()

   Dim i As Long, j As Long, k As Long
   Dim Rws As Long
   Dim NxtRw As Long
   Dim Ws As Worksheet
   
   Set Ws = Sheets("[COLOR=#ff0000]Output[/COLOR]")
   Ws.Range("A1:F1").Value = Array("Company", "CITY", "PR", "NP", "AS", "OL")
   With Sheets("[COLOR=#ff0000]Sheet1[/COLOR]")
      For i = 2 To .Range("A" & Rows.Count).End(xlUp).Row
         Rws = .Range("B" & i).Value
         NxtRw = Ws.Range("A" & Rows.Count).End(xlUp).Offset(1).Row
         Ws.Range("A" & NxtRw).Resize(1 * Rws).Value = .Range("A" & i).Value
         Ws.Range("B" & NxtRw).Resize(Rws).Value = Application.Transpose(.Range("C" & i).Resize(, Rws))
         k = 10
         For j = 1 To Rws
            Ws.Range("C" & Rows.Count).End(xlUp).Offset(1).Resize(, 4).Value = .Cells(i, k).Resize(, 4).Value
            k = k + 4
         Next j
      Next i
   End With
End Sub
Change sheet names in red to suit
 
Upvote 0
Without an accurate sample of your sheet I can't tell.
 
Upvote 0
How about
Code:
Sub RearrangeData()

   Dim i As Long, j As Long, k As Long
   Dim Rws As Long
   Dim NxtRw As Long
   Dim ws As Worksheet
   
   Set ws = Sheets("Output")
   ws.Range("A1:F1").Value = Array("Company", "CITY", "PR", "NP", "AS", "OL")
   With Sheets("Flip")
      For i = 2 To .Range("A" & Rows.Count).End(xlUp).Row
         Rws = .Range("B" & i).Value
         NxtRw = ws.Range("A" & Rows.Count).End(xlUp).Offset(1).Row
         ws.Range("A" & NxtRw).Resize(1 * Rws).Value = .Range("A" & i).Value
         ws.Range("B" & NxtRw).Resize(Rws).Value = Application.Transpose(.Range("C" & i).Resize(, Rws))
         k = 83
         For j = 1 To Rws
            ws.Range("C" & NxtRw).Resize(, 4).Value = .Cells(i, k).Resize(, 4).Value
            NxtRw = NxtRw + 1
            k = k + 4
         Next j
      Next i
   End With
End Sub
 
Upvote 0
GREAT, this works, many thanks!


How about
Code:
Sub RearrangeData()

   Dim i As Long, j As Long, k As Long
   Dim Rws As Long
   Dim NxtRw As Long
   Dim ws As Worksheet
   
   Set ws = Sheets("Output")
   ws.Range("A1:F1").Value = Array("Company", "CITY", "PR", "NP", "AS", "OL")
   With Sheets("Flip")
      For i = 2 To .Range("A" & Rows.Count).End(xlUp).Row
         Rws = .Range("B" & i).Value
         NxtRw = ws.Range("A" & Rows.Count).End(xlUp).Offset(1).Row
         ws.Range("A" & NxtRw).Resize(1 * Rws).Value = .Range("A" & i).Value
         ws.Range("B" & NxtRw).Resize(Rws).Value = Application.Transpose(.Range("C" & i).Resize(, Rws))
         k = 83
         For j = 1 To Rws
            ws.Range("C" & NxtRw).Resize(, 4).Value = .Cells(i, k).Resize(, 4).Value
            NxtRw = NxtRw + 1
            k = k + 4
         Next j
      Next i
   End With
End Sub
 
Upvote 0
Glad to help & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,284
Members
452,630
Latest member
OdubiYouth

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