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:
- Create a PivotTable from your data as you normally would.
- Place the column from which you want worksheets created into the “Report Filter” section of the PivotTable.
- Display the Options tab of the ribbon. (This tab is visible only when you are working on a PivotTable.)
- Click the down-arrow next to the Options tool, in the PivotTable group at the left end of the ribbon.
- Choose Show Report Filter Pages. Excel asks you to confirm that you want to show the pages.
- 6 Click OK.
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