Extracting numbers from cell

tricky81

New Member
Joined
Oct 15, 2007
Messages
26
600120 Steve Hall
Stteph Day 600985
607776 Karen Jones
uk 600779 O'Neale

If I have a list similar to the above in a column. Is possible to extract just the 60*** numbers from the list and have them in the next column?

Many thanks in advance.
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
hi

Assuming those values in A1 downwards try:

=LOOKUP(100^100,--MID(A1,MIN(FIND({1,2,3,4,5,6,7,8,9,0},A1&1234567890)),ROW(INDIRECT("1:"&LEN(A1)))))

It will extract the first string of numbers in the cell (not retsricted to those beginning 60) so may not do exactly what you want.
 

HarryS

Board Regular
Joined
May 2, 2008
Messages
202
From your example you are looking for 60**** type numbers


try something like this

ColFrom = 4 ' what it is
rowSt= 3 ' start row then looped

while cells(colfrom,rowst)<>""
p=instr(cells(colfrom,rowst),"60")
if p >0 then
cells(colfrom+1,rowst)=mid(cells(colfrom,rowst),p,6)
' adjust the 6 for size of numbers
end if
rowst=rowst+1
wend
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Here's an updated one:

=IF(ISNUMBER(FIND(" 60"," "&A1)),MID(" "&A1,FIND(" 60"," "&A1),FIND(" ",A1&" ",FIND(" 60"," "&A1)+3)-FIND(" 60"," "&A1)+1),"")

restricts results to 60 numbers. Does presume there is always a space following the end of the 60 number (or the end of the string) and also always a space before the 60 number (or the start of the string).
 

Jon von der Heyden

MrExcel MVP, Moderator
Joined
Apr 6, 2004
Messages
10,808
Office Version
  1. 365
Platform
  1. Windows
=LOOKUP(100^100,--MID(A1,MIN(FIND({1,2,3,4,5,6,7,8,9,0},A1&1234567890)),ROW(INDIRECT("1:"&LEN(A1)))))

The mind boggles with the stuff you come up with Rich! (y)
You da man!
 

Watch MrExcel Video

Forum statistics

Threads
1,129,549
Messages
5,636,959
Members
416,952
Latest member
prakashkumar

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
Top