Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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 for a Walking Tour.
Written by Allen Wyatt (last updated December 23, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Francine has a series of addresses in a worksheet. The house numbers are in one column (124, 127, 130, etc.) and the street name is in the adjacent column (Maple St., Elm St., etc.). She needs to sort the list first by street name and then by house number with the even numbers first, in ascending order, and then the odd numbers next, in descending order. This will allow her to create a list of houses, in order, for a walking tour. People can then walk down the even-numbered side of the street, cross to the other side, and walk back down the odd-numbered side of the street. She wonders how to do this type of sorting.
Excel allows you to sort information in ascending and descending order quickly by using the sort feature. While this option is useful in many instances, this is an example of one time when a formula is necessary to determine a value you can use in your sorting. There are a few ways to do this.
You need to create a column that will specify each address as odd or even. Assuming the number portion of the address is in cell A1 and the street name is in B1, in a third column you could enter this formula:
=IF(ISEVEN(A1),B1&"_0_"&A1,B1&"_1_"&MAX($A$1:$A$19)-A1)
This formula returns the name of the street with some numbers that are for sorting purposes only. At this point, copy and paste the formula down the new column you created. Once the formula has been entered for each address, you can sort the information. You only need to sort by the formula, in ascending order. Excel returns the addresses with the street names in alphabetical order where the even street numbers are in ascending order, followed by the odd street numbers in descending order, as requested.
Note: In the above formula, it is assumed that the range for the addresses is A1:A19, which is where MAX($A$1:$A$19) comes from. If there are more addresses, then put the correct range in that portion of the formula.
And yet another approach is to use the following formula:
=IF(MOD(A1,2)=1,(1+RANK(A1,A:A,1))/2,(COUNT(A:A)+RANK(A1,A:A)+1)/2)
The numbers returned by this formula are not particularly important; they essentially assign a relative order for an address based on the house number. Simply copy and paste the formula down the column you created and sort the information. You then need to sort the list, first by street name in ascending order and then by the formula in descending order. The result is that your addresses are ordered in the desired fashion.
You can also use the same MOD formula as follow for a different approach:
=MOD(A1,2)*(9999999-A1*2)+A1
This formula returns two types of numbers—big ones for odd addresses and small ones for even addresses. As with the previous formulas, copy and paste the formula down the column you created. Once this is done you can sort the information. You need to sort first by street name, then by formula, both in ascending order. Excel orders the addresses based on the formula, which puts the even addresses first and the odd addresses second, in descending order.
As you can see, there are a number of formulas that can return the same information. Play around with them and use the one that makes sense for you and your project.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8105) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Sorting for a Walking Tour.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Need to do the same sorting operation over and over again? Excel doesn't provide a way to save your sorting criteria, but ...
Discover MoreOne way you can easily work with data in a worksheet is to sort it into whatever order you find most helpful. Excel ...
Discover MoreWhen formatting the layout of your worksheet, Excel allows you to easily merge adjacent cells together. This can cause ...
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 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