SOLVED

Extract Number If Text

Copper Contributor

I have data in the first column and I want a formula that will return the number before "min" in the 2nd column and the number before "secs" in the 3rd column.

 

 MINSEC
35 secs#N/A35 
40 secs#N/A40 
1 min 5 secs1 min 5 
1 min 15 secs1 min 15 
9 Replies

Hi@anthonyc89

see atached file.

MIN =

=IFERROR(IF(SEARCH("min",A2)>0,VALUE(LEFT(A2,SEARCH("min",A2)-2))),NA())

 

SEC =

=VALUE(MID(A2,IFERROR(SEARCH("min ",A2)+4,1),2))

@dscheikey it works but if there is no "secs", its returning the "min" in the secs columns. See 2nd to the last row.

 MINSEC
35 secs#N/A35
40 secs#N/A40
1 min 5 secs15
1 min 15 secs115
30 secs#N/A30
1 min 20 secs120
1 min11
45 secs#N/A45
best response confirmed by Hans Vogelaar (MVP)
Solution

@anthonyc89 

=IFERROR(IF(SEARCH("secs",A2),VALUE(MID(A2,IFERROR(SEARCH("min ",A2)+4,1),2))),NA())

Thank you @dscheikey . This worked!

@anthonyc89  alternatively:

min:

=IFERROR(--LEFT(A2,SEARCH("min",A2)-1),"")

sec:

=IFERROR(--MID(LEFT(A2,SEARCH("sec",A2)-1),IFERROR(SEARCH("min",A2)+4,1),99),"")

@anthonyc89 FILTERXML() may a good formula in this case.

=MAX(FILTERXML("<t><s>"&SUBSTITUTE(A2," ","</s><s>")&"</s></t>","//s"))

 

Harun24HR_0-1661568196680.png

 

@dscheikey I get a "2" where 15 should read.

anthonyc89_0-1661880015285.png

 

It gives "2" because it can't find "min " (notice the space). change that to "min" instead but then you might have issues with the # characters so change the ,2 to ,3
OR try the FILTERXML formulas

@anthonyc89 

As variant, for modern Excel

=--TEXTBEFORE(A2, " min",,,,0)
=--LET( s, TEXTBEFORE(A2, " secs",,,,0), TEXTAFTER(  s, "min ",,,,s) )
1 best response

Accepted Solutions
best response confirmed by Hans Vogelaar (MVP)
Solution

@anthonyc89 

=IFERROR(IF(SEARCH("secs",A2),VALUE(MID(A2,IFERROR(SEARCH("min ",A2)+4,1),2))),NA())

View solution in original post