Written by Allen Wyatt (last updated December 31, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Kyle has a worksheet that consists of three columns of data: Part Number, Quantity, and Length. Length is designated in inches, with a quotation mark to show it is in inches (such as 30", 54", or 100"). Kyle needs to sort the data from shortest to longest length, but Excel sorts the lengths as text, such that 100" comes before 30". He wonders if there is a way to get Excel to sort the textual information as if it were numbers, so 30" correctly comes before 100", without getting rid of the quotation marks.
The short answer is that you can't do it, at least not directly. When you include the quote mark in the cell, Excel treats the entire cell as text and sorts it as such. And, as Kyle noted, the text string 100" comes before 30" because 1 comes before 3 in a textual sort.
There are things you can do, however. For instance, if you use a formula to generate the values in your Length column, you could modify the formula so that it "front pads" the lengths with zeroes, as necessary. Using this approach you would not have lengths like 30", 54", or 100", but instead you would have 030", 054", and 100". As long as all the lengths used the same number of digits, the sorting will occur correctly.
You could also add a helper column to the right of the Length column and, in the helper column, place the numeric values of whatever is in the cell to the left. So, if your first data in in cell C2, in cell D2 (your helper column) you could enter the following:
=VALUE(SUBSTITUTE(C2,"""",""))
The four quote marks are necessary as the second parameter of the SUBSTITUTE function in order to get rid of quote marks in C2. The result is that D2 contains the numeric value of whatever was in cell C2. Copy the formula down as far as necessary, and then use column D to do the sorting. After sorting you can even hide column D, if desired, or make it as narrow as you want.
Another approach that can work well if you have a limited number of lengths is to create a custom list and then use that list to do the sorting. Here's how to set up the custom list for your lengths:
Figure 1. The Custom Lists dialog box.
Once the custom list is defined, you can use the Sort dialog box and specify that you want to do a custom sort. Pick your new list and that is what Excel will use when arranging the rows in the worksheet. Again, this approach only really works if you have a limited number of lengths and you know ahead of time what those lengths will be.
Perhaps the best solution, though, is to remove the quotation marks. (Yes, I know... Kyle said he didn't want to get rid of them, but bear with me for a moment.) If everything in the Length column is shown in inches, then you can get rid of the explicit quote marks and create a custom format that will display them. Getting rid of the quote marks is easy—just use Find and Replace to remove them. (Search for a quote mark and replace it with nothing.) Then, create the custom format in this manner:
Figure 2. The Number tab of the Format Cells dialog box.
You should now see all the cells (selected in step 1) displayed with the trailing quote mark. It is the format specified in step 5 that instructs Excel to include the quote mark after any number. It also instructs Excel to display one digit after the decimal point. (You can modify the format so it displays a different number of digits, if desired. If you just want the number to be generally visible, then use this custom format:
#\"
As with the custom format in step 5 of the steps just shown, the backslash is necessary so that Excel knows the quote mark is part of the custom format itself.
Again, the custom format route works great if everything in the Length column is shown in inches. If it isn't all in inches, then you could move the dimension indicator (quote mark, apostrophe, whatever) to column D and remove it from column C. Make column D just as narrow as necessary to display the dimension indicator, and then sort by column C.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3917) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
Sorting information in a worksheet can be confusing when Excel applies sorting rules of which you are unaware. This is ...
Discover MoreIf the font color used for the data in your worksheet is critical, you may at some time want to move cells that use a ...
Discover MoreIf you have some data in a worksheet that is bold, you may want to sort that data based on the text attribute. This is ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-01-03 01:12:03
Tomek
Please note the space in the custom format i suggested:
# ??/??\"
Also, you can use "-" as the delimiter between inches and fractions displayed, but only in the format; when entering the data you have to use a ***single*** space like in 1 3/16.
2023-01-03 01:02:20
Tomek
If you use the last solution with custom format, you can even modify it to sort properly when the length is displayed in inches with fractions.
The custom format for this is
# ??/??\"
The nice thing about this format is that the spaces between whole inches and fractions will be aligned, as will be the / in fractions. and it will sort properly as the underlying numbers are stored as decimal numbers.
Once a column is formatted this way you can even enter your lengths explicitly as inches and fractions, which makes it easy to stick to 1/2 1/4 1/8ths...
For example you can enter 120 13/64.
If you try to enter decimals you may end up with fractions like 7/10 or 8/13 depending on nearest rounding.
If you need smaller fractions like 128ths just use more ? on both sides of the division mark.
(see Figure 1 below) for an example
Figure 1.
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