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

Sorting Data Containing Merged Cells

by Allen Wyatt
(last updated July 27, 2019)

Excel has long included the ability to merge adjacent cells into a larger, single cell. This ability has been used by many worksheet designers to give their worksheets a polished, professional look.

There is a huge drawback to using merged cells, however: You can't sort tables that include them. If you try, you'll get a message that says, "The operation requires the merged cells to be identically sized."

The most obvious solution to the problem is to not use merged cells. Let's say, for instance, that you have a worksheet in which each "record" actually consists of two rows, and that the first column of the worksheet contains merged cells. (Each two-row record starts with two merged cells spanning the two rows. This merged cell contains a project name.)

It is better to unmerge the cells in the first column, but then you may wonder how to make the records sort properly in the worksheet; how to keep the row pairs together during a sort. You can do this by putting your project name in the first row and the project name appended with "zz" in the second row. For instance, if the first row contains "Wilburn Chemical" (the project name), then the second row could contain "Wilburn Chemicalzz". Format the second row's cell so the name doesn't show up (such as white text on a white background), and you can then successfully sort as you want to.

Another solution is to use a macro to juggle your worksheet and get the sorting done. Assuming that the merged cells are in column A (as previously described), you can use the following macro to sort the data by the contents of column A:

Sub SortList()
    Dim sAddStart As String
    Dim rng As Range
    Dim rng2 As Range
    Dim lRows As Long

    Application.ScreenUpdating = False
    sAddStart = Selection.Address
    Set rng = Range("A1").CurrentRegion

    With rng
        lRows = .Rows.Count - 1
        .Cells(1).EntireColumn.Insert
        .Cells(1).Offset(0, -1) = "Temp"
        .Cells(1).Offset(1, -1).FormulaR1C1 = _
          "=+RC[1]&"" ""&ROW()"
        .Cells(1).Offset(2, -1).FormulaR1C1 = _
          "=+R[-1]C[1]&"" ""&ROW()"
        Set rng2 = .Cells(1).Offset(1, -1).Resize(lRows, 1)
        Range(.Cells(2, 0), .Cells(3, 0)).AutoFill _
            Destination:=rng2
        rng2.Copy
        rng2.PasteSpecial Paste:=xlValues

        .Columns(1).MergeCells = False

    .CurrentRegion.Sort _
        Key1:=Range("A2"), Order1:=xlAscending, _
        Header:=xlYes, OrderCustom:=1, _
        MatchCase:=False, Orientation:=xlTopToBottom

        rng2.EntireColumn.Delete

        With Range(.Cells(2, 1), .Cells(3, 1))
            .Merge
            .Copy
            .Cells(3, 1).Resize(lRows - 2, 1). _
                PasteSpecial Paste:=xlFormats
        End With
    End With
    Application.CutCopyMode = False
    Range(sAddStart).Select
    Application.ScreenUpdating = True
End Sub

The macro inserts a temporary column, reads the items from the first column of the list, appends the row number, copies it down the temporary column, unmerges the cells, sorts the list, deletes the temporary column, and re-merges column A. (That's a lot of work just to sort a table with merged cells!)

This macro is very specific to a particular layout of your data, and therefore would need to be tested and probably modified to make sure it would work with data formatted in any other way.

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 (761) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. You can find a version of this tip for the older menu interface of Excel here: Sorting Data Containing Merged Cells.

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

Using Non-Printing Notes

Adding notes to your document in Word is a handy tool. But what if you don't want those notes to be seen on the screen or ...

Discover More

Removing Dashes from ISBN Numbers

ISBN numbers are used to denote a unique identifier for a published book. If you remove the dashes included in an ISBN, ...

Discover More

Printing Post Office Permits on Envelopes

When preparing to snail-mail information, you may want to print your envelopes with permit information in the upper-right ...

Discover More

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 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Forcing Excel to Sort Cells as Text

If you have a mixture of numbers and text in a column and you want to sort based upon that column, the results may not be ...

Discover More

Non-standard Sorting

Information in a cell can be entered using line feeds, which results in multiple lines of data in the same cell. If you ...

Discover More

Can't Sort Imported Data

Import information from an external database, and you'll no doubt want to use Excel's simple tools to manipulate that ...

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}] 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 6 + 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.