Transpose formula

kcin

Board Regular
Joined
Jun 6, 2006
Messages
118
Hello,

I currently paste some data into excel from a different source and then work to format it the way I would like. Right now, the data is pasted in horizontally. I create a few summary columns off to the side in which I select the cells I would like horizontally and select paste special -> values, transpose. Is there a formula approach to this?

So I would like a formula to display cells vertically from the current data that is displayed horizontally.

IE: Data is formatted to be in cells B2, C2, D2....and I would like a formula that I can propogate downward in Column X. So in X2 I will have the formula "=B$2" and then be able to drag it downward to display cell C2 in cell X3.

I can't figure out how to tell excel to move over one cell instead of always down one cell. Hopefully it is clear what I am looking to do.

Any help would be appreciated, thanks.
 

Some videos you may like

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number

Scott Huish

MrExcel MVP
Joined
Mar 17, 2004
Messages
19,958
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
Change your range as necessary.

Formula in X2:
=INDEX($B$2:$E$2,ROWS($X$1:X1))
Copy down.
 

kcin

Board Regular
Joined
Jun 6, 2006
Messages
118
Thanks Hotpepper. This formula works perfectly although can you please explain exactly what the ROWS part does? It doesn't seem to have any effect on my results no matter what range I put into it.
 

Scott Huish

MrExcel MVP
Joined
Mar 17, 2004
Messages
19,958
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
Sure,

In X2, ROWS($X$1:X1) would equal 1 so it will pull the first value from the range.

In X3, it will become ROWS($X$1:X2) which equals 2, so it will pull the second value from the range.

etc.

Now why ROWS?

Say you insert a row before row 2.

The first formula would now become:
=INDEX($B$3:$E$3,ROWS($X$2:X2))

Which ROWS($X2:X2) still equals 1 so it will return the correct result.

In X4:
=INDEX($B$3:$E$3,ROWS($X$2:X3))
where ROWS($X$2:X3) still returns a value of 2 and so on.
 

Watch MrExcel Video

Forum statistics

Threads
1,123,514
Messages
5,602,093
Members
414,501
Latest member
mdhaumyu

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
Top