Extracting words in between specified characters - question

gambit023

New Member
Joined
Jul 14, 2009
Messages
29
I have the following string in an two Excel cells:

CID.1204^Cardiovascular Disease^Cardiology^CARDIOLOGY^
CID.1202^Anesthesiology^Anes^^

How do I write a function to extract just the word inbetween the second and third "^" character (bolded and underlined)?

Thanks in advance for your help!
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
Code:
=mid(a1,find("~",substitute(a1,"^","~",3))+1,find("#",substitute(a1,"^","#",4))-find("~",substitute(a1,"^","~",3))-1)
 
Upvote 0
Will there always be a second and third "^"?
 
Upvote 0
The code above only works is there are characters in between the last "^" marks.

if there is no data it doesn't pull back any info.

There will always be four "^" characters in each string but data may or may not exist in between every caret character.
 
Upvote 0
<b>Excel 2003</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">CID.1204^Cardiovascular Disease^Cardiology^CARDIOLOGY^</td><td style=";">Cardiology</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">CID.1202^Anesthesiology^Anes^^</td><td style=";">Anes</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">CID.1203^Cardiovascular Disease^^CARDIOLOGY</td><td style=";"></td></tr></tbody></table><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style="background-color: #E0E0F0;text-align: center;color: #161120"><th><b>Sheet1</b></th></tr></td></thead></table><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">B1</th><td style="text-align:left">=IF(<font color="Blue">ISERROR(<font color="Red">FIND(<font color="Green">"$$",SUBSTITUTE(<font color="Purple">SUBSTITUTE(<font color="Teal">A1,"^","$",3</font>),"^","$",2</font>)</font>)</font>),MID(<font color="Red">A1,FIND(<font color="Green">"~",SUBSTITUTE(<font color="Purple">A1,"^","~",2</font>)</font>)+1,FIND(<font color="Green">"#",SUBSTITUTE(<font color="Purple">A1,"^","#",3</font>)</font>)-FIND(<font color="Green">"~",SUBSTITUTE(<font color="Purple">A1,"^","~",2</font>)</font>)-1</font>),""</font>)</td></tr></tbody></table></td></tr></table><br />
 
Upvote 0
The code above only works is there are characters in between the last "^" marks.

if there is no data it doesn't pull back any info.

There will always be four "^" characters in each string but data may or may not exist in between every caret character.

Amended my formula:
Code:
=MID(A1,FIND("~",SUBSTITUTE(A1,"^","~",2))+1,FIND("#",SUBSTITUTE(A1,"^","#",3))-FIND("~",SUBSTITUTE(A1,"^","~",2))-1)
 
Upvote 0
Why is it that I feel like I've reached nirvana when you guys help me out with this stuff and things start working.


Thanks all!!!
 
Upvote 0
Hi

Also a variation on Neil's formula:

=MID(A1,FIND("~",SUBSTITUTE(A1,"^","~",2))+1,SUM(FIND("#",SUBSTITUTE(A1,"^","#",{2,3}))*{-1,1})-1)
 
Upvote 0

Forum statistics

Threads
1,224,537
Messages
6,179,405
Members
452,911
Latest member
a_barila

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