richardthelionheart

Board Regular
Joined
Mar 25, 2016
Messages
95
Office Version
  1. 2016
Platform
  1. Windows
I have data which I need to sort based on certain criteria.
Here are a few examples of the data.
1TT66
32144
24TTT
5T153
36335
TTTTT
44T23
So the data may contain no 'T's' or a number of 'T's'.
These occur randomly in the data.
I need to identify only the following:
Those that contain only 1 'T'
Those that contain no 'T's'
I thought that there might be a formula that could be created that would do this for me, rather than create a number of columns and convoluted maths.
I would be very grateful if someone could give me some direction on this problem.
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Use SUBSTITUTE "T" for null and check before and after lengths.

ABC
11TT6632 T
2321445No T
324TTT23 T
45T15341 T
5363355No T
6TTTTT05 T
744T2341 T

<colgroup><col style="width: 25pxpx"><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
B1=LEN(SUBSTITUTE(A1,"T",""))
C1
=CHOOSE(LEN(A1)-LEN(SUBSTITUTE(A1,"T",""))+1,"No T","1 T","2 T","3 T","4 T","5 T")

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>
 
Upvote 0
I need to identify only the following:
Those that contain only 1 'T'
Those that contain no 'T's'
.. so could it be this variation, copied down.


Excel 365 (Windows) 32 bit
AB
11TT66 
2321440
324TTT
45T1531
5363350
6TTTTT
744T231
Count T
Cell Formulas
RangeFormula
B1=LOOKUP(LEN(A1)-LEN(SUBSTITUTE(A1,"T","")),{0,1,2},{0,1,""})
 
Upvote 0
I show you a couple of options:

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:93.15px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Text</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Option 1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Option 2</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:left; ">1TT66</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="text-align:left; ">32144</td><td >Yes</td><td >Yes</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="text-align:left; ">24TTT</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="text-align:left; ">5T153</td><td >Yes</td><td >Yes</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td style="text-align:left; ">36335</td><td >Yes</td><td >Yes</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td style="text-align:left; ">TTTTT</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td style="text-align:left; ">44T23</td><td >Yes</td><td >Yes</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >B2</td><td >=IF(LEN(A2)-LEN(SUBSTITUTE(A2,"T",""))<2,"Yes","")</td></tr><tr><td >C2</td><td >=IF(IFERROR(SEARCH("T*T",A2),"x")="x","Yes","")</td></tr></table></td></tr></table>
 
Upvote 0
In fact, if you use the last option you can use "T" or "t".
A shorter option:

=IF(IFERROR(SEARCH("t*t",A2),0),"","Yes")
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,653
Messages
6,120,751
Members
448,989
Latest member
mariah3

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