![]() |
Extrapolate numeric values from text string
Hi,
I need to extrapolate the numeric values from a list of text strings. However, the numeric portion of each string is not consistent from observation to observation. Does anyone have any idea about how to do this in excel. I.e. one observation might be NHY939591C the numeric portion is 939591 PW086877B numeric portion is 086877 AB087623 numeric portion is 087623 Your ideas are much appreciated. Thanks, Henrik |
Extrapolate numeric values from text string
Hello Henrik,
Here is a UDF (user defined function) that does what you want If you are not familiar with UDFs, email me at my private email not the group Function t2n(textin) For j = 1 To Len(textin) mychar = Mid(textin, j, 1) If IsNumeric(mychar) Then temp = temp * 10 + mychar 'Debug.Print mychar, temp Next j t2n = temp End Function -- Bernard V Liengme www.stfx.ca/people/bliengme remove caps from email "Henrik" wrote in message ... Hi, I need to extrapolate the numeric values from a list of text strings. However, the numeric portion of each string is not consistent from observation to observation. Does anyone have any idea about how to do this in excel. I.e. one observation might be NHY939591C the numeric portion is 939591 PW086877B numeric portion is 086877 AB087623 numeric portion is 087623 Your ideas are much appreciated. Thanks, Henrik |
Extrapolate numeric values from text string
Henrik wrote...
I need to extrapolate the numeric values from a list of text strings. However, the numeric portion of each string is not consistent from observation to observation. Does anyone have any idea about how to do this in excel. .... AB087623 numeric portion is 087623 You could do this with array formulas, specifically, =LOOKUP(2,1/MID(x,MIN(FIND({0,1,2,3,4,5,6,7,8,9},x&"0123456789 ")), ROW(INDIRECT("1:"&LEN(x)))),MID(x,MIN(FIND({0,1,2, 3,4,5,6,7,8,9}, x&"0123456789")),ROW(INDIRECT("1:"&LEN(x))))) If you need to do this often, then I'd recommend that you download and install Laurent Longre's MOREFUNC.XLL add-in from http://xcell05.free.fr/english/ and use the REGEX.MID function it provides, e.g., =REGEX.MID(x,"\d+",1) |
Extrapolate numeric values from text string
How can I test for a numeric value in the first position of a text string?
"Harlan Grove" wrote: Henrik wrote... I need to extrapolate the numeric values from a list of text strings. However, the numeric portion of each string is not consistent from observation to observation. Does anyone have any idea about how to do this in excel. .... AB087623 numeric portion is 087623 You could do this with array formulas, specifically, =LOOKUP(2,1/MID(x,MIN(FIND({0,1,2,3,4,5,6,7,8,9},x&"0123456789 ")), ROW(INDIRECT("1:"&LEN(x)))),MID(x,MIN(FIND({0,1,2, 3,4,5,6,7,8,9}, x&"0123456789")),ROW(INDIRECT("1:"&LEN(x))))) If you need to do this often, then I'd recommend that you download and install Laurent Longre's MOREFUNC.XLL add-in from http://xcell05.free.fr/english/ and use the REGEX.MID function it provides, e.g., =REGEX.MID(x,"\d+",1) |
Extrapolate numeric values from text string
MarcusA wrote...
How can I test for a numeric value in the first position of a text string? If you mean a decimal numeral as first character, try =COUNT(-LEFT(string,1)) The negative sign just before LEFT is intentional. |
All times are GMT +1. The time now is 08:10 PM. |
Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com