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>
 

Some videos you may like

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.

Michael M

Well-known Member
Joined
Oct 27, 2005
Messages
19,692
Office Version
  1. 2016
  2. 2013
  3. 2007
Platform
  1. Windows
Maybe this, I believe previously posted by Domenic


<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;;">S.NO</td><td style="font-weight: bold;;">DATA</td><td style="font-weight: bold;;">Result</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">1</td><td style=";">TATA123456KUMAR</td><td style="text-align: right;color: #222222;;">123456</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">2</td><td style=";">Venky987456MS</td><td style="text-align: right;color: #222222;;">987456</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C2</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">MID(<font color="Red">0&B2,LARGE(<font color="Green">INDEX(<font color="Purple">ISNUMBER(<font color="Teal">--MID(<font color="#FF00FF">B2,ROW(<font color="Navy">$1:$25</font>),1</font>)</font>)* ROW(<font color="Teal">$1:$25</font>),0</font>),ROW(<font color="Purple">$1:$25</font>)</font>)+1,1</font>)*10^ROW(<font color="Red">$1:$25</font>)/10</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C3</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">MID(<font color="Red">0&B3,LARGE(<font color="Green">INDEX(<font color="Purple">ISNUMBER(<font color="Teal">--MID(<font color="#FF00FF">B3,ROW(<font color="Navy">$1:$25</font>),1</font>)</font>)* ROW(<font color="Teal">$1:$25</font>),0</font>),ROW(<font color="Purple">$1:$25</font>)</font>)+1,1</font>)*10^ROW(<font color="Red">$1:$25</font>)/10</font>)</td></tr></tbody></table></td></tr></table><br />
 

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
36,674
Office Version
  1. 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,201
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)
 

Watch MrExcel Video

Forum statistics

Threads
1,122,193
Messages
5,594,774
Members
413,934
Latest member
austinb

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