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

Sorting Data Containing Merged Cells

Written by Allen Wyatt (last updated August 30, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365


3

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, 2021, 2024, and Excel in Microsoft 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

Setting the Right Indent of a Paragraph in a Macro

Need to format your document using a macro? You can easily set the right margin for an individual paragraph by using the ...

Discover More

Duplicating Drawing Objects

Using the copy and paste techniques you already know, you can copy and paste drawing objects. In this way, you can ...

Discover More

Creating a Photo Catalog from a Folder of Photos

Excel is great for collecting all sorts of information. You might even use it to create a catalog of your photos. Working ...

Discover More

Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!

More ExcelTips (ribbon)

Too Many Formats when Sorting

Sorting is one of the basic operations done in a worksheet. If your sorting won't work and you instead get an error ...

Discover More

Sorting Dates and Times

One of the strong features of Excel is its ability to sort information in a worksheet. When it doesn't sort information ...

Discover More

Getting Wrong Results from a Simple Sort

Sorting in Excel is easy. Getting the right results from a sort, though, can sometimes be perplexing. This tip looks at ...

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 1 + 8?

2025-09-04 06:01:30

SteveJez

Surely the "problem" is that users are not sufficiently trained. There should be no reason to use merged cells in data sets/ranges. Merged cells should only exist in "presentation" sheets / spaces / reports. Data should be capable of being sorted / filtered without the hinderance of workarounds or having to run macros.
The report / output should then "indirectly" use that data.
Education is key.


2025-09-03 12:54:09

J. Woolley

Re. the macro in my comment below, the following two statements
                .Cells(n) = .Cells(n) & Format(n, FMT)
                .Cells(n + 1) = .Cells(n) & Format(n + 1, FMT)
should be reversed like this
                .Cells(n + 1) = .Cells(n) & Format(n + 1, FMT)
                .Cells(n) = .Cells(n) & Format(n, FMT)
The macro works without the correction, but the correction makes it work as intended. Mea culpa.


2025-08-31 14:53:00

J. Woolley

Here's an alternate version of the Tip's macro. It assumes the following:
1. Row 1 of the list is a heading
2. Cells in column A below row 1 are merged in pairs
3. The merged cells in column A contain text constants
4. There are no other merged cells in the list

Sub SortList2()
    Const FMT = "0000000000"
    Dim nRows As Long, n As Long
    With Range("A1").CurrentRegion
        nRows = .Rows.Count
        With .Columns(1)
            .UnMerge
            For n = 2 To nRows Step 2
                .Cells(n) = .Cells(n) & Format(n, FMT)
                .Cells(n + 1) = .Cells(n) & Format(n + 1, FMT)
            Next n
        End With
        .Sort Key1:=Range("A2"), Order1:=xlAscending, Header:=xlYes
        With .Columns(1)
            For n = 2 To nRows Step 2
                .Cells(n) = Left(.Cells(n), Len(.Cells(n)) - Len(FMT))
                .Cells(n + 1) = ""
                Range(.Cells(n), .Cells(n + 1)).Merge
            Next n
        End With
    End With
End Sub


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.