Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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.

Three-Dimensional Transpositions

Written by Allen Wyatt (last updated July 4, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


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:

  1. Create a PivotTable from your data as you normally would.
  2. Place the column from which you want worksheets created into the "Report Filter" section of the PivotTable.
  3. Display the Options tab of the ribbon. (This tab is visible only when you are working on a PivotTable.)
  4. Click the down-arrow next to the Options tool, in the PivotTable group at the left end of the ribbon.
  5. Choose Show Report Filter Pages. Excel asks you to confirm that you want to show the pages.
  6. 6 Click OK.

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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11246) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Three-Dimensional Transpositions.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Deleting Caption Labels

Define a label to be used in a caption, and you may later want to delete that label. Here's how you can easily make the ...

Discover More

Setting Spell-Checking Options

Like many things in Word, you can configure the way the spelling checker does its job. If you want to exercise more ...

Discover More

Reformatting a Document with Messed-Up Styles

If there are lots of hands that touch a document, there are lots of ways those hands can mess up the document. You may be ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Identifying Duplicates

Do you need to flag duplicate values in your data? This tip shows three different ways you can do the flagging you need.

Discover More

Copying Cells to Fill a Range

Excel provides two really helpful shortcuts you can use to fill a range of cells, either horizontally or vertically. ...

Discover More

Concatenating Ranges of Cells

Putting the contents of two cells together is easy. Putting together the contents of lots of cells is more involved, as ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two more than 9?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.