Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Three-Dimensional Transpositions.
Written by Allen Wyatt (last updated July 4, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
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 in 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 (11246) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Three-Dimensional Transpositions.
                        Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!
When you filter rows in your data, you may want to later number those rows. This tip provides a variety of ways you can ...
Discover MoreWhen you select a cell, you typically do so to see what the cell contains to to make changes to the cell. How Excel ...
Discover MoreAutoComplete can help you to more quickly enter information in a worksheet. How it works, behind the scenes, can affect ...
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 ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu 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