Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Henrik
 
Posts: n/a
Default 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
  #2   Report Post  
Bernard Liengme
 
Posts: n/a
Default 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



  #3   Report Post  
Harlan Grove
 
Posts: n/a
Default 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)

  #4   Report Post  
MarcusA
 
Posts: n/a
Default 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)


  #5   Report Post  
Harlan Grove
 
Posts: n/a
Default 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.

Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
can you find specific text in a string ignoring any other text chriscp Excel Discussion (Misc queries) 1 September 18th 05 09:54 PM
Equation in text string? hoising8 Excel Discussion (Misc queries) 3 July 28th 05 08:23 PM
dynamic cell reference within a text string gvm Excel Worksheet Functions 4 July 25th 05 02:40 AM
How do I LOOKUP text values Amber C-W Excel Worksheet Functions 4 July 20th 05 05:27 PM
Finding Specific Text in a Text String Peter Gundrum Excel Worksheet Functions 9 April 10th 05 07:21 PM


All times are GMT +1. The time now is 09:03 PM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
Copyright ©2004-2024 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"