I need Only Numeric data from TEXT

TATAPRATAPKUMAR

New Member
Joined
Dec 22, 2016
Messages
3
Hi All,

please help me to provide formula for below.for example


S.NO DATAResult
1TATA123456KUMAR123456
2Venky987456MS987456

<tbody>
</tbody><colgroup><col><col><col></colgroup>
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).

Michael M

Well-known Member
Joined
Oct 27, 2005
Messages
21,274
Office Version
  1. 365
  2. 2007
Platform
  1. Windows
Maybe this, I believe previously posted by Domenic



Excel 2007
ABC
1S.NODATAResult
21TATA123456KUMAR123456
32Venky987456MS987456
Sheet1
Cell Formulas
RangeFormula
C2=SUMPRODUCT(MID(0&B2,LARGE(INDEX(ISNUMBER(--MID(B2,ROW($1:$25),1))* ROW($1:$25),0),ROW($1:$25))+1,1)*10^ROW($1:$25)/10)
C3=SUMPRODUCT(MID(0&B3,LARGE(INDEX(ISNUMBER(--MID(B3,ROW($1:$25),1))* ROW($1:$25),0),ROW($1:$25))+1,1)*10^ROW($1:$25)/10)
 

FDibbins

Well-known Member
Joined
Feb 16, 2013
Messages
6,723
Here is another option...
=LOOKUP(99^99,--("0"&MID(A1,MIN(SEARCH({0,1,2,3,4,5,6,7,8,9},A1&"0123456789")),ROW($1:$10000)))) Courtesy of:*Ron Coderre
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
37,866
Office Version
  1. 2019
  2. 2010
Platform
  1. Windows
Hi All,

please help me to provide formula for below.for example


S.NO DATAResult
1TATA123456KUMAR123456
2Venky987456MS987456

<tbody>
</tbody><colgroup><col><col><col></colgroup>

Will your numbers always be six digits long as your two examples show? If so, you can use this formula...

=MID(A1,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A1&"0123456789")),6)
 
Last edited:

Gravitas

Board Regular
Joined
Dec 19, 2016
Messages
52
Here A1 is an alphanumeric string: eg 9128ABC37DEF465

This ARRAY FORMULA, committed with CTRL+SHIFT+ENTER
(instead of just ENTER) returns ONLY the numbers:
Code:
B1: =SUM(MID(A1,LARGE(ISNUMBER(--MID(A1,ROW($1:$25),1))*
ROW($1:$25),ROW($A$1:INDEX($A:$A,COUNT(--MID(A1,ROW($1:$25),1))))),1)*
10^(ROW(INDEX($1:$25,COUNT(--MID(A1,ROW(INDEX($1:$25,1,1):
INDEX($1:$25,LEN(A1),1)),1)),1):INDEX($1:$25,1,1))-1))

In the above example, the formula returns: 912837465

That formula works for text up to 25 characters long.
Hope it helps :)
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,210
Well, using original bits...

=LOOKUP(9.99999999999999E+307,MID(B2,MIN(SEARCH({0,1,2,3,4,5,6,7,8,9},B2&"0123456789")),ROW(INDIRECT("1:"&LEN("0"&B2))))+0)
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,163,545
Messages
5,832,387
Members
430,129
Latest member
EmilyCrandall

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