Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Sorting by Colors.

Sorting by Colors

by Allen Wyatt
(last updated October 4, 2014)

Excel allows you to sort the data in your worksheets by any number of attributes. One of the things that you cannot intrinsically sort by, however, is the color of cells—at least not without updating to Excel 2007 or later. For some applications this could be a very handy feature. The following macro, SortByColor, will sort a table based on the color with which a cell is formatted.

Sub SortByColor()
    On Error GoTo SortByColor_Err

    Dim sRangeAddress As String
    Dim sStartCell As String
    Dim sEndCell As String
    Dim rngSort As Range
    Dim rng As Range

    Application.ScreenUpdating = False

    sStartCell = InputBox("Enter the cell address of the " & _
      "top cell in the range to be sorted by color" & _
      Chr(13) & "i.e.  'A1'", "Enter Cell Address")

    If sStartCell > "" Then
        sEndCell = Range(sStartCell).End(xlDown).Address
        Range(sStartCell).EntireColumn.Insert
        Set rngSort = Range(sStartCell, sEndCell)
        For Each rng In rngSort
            rng.Value = rng.Offset(0, 1).Interior.ColorIndex
        Next
        Range(sStartCell).Sort Key1:=Range(sStartCell), _
          Order1:=xlAscending, Header:=xlNo, _
          Orientation:=xlTopToBottom
        Range(sStartCell).EntireColumn.Delete
    End If

SortByColor_Exit:
    Application.ScreenUpdating = True
    Set rngSort = Nothing
    Exit Sub

SortByColor_Err:
    MsgBox Err.Number & ": " & Err.Description, _
      vbOKOnly, "SortByColor"
    Resume SortByColor_Exit
End Sub

The macro works by first asking you the beginning cell of the range you want to sort. This should be the top-most cell in the range. The macro then inserts a column (just temporarily) in which color values can be stored. It then steps through each cell in the range defined by the starting cell you specified.

SortByColor assumes your data table doesn't have a header row. If it does, you should change the actual sorting command. Simply change Header:=xlNo to Header:=xlYes.

You should note that the SortByColor macro will only sort cells based on the explicit color applied to the cell, it will not sort if the color of the cell is the result of conditional formatting.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3122) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Sorting by Colors.

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

Understanding Subroutines

The heart of creating powerful programs in VBA is to understand how to create subroutines. These structures allow you to ...

Discover More

Displaying a Hidden First Column

Hiding columns is easy, even hiding column A. How, then, do you get that left-most column displayed again? Here are a few ...

Discover More

Copying Subtotals

If you have added subtotals to your worksheet data, you might want to copy those subtotals somewhere else. This is easy to do ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

MORE EXCELTIPS (MENU)

Sorting a Range of Cells

When you sort data in a worksheet, you don't need to sort everything at once. You can sort just a portion of your data by ...

Discover More

Sorting Letters and Numbers

Sorting information in a worksheet can be confusing when Excel applies sorting rules of which you are unaware. This is ...

Discover More

Sorting an Entire List

Need to sort all the data in a table? Here's the fastest and easiest way to do it.

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 for this tip:

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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

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.

Links and Sharing
Share