How to sort() value with alpha numeric

mart_mrexcel

Active Member
Joined
Aug 23, 2008
Messages
310
Office Version
  1. 365
Platform
  1. Windows
I have values in a column where i want to sort (using SORT function) from highest to lowest (or vice versa), but the data has letters.

T3
T12
T7
T14
T13
T15
T5
T4
T2
T0
T16
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
Here is an option to try:
Book1
AB
2T3T0
3T12T2
4T7T3
5T14T4
6T13T5
7T15T7
8T5T12
9T4T13
10T2T14
11T0T15
12T16T16
Sheet1
Cell Formulas
RangeFormula
B2:B12B2=LET(r,A2:A12,d,--SUBSTITUTE(r,"T",""),SORTBY(r,d,1))
Dynamic array formulas.
 
Last edited:
Upvote 0
Solution
Here is an option to try:
Book1
AB
2T3T0
3T12T2
4T7T3
5T14T4
6T13T5
7T15T7
8T5T12
9T4T13
10T2T14
11T0T15
12T16T16
Sheet1
Cell Formulas
RangeFormula
B2:B12B2=LET(r,A2:A12,d,--SUBSTITUTE(A2:A12,"T",""),SORTBY(r,d,1))
Dynamic array formulas.
That works perfect ... thank you
 
Upvote 0
You are welcome, thanks for the feedback.

I have made the formula slightly shorter in post 4.
 
Upvote 0

Forum statistics

Threads
1,223,275
Messages
6,171,127
Members
452,381
Latest member
Nova88

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top