Written by Allen Wyatt (last updated August 13, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
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.
Note:
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.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
When you sort data in a worksheet, there are a couple ways you can do it. Using the simple way can result in ...
Discover MoreWhen you sort information in a worksheet, you have control over the order in which that information is sorted. Here's a ...
Discover MoreInformation in a cell can be entered using line feeds, which results in multiple lines of data in the same cell. If you ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments