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: Sorting Data Containing Merged Cells.
Written by Allen Wyatt (last updated March 20, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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:
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 Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Sorting Data Containing Merged Cells.
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!
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 MoreWhen you sort information in a worksheet, you have control over the order in which that information is sorted. Here's a ...
Discover MoreIf you use graphics in a worksheet that are associated with certain cells (perhaps images of parts or icons for worksheet ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-03-23 10:28:45
J. Woolley
For more about "center across selection," see my recent comment about the CenterAcrossSelection macro in My Excel Toolbox here: https://excelribbon.tips.net/T012183_Creating_a_Center_Across_Selection_Button.html
For something like "center across selection vertically," see my recent comment about the FillJustifyText macro in My Excel Toolbox here: https://excelribbon.tips.net/T011496_Combining_Multiple_Rows_in_a_Column.html
2023-03-22 00:56:52
Tomek
@Kerry:
Your suggestion works only as an option for cells merged horizontally, and actually is is the recommended method to put information across several cells, but not cause any limitations merged cells induce.
However, there is no equivalent "center across selection" vertically for adjacent cells in the same column. That is why you need to find workarounds for such scenarios.
2023-03-20 14:42:09
Sarah J
Pat, the "zz" is simply to keep the names, and therefore the corresponding data, paired together. You could use any character(s) there to append to the name, but unless you use something really unusual you run the risk of your entries mixing together within small segments of the alphabet. It's unlikely that your data will include a "zz" to confuse the sort function, but if it does, use something else as a differentiator for your text. Numbers could work too, if none of your data includes alphanumeric entries. The "zz" itself doesn't do anything special.
2023-03-20 10:30:28
Kerry
Re: Sorting merged cells.
Instead of "merge" could you use Alignment > "center across selection" and then sort on the left hand column of the two cells. You may have to re-align the cells when finished.
2021-03-24 13:54:31
Pat Hughes
Why do we use "zz" to add to the 1st column 2nd row, and every other row going down when we turn off the merged cells? What does "zz" do?
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 © 2024 Sharon Parq Associates, Inc.
Comments