Truncating text based on various punctuations

kpieper876

New Member
Joined
Aug 12, 2011
Messages
13
I have the following in cell A1:

optimized-by.rubiconproject.com/a/8191/13252

I need to remove everything from the left of the second decimal from the right:

=IF(LEN(A1)-LEN(SUBSTITUTE(A1,".",""))<2,A1,RIGHT(A1,LEN(A1)-FIND(CHAR(1),SUBSTITUTE(A1,".",CHAR(1),LEN(A1)-LEN(SUBSTITUTE(A1,".",""))-1))))

results in this:
rubiconproject.com/a/8191/13252

Now I need to remove everything after the first "/" including the "/":
=IF(FIND("/",A1)>0,LEFT(A9,FIND("/",A1)-1))

Problem is, I want to combine these two formulas into one. AND the second formula looking for the backslash needs to happen AFTER the first formula AND there may not always be a "/" to truncate from.

Thanks for your help.
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
If your version of excel is Excel 2007 or later then this mega formula, with 52 refs to cell A1 might do it:
Code:
=IF(ISERR(FIND("/",MID(IF((LEN(A1)-LEN(SUBSTITUTE(A1,".","")))<2,A1,SUBSTITUTE(A1,".","¬",(LEN(A1)-LEN(SUBSTITUTE(A1,".","")))-1)),FIND("¬",IF((LEN(A1)-LEN(SUBSTITUTE(A1,".","")))<2,A1,SUBSTITUTE(A1,".","¬",(LEN(A1)-LEN(SUBSTITUTE(A1,".","")))-1)))+1,LEN(A1)))),MID(IF((LEN(A1)-LEN(SUBSTITUTE(A1,".","")))<2,A1,SUBSTITUTE(A1,".","¬",(LEN(A1)-LEN(SUBSTITUTE(A1,".","")))-1)),FIND("¬",IF((LEN(A1)-LEN(SUBSTITUTE(A1,".","")))<2,A1,SUBSTITUTE(A1,".","¬",(LEN(A1)-LEN(SUBSTITUTE(A1,".","")))-1)))+1,LEN(A1)),LEFT(MID(IF((LEN(A1)-LEN(SUBSTITUTE(A1,".","")))<2,A1,SUBSTITUTE(A1,".","¬",(LEN(A1)-LEN(SUBSTITUTE(A1,".","")))-1)),FIND("¬",IF((LEN(A1)-LEN(SUBSTITUTE(A1,".","")))<2,A1,SUBSTITUTE(A1,".","¬",(LEN(A1)-LEN(SUBSTITUTE(A1,".","")))-1)))+1,LEN(A1)),FIND("/",MID(IF((LEN(A1)-LEN(SUBSTITUTE(A1,".","")))<2,A1,SUBSTITUTE(A1,".","¬",(LEN(A1)-LEN(SUBSTITUTE(A1,".","")))-1)),FIND("¬",IF((LEN(A1)-LEN(SUBSTITUTE(A1,".","")))<2,A1,SUBSTITUTE(A1,".","¬",(LEN(A1)-LEN(SUBSTITUTE(A1,".","")))-1)))+1,LEN(A1)))-1))

But using helper columns should reduce the strain, or make a user defined function (macro/vba).
 
Upvote 0
Maybe this:

<b>Excel 2007</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=";">test1.com//345</td><td style=";">test1.com</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">test2.com//dddd</td><td style=";">test2.com</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">test4.test3.com/ccc</td><td style=";">test3.com</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">optimized-by.rubiconproject.com/a/8191/13252</td><td style=";">rubiconproject.com</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">optimized.-by.rubiconproject.com/a/8191/13252</td><td style=";">rubiconproject.com</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">test.test5.com</td><td style=";">test5.com</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">test6.com</td><td style=";">test6.com</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet2</p><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">ISNUMBER(<font color="Red">FIND(<font color="Green">"/",A1</font>)</font>),
SUBSTITUTE(<font color="Red">IF(<font color="Green">LEN(<font color="Purple">A1</font>)-LEN(<font color="Purple">SUBSTITUTE(<font color="Teal">A1,".",""</font>)</font>)-1,MID(<font color="Purple">A1,FIND(<font color="Teal">CHAR(<font color="#FF00FF">10</font>),SUBSTITUTE(<font color="#FF00FF">A1,".",CHAR(<font color="Navy">10</font>),E1</font>)</font>)+1,1000</font>),A1</font>),RIGHT(<font color="Green">A1,LEN(<font color="Purple">A1</font>)-FIND(<font color="Purple">"/",A1</font>)+1</font>),""</font>),
IF(<font color="Red">LEN(<font color="Green">A1</font>)-LEN(<font color="Green">SUBSTITUTE(<font color="Purple">A1,".",""</font>)</font>)-1,MID(<font color="Green">A1,FIND(<font color="Purple">CHAR(<font color="Teal">10</font>),SUBSTITUTE(<font color="Teal">A1,".",CHAR(<font color="#FF00FF">10</font>),E1</font>)</font>)+1,1000</font>),A1</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
Markmzz
 
Upvote 0
Markmzz - Great sample data set. your formula didn't work though...only on rows 1, 2, 7. Also, what is the reference to column e?

P45cal - ironically, your formula works on only rows 1, 2, and 7 in markmzz sample data set.
 
Upvote 0
This one works for all of them except row 5:

Code:
=IF(LEN(MID(A1,FIND(".",A1)+1,IFERROR(FIND("/",A1),LEN(A1)+1)-FIND(".",A1)-1))=3,
IFERROR(LEFT(A1,FIND("/",A1)-1),A1),
MID(A1,FIND(".",A1)+1,IFERROR(FIND("/",A1),LEN(A1)+1)-FIND(".",A1)-1))

I am thinking that a UDF may be a better approach if you are going to have varying numbers of periods and backslashes.

AMAS
 
Upvote 0
Unfortunately, I am not a VBA person.

OK. User Defined Function coming up. Use in the spreadsheet cell thus:
=LeaveDomain(A55)

Paste this into a standard code module:
Code:
Function LeaveDomain(TheURL)
LeaveDomain = Mid(TheURL, InStrRev(TheURL, ".", InStrRev(TheURL, ".") - 1) + 1)
x = InStr(LeaveDomain, "/")
If x > 0 Then LeaveDomain = Left(LeaveDomain, x - 1)
End Function

Excel Workbook
AB
55test1.com//345test1.com
56test2.com//ddddtest2.com
57test4.test3.com/ccctest3.com
58optimized-by.rubiconproject.com/a/8191/13252rubiconproject.com
59optimized.-by.rubiconproject.com/a/8191/13252rubiconproject.com
60test.test5.comtest5.com
61test6.comtest6.com
Sheet13
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,364
Messages
6,124,510
Members
449,166
Latest member
hokjock

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