Weird or custom auto fill series problem?

Event2020

Board Regular
Joined
Jan 6, 2011
Messages
122
Office Version
  1. 2019
Platform
  1. Windows
I have been racking my brain on this for weeks and got precisely no where so I wonder if any of you guys may be able to suggest something.

I have a complected spreadsheet using multiple pages with various formulas pulling all the data together.

I have simplified my problem here but on one page I need a group of cells to auto fill the series vertically but as a block.

It would almost be like copying a group of cells stacked on top of each other and then each time you pasted them the cell reference inside auto updates by one, so =A1 would become =A2 and so on.

I am going to try and insert a table here which should show things better than I am explaining..

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]'=A1
[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=B1[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=C1[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=D1[/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=A2[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=B2[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=C2[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=D2
[/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=A3[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=B3[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=C3[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]'=D3[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

So hopefully you see what I mean and I need to repeat this 200 times so a formula or some other trick I am missing would be great as it will take far too long to do this by hand?

Thanks everyone:laugh:
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Try this formula:
=INDEX(A:D,-INT(-ROWS($A$1:A1)/4),MOD(ROWS($A$1:A1)-1,4)+1)

Copy down.

<b>Sheet1</b><br /><br /><table border="1" cellspacing="0" cellpadding="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; padding-left:2pt; padding-right:2pt; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td><td >H</td><td >I</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="text-align:right; ">1</td><td style="text-align:right; ">2</td><td style="text-align:right; ">3</td><td style="text-align:right; ">4</td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">1</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">9</td><td style="text-align:right; ">10</td><td style="text-align:right; ">11</td><td style="text-align:right; ">12</td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">2</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="text-align:right; ">20</td><td style="text-align:right; ">21</td><td style="text-align:right; ">22</td><td style="text-align:right; ">23</td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">3</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">4</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">9</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">10</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">11</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">12</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">20</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >10</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">21</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >11</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">22</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >12</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">23</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>Spreadsheet Formulas</b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >I1</td><td >=INDEX(A:D,-INT<span style=' color:008000; '>(-ROWS<span style=' color:#0000ff; '>($A$1:A1)</span>/4)</span>,MOD<span style=' color:008000; '>(ROWS<span style=' color:#0000ff; '>($A$1:A1)</span>-1,4)</span>+1)</td></tr></table></td></tr></table> <br /><br /><span style="font-family:Arial; font-size:9pt; font-weight:bold;background-color:#ffffff; color:#000000; ">Excel tables to the web >> </span>
 
Upvote 0
Scott

Brilliant, it did just what I wanted and I would never have been able to work that out on my own.

Thanks, much appreciated.
 
Upvote 0

Forum statistics

Threads
1,223,243
Messages
6,170,964
Members
452,371
Latest member
Frana

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