Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Three-Dimensional Transpositions.
Written by Allen Wyatt (last updated March 2, 2024)
This tip applies to Excel 97, 2000, 2002, and 2003
As a former heavy-duty Lotus 1-2-3 user at a prior job, Patti got VERY attached to a feature that is sorely lacking in Excel: the ability to transpose data in three dimensions. Two-dimensional transposition is supported in Excel, but Patti has not figured out a way to take a row or column or table and spread it through a stack of worksheets. This was a function that was used daily by everyone in her finance office, and she really misses it.
Patti is right; there is no built-in function to do this in Excel. The closest option is to use a PivotTable and the "Show Pages" capabilities it includes. In general, you follow these steps:
What you end up with is a series of worksheets, one for each entry the column you specified in step 2. Those worksheets each contain a "page" of the PivotTable.
If this still doesn't quite do what you want, then you'll need to resort to using a macro to transpose the data. Such a macro can get quite complex, but basically all it needs to do is step through your data table and move each row (or column) of data to its own worksheet.
As an example, the following macro (Transpose3D) will take each row from a selected range of cells and place that row on its own, newly created worksheet.
Sub Transpose3D()
Dim rngTbl As Range
Dim wsName As String
Dim R As Integer
Dim C As Integer
Dim i As Integer
Dim j As Integer
Dim Killit As Integer
Dim RCount As Integer
Dim CCount As Integer
Dim Table1() As Variant
Dim Row1() As Variant
RCount = Selection.Rows.Count
CCount = Selection.Columns.Count
If RCount < 2 Then
MsgBox ("Error; Select a range with more than one row.")
GoTo EndItAll
End If
wsName = ActiveSheet.Name
R = ActiveCell.Row
C = ActiveCell.Column
Set rngTbl = Selection
ReDim Table1(1 To RCount, 1 To CCount)
ReDim Row1(1 To 1, 1 To CCount)
Table1() = rngTbl.Value
On Error GoTo Abend
For i = 1 To RCount
If SheetExists(wsName & "_Row_" & i) Then
Killit = MsgBox("Sheet " & wsName & "_Row_" & i & _
" Already Exists!" & vbCrLf & _
" Cancel: Stop Transposition" & vbCrLf & _
" OK: Delete Sheet and Continue", vbOKCancel)
If Killit = vbCancel Then GoTo EndItAll
Application.DisplayAlerts = False
Sheets(wsName & "_Row_" & i).Delete
Application.DisplayAlerts = True
End If
Sheets.Add
ActiveSheet.Name = wsName & "_Row_" & i
Cells(R, C).Select
For j = 1 To CCount
Row1(1, j) = Table1(i, j)
Next j
Range(ActiveCell, ActiveCell.Offset(0, CCount - 1)) = Row1()
Sheets(wsName).Select
Next i
GoTo EndItAll
Abend:
MsgBox ("Error in Routine Transpose3D.")
EndItAll:
Application.DisplayAlerts = True
End Sub
Function SheetExists(SheetName As String) As Boolean
Dim ws As Worksheet
SheetExists = False
For Each ws In ThisWorkbook.Worksheets
If ws.Name = SheetName Then
SheetExists = True
Exit For
End If
Next ws
End Function
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11245) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Three-Dimensional Transpositions.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel Data Analysis and Business Modeling today!
Paste information in a worksheet, and you may end up with Excel placing it into lots of different cells. If you want it ...
Discover MoreHave you ever typed something in Excel, only to have it replace whatever is to the right of the insertion point? That's ...
Discover MoreCopying information from one program (such as Word) to another (such as Excel) is a common occurrence. If you want to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments