Trim Text after 3rd Underscore but retain format

trankim

Board Regular
Joined
Nov 14, 2009
Messages
192
I am hoping you excel geniuses can help me with a formula that will look for the 3rd underscore in a string and truncate all the text after the the 3rd underscore. I need to retain the format before the 3rd underscore though. Note: I may not have the same amount of underscores in each cell, so if there's not enough "underscore", it should return "Text/Logo".

<TABLE style="WIDTH: 220pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=293><COLGROUP><COL style="WIDTH: 220pt; mso-width-source: userset; mso-width-alt: 8334" width=293><TBODY><TR style="HEIGHT: 16.5pt" height=22><TD style="BORDER-BOTTOM: #d4d0c8; BORDER-LEFT: #d4d0c8; BACKGROUND-COLOR: transparent; WIDTH: 220pt; HEIGHT: 16.5pt; BORDER-TOP: #d4d0c8; BORDER-RIGHT: #d4d0c8" class=xl385 height=22 width=293>Example:
Intel_CI_City_VisitCI_300x250_Flash.swf
</TD></TR></TBODY></TABLE>

Output Result:
<TABLE style="WIDTH: 220pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=293><COLGROUP><COL style="WIDTH: 220pt; mso-width-source: userset; mso-width-alt: 8334" width=293><TBODY><TR style="HEIGHT: 16.5pt" height=22><TD style="BORDER-BOTTOM: #d4d0c8; BORDER-LEFT: #d4d0c8; BACKGROUND-COLOR: transparent; WIDTH: 220pt; HEIGHT: 16.5pt; BORDER-TOP: #d4d0c8; BORDER-RIGHT: #d4d0c8" class=xl385 height=22 width=293>Intel_CI_City_VisitCI

<TABLE style="WIDTH: 220pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=293><COLGROUP><COL style="WIDTH: 220pt; mso-width-source: userset; mso-width-alt: 8334" width=293><TBODY><TR style="HEIGHT: 16.5pt" height=22><TD style="BORDER-BOTTOM: #d4d0c8; BORDER-LEFT: #d4d0c8; BACKGROUND-COLOR: transparent; WIDTH: 220pt; HEIGHT: 16.5pt; BORDER-TOP: #d4d0c8; BORDER-RIGHT: #d4d0c8" class=xl385 height=22 width=293>Example 2:
1x1_AMD.gif
</TD></TR></TBODY></TABLE>
Output Result:
<TABLE style="WIDTH: 220pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=293><COLGROUP><COL style="WIDTH: 220pt; mso-width-source: userset; mso-width-alt: 8334" width=293><TBODY><TR style="HEIGHT: 16.5pt" height=22><TD style="BORDER-BOTTOM: #d4d0c8; BORDER-LEFT: #d4d0c8; BACKGROUND-COLOR: transparent; WIDTH: 220pt; HEIGHT: 16.5pt; BORDER-TOP: #d4d0c8; BORDER-RIGHT: #d4d0c8" class=xl385 height=22 width=293>Text/Logo</TD></TR></TBODY></TABLE>
</TD></TR></TBODY></TABLE>
I appreciate any help that anyone can give me. Thanks!
<!-- / message -->
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
I am hoping you excel geniuses can help me with a formula that will look for the 3rd underscore in a string and truncate all the text after the the 3rd underscore. I need to retain the format before the 3rd underscore though. Note: I may not have the same amount of underscores in each cell, so if there's not enough "underscore", it should return "Text/Logo".

<TABLE style="WIDTH: 220pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=293><COLGROUP><COL style="WIDTH: 220pt; mso-width-source: userset; mso-width-alt: 8334" width=293><TBODY><TR style="HEIGHT: 16.5pt" height=22><TD style="BORDER-BOTTOM: #d4d0c8; BORDER-LEFT: #d4d0c8; BACKGROUND-COLOR: transparent; WIDTH: 220pt; HEIGHT: 16.5pt; BORDER-TOP: #d4d0c8; BORDER-RIGHT: #d4d0c8" class=xl385 height=22 width=293>Example:
Intel_CI_City_VisitCI_300x250_Flash.swf

</TD></TR></TBODY></TABLE>

Output Result:
<TABLE style="WIDTH: 220pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=293><COLGROUP><COL style="WIDTH: 220pt; mso-width-source: userset; mso-width-alt: 8334" width=293><TBODY><TR style="HEIGHT: 16.5pt" height=22><TD style="BORDER-BOTTOM: #d4d0c8; BORDER-LEFT: #d4d0c8; BACKGROUND-COLOR: transparent; WIDTH: 220pt; HEIGHT: 16.5pt; BORDER-TOP: #d4d0c8; BORDER-RIGHT: #d4d0c8" class=xl385 height=22 width=293>Intel_CI_City_VisitCI

<TABLE style="WIDTH: 220pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=293><COLGROUP><COL style="WIDTH: 220pt; mso-width-source: userset; mso-width-alt: 8334" width=293><TBODY><TR style="HEIGHT: 16.5pt" height=22><TD style="BORDER-BOTTOM: #d4d0c8; BORDER-LEFT: #d4d0c8; BACKGROUND-COLOR: transparent; WIDTH: 220pt; HEIGHT: 16.5pt; BORDER-TOP: #d4d0c8; BORDER-RIGHT: #d4d0c8" class=xl385 height=22 width=293>Example 2:
1x1_AMD.gif

</TD></TR></TBODY></TABLE>
Output Result:
<TABLE style="WIDTH: 220pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=293><COLGROUP><COL style="WIDTH: 220pt; mso-width-source: userset; mso-width-alt: 8334" width=293><TBODY><TR style="HEIGHT: 16.5pt" height=22><TD style="BORDER-BOTTOM: #d4d0c8; BORDER-LEFT: #d4d0c8; BACKGROUND-COLOR: transparent; WIDTH: 220pt; HEIGHT: 16.5pt; BORDER-TOP: #d4d0c8; BORDER-RIGHT: #d4d0c8" class=xl385 height=22 width=293>Text/Logo</TD></TR></TBODY></TABLE>

</TD></TR></TBODY></TABLE>
I appreciate any help that anyone can give me. Thanks!
<!-- / message -->
Your description does not match your example! You description says you want to "truncate all the text after the the 3rd underscore", however your example truncates the text after the 4th underscore. Assuming your example is wrong, this formula should do what you want...

=IF(LEN(A1)-LEN(SUBSTITUTE(A1,"_",""))>=3,LEFT(A1,FIND(CHAR(1),SUBSTITUTE(A1,"_",CHAR(1),3))-1),"Text/Logo")

If in fact your example was correct and your description wasn't, then simply change both red 3's to 4's.
 
Upvote 0
OH MY......I apologize, I miscounted! I am so glad you understood what I was trying to do anyways. It's the 4th underscore that needed to be removed.

Thank you soooooo MUCH as this formula worked! GENIUS!
 
Upvote 0

Forum statistics

Threads
1,217,881
Messages
6,139,176
Members
450,184
Latest member
Welsrot

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