VBA Extract number (from 9 to 12 characters) in string which has 200 characters

nammatdo

New Member
Joined
Oct 5, 2021
Messages
2
Office Version
  1. 2019
Platform
  1. Windows
Dear All,

I'm trying to extract number which randomly has 9 to 12 character in a string which has about 200 characters.

The number some time start with leading 0

Example 1:
I want to extract numer: "013542070"
from string:
"5. N gu’iri dgi dién theo phép luéit
HQ tén (ghi bang chfi? hoa): PHAN TO HONG NAM Giéi tinh: Nam
N gfiy sinh: 13/03/1968 Dén téc: Kinh Quéc tich:
sé giéy chl'Ing thuc Cé. nhén: 013542070
Nge‘ly cép: 17/07/2003 Noi cép: Céng an thémh phé H6 Chi Minh
Noi ding k}? dia chi thux‘mg trfi: B1-23, L6 818-1, khu p116 M37 Théi 3, Phu’c‘mg T fin
Ph1’1, Quém 7, Thanh ph6 H6 Chi Minh, Viét Nam
6."

Example 2:
I want to extract numer: "023413542070"
from string:
"5. N gu’iri dgi dién theo phép luéit
HQ tén (ghi bang chfi? hoa): PHAN TO HONG NAM Giéi tinh: Nam
N gfiy sinh: 13/03/1968 Dén téc: Kinh Quéc tich:
sé giéy chl'Ing thuc13254: 023413542070
gee‘ly cép: 17/07/2003 Noi cép: Céng an thémh phé H6 Chi Minh
Noi ding k}? dia chi thux‘mg trfi: B1-23, L6 818-1, khu p116 M37 Théi 3, Phu’c‘mg T fin
Ph1’1, Quém 7, Thanh ph6 H6 Chi Minh, Viét Nam
6."

Just an ideal if we can search and extract any number in string which greater than "1000000" (a milion) - noted: with zero number leading if any

Thank you guys so much for helping
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Welcome to the MrExcel forum!

It's not too bad if you don't need the leading 0 (formula B1), a bit tougher if you want the 0:

Book2
ABC
1"5. N gu’iri dgi dién theo phép luéit HQ tén (ghi bang chfi? hoa): PHAN TO HONG NAM Giéi tinh: Nam N gfiy sinh: 13/03/1968 Dén téc: Kinh Quéc tich: sé giéy chl'Ing thuc Cé. nhén: 013542070 Nge‘ly cép: 17/07/2003 Noi cép: Céng an thémh phé H6 Chi Minh Noi ding k}? dia chi thux‘mg trfi: B1-23, L6 818-1, khu p116 M37 Théi 3, Phu’c‘mg T fin Ph1’1, Quém 7, Thanh ph6 H6 Chi Minh, Viét Nam 6."13542070013542070
2"5. N gu’iri dgi dién theo phép luéit HQ tén (ghi bang chfi? hoa): PHAN TO HONG NAM Giéi tinh: Nam N gfiy sinh: 13/03/1968 Dén téc: Kinh Quéc tich: sé giéy chl'Ing thuc13254: 023413542070 gee‘ly cép: 17/07/2003 Noi cép: Céng an thémh phé H6 Chi Minh Noi ding k}? dia chi thux‘mg trfi: B1-23, L6 818-1, khu p116 M37 Théi 3, Phu’c‘mg T fin Ph1’1, Quém 7, Thanh ph6 H6 Chi Minh, Viét Nam 6."23413542070023413542070
Sheet6
Cell Formulas
RangeFormula
B1:B2B1=AGGREGATE(14,6,MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,1)
C1:C2C1=MID(A1,MIN(IF(IFERROR(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,-1)=AGGREGATE(14,6,MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,1),ROW(INDIRECT("1:"&LEN(A1)))*100+{9,10,11,12},""))/100,MOD(MIN(IF(IFERROR(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,-1)=AGGREGATE(14,6,MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,1),ROW(INDIRECT("1:"&LEN(A1)))*100+{9,10,11,12},"")),100))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
Solution
Welcome to the MrExcel forum!

It's not too bad if you don't need the leading 0 (formula B1), a bit tougher if you want the 0:

Book2
ABC
1"5. N gu’iri dgi dién theo phép luéit HQ tén (ghi bang chfi? hoa): PHAN TO HONG NAM Giéi tinh: Nam N gfiy sinh: 13/03/1968 Dén téc: Kinh Quéc tich: sé giéy chl'Ing thuc Cé. nhén: 013542070 Nge‘ly cép: 17/07/2003 Noi cép: Céng an thémh phé H6 Chi Minh Noi ding k}? dia chi thux‘mg trfi: B1-23, L6 818-1, khu p116 M37 Théi 3, Phu’c‘mg T fin Ph1’1, Quém 7, Thanh ph6 H6 Chi Minh, Viét Nam 6."13542070013542070
2"5. N gu’iri dgi dién theo phép luéit HQ tén (ghi bang chfi? hoa): PHAN TO HONG NAM Giéi tinh: Nam N gfiy sinh: 13/03/1968 Dén téc: Kinh Quéc tich: sé giéy chl'Ing thuc13254: 023413542070 gee‘ly cép: 17/07/2003 Noi cép: Céng an thémh phé H6 Chi Minh Noi ding k}? dia chi thux‘mg trfi: B1-23, L6 818-1, khu p116 M37 Théi 3, Phu’c‘mg T fin Ph1’1, Quém 7, Thanh ph6 H6 Chi Minh, Viét Nam 6."23413542070023413542070
Sheet6
Cell Formulas
RangeFormula
B1:B2B1=AGGREGATE(14,6,MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,1)
C1:C2C1=MID(A1,MIN(IF(IFERROR(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,-1)=AGGREGATE(14,6,MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,1),ROW(INDIRECT("1:"&LEN(A1)))*100+{9,10,11,12},""))/100,MOD(MIN(IF(IFERROR(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,-1)=AGGREGATE(14,6,MID(A1,ROW(INDIRECT("1:"&LEN(A1))),{9,10,11,12})+0,1),ROW(INDIRECT("1:"&LEN(A1)))*100+{9,10,11,12},"")),100))
Press CTRL+SHIFT+ENTER to enter array formulas.
Hello Eric W, It works perfect to me

My apology for late replying on this thread, i'm so thankful to your help
 
Upvote 0

Forum statistics

Threads
1,214,646
Messages
6,120,716
Members
448,985
Latest member
chocbudda

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
Back
Top