Get the last 4 digits from a column

meloh

New Member
Joined
Aug 27, 2014
Messages
4
Hi

I need some help!

c/oMariann Sveinsvoll, Fagerheim 14 4322 SANDNES
Hvamveien 6, Postboks 100, 2026 SKJETTEN
Oksenøyveien 16, 1366 LYSAKER
Postboks 176, 4098 TANANGER
Verksgaten 3/5, 4013 STAVANGER
Postboks 14, 1305 HASLUM
Gamle Åslandsvegen 8, 4355 KVERNALAND


I want to get the bold digits in a column and the blue text in another column. Its fine if I have to do it with two different commands.
 

Excel Facts

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.
Welcome to the forum!

Here is one potential way:

Excel Workbook
ABC
1c/oMariann Sveinsvoll, Fagerheim 14 4322 SANDNESc/oMariann Sveinsvoll, Fagerheim 144322
2Hvamveien 6, Postboks 100, 2026 SKJETTENHvamveien 6, Postboks 100,2026
3Oksenyveien 16, 1366 LYSAKEROksenyveien 16,1366
4Postboks 176, 4098 TANANGERPostboks 176,4098
5Verksgaten 3/5, 4013 STAVANGERVerksgaten 3/5,4013
6Postboks 14, 1305 HASLUMPostboks 14,1305
7Gamle slandsvegen 8, 4355 KVERNALANDGamle slandsvegen 8,4355
Sheet2
 
Upvote 0
Is that number always 4 digits?

Try

Find the 4 digit number
Long String in A1
Formula in B1
=MID(A1,FIND("^",SUBSTITUTE(A1," ","^",LEN(A1)-LEN(SUBSTITUTE(A1," ",""))-1))+1,4)

Get the text prior to the 4 digit number (using the cell with the other formula.. B1)
Formula in C1
=LEFT(A1,FIND(B1,A1)-2)
 
Upvote 0
Thank you for the replies.

Can't seem to get any of these to work. FYI im using excel 2010.

FormR:
=left(A1;find("~";SUBSTITUTE(A1;" ";"~";lenA1)-LEN(SUBSTITUTE(A1;" ";1;""))-1))-1)
I think I replaced all the , with ; correctly, but I got an error with LEN(SUBSTITUTE(A1;" ";1;"") where it said I had to add a number of characters. I just added 1, but im only getting #VALUE as a result


Jonmo1:
=MID(A1;FIND("^";SUBSTITUTE(A1;" ";"^";LEN(A1)-LEN(SUBSTITUTE(A1;" ";999;""))-1))+1;4) where it said I had to add a number of characters. I just added 999, but im only getting #NAME as a result
 
Upvote 0
c/oMariann Sveinsvoll, Fagerheim 14 4322 SANDNES
Hvamveien 6, Postboks 100, 2026 SKJETTEN
Oksenøyveien 16, 1366 LYSAKER
Postboks 176, 4098 TANANGER
Verksgaten 3/5, 4013 STAVANGER
Postboks 14, 1305 HASLUM
Gamle Åslandsvegen 8, 4355 KVERNALAND

I want to get the bold digits in a column and the blue text in another column. Its fine if I have to do it with two different commands.

Is there ALWAYS one single "word" after the 4-digit number you want to retrieve (as all your examples show)? If yes, then this formula will return the number as TEXT (thus preserving leading zeroes if there ever are any)...

=TRIM(LEFT(RIGHT(SUBSTITUTE(" "&A1," ",REPT(" ",1000)),2000),1000))

Adding zero to the formula will convert "text number" into a real number (but leading zeroes, if any, will then be lost)...

=0+TRIM(LEFT(RIGHT(SUBSTITUTE(" "&A1," ",REPT(" ",1000)),2000),1000))
 
Upvote 0
So for 2010 excel(maybe its because its the scandinavian version I have to change , into; ) it should be like this =TRIM(LEFT(RIGHT(SUBSTITUTE(" "&A1;" ";REPT(" ";1000));2000);1000))

I've tried that, but I'm getting an error "
not enough arguments were entered," Seems I gotta add a value (" ";1000));2000);1000)) here somewhere.
 
Last edited:
Upvote 0
So for 2010 excel it should be like this =TRIM(LEFT(RIGHT(SUBSTITUTE(" "&A1;" ";REPT(" ";1000));2000);1000))

I've tried that, but I'm getting an error "
not enough arguments were entered," Seems I gotta add a value (" ";1000));2000);1000)) here somewhere.

I am not familiar with all the peculiarities (if any) of converting a comma delimited formula to a semi-colon formula as required by your locale, so I cannot help you with that part of your requirement; however, I can tell you that I tested the formula on my comma delimited formula system before posting it and it worked fine for me here.
 
Upvote 0
Another option (no comma at the end):


In B1:

=IF(RIGHT(REPLACE(A1;FIND(C1;A1)-1;255;"");1)=",";REPLACE(A1;FIND(C1;A1)-2;255;"");REPLACE(A1;FIND(C1;A1)-1;255;""))

In C1:

=TRIM(LEFT(RIGHT(SUBSTITUTE(SUBSTITUTE(A1;CHAR(160);" ");" ";REPT(" ";99));198);99))
Excel Workbook
ABC
1c/oMariann Sveinsvoll, Fagerheim 14 4322 SANDNESc/oMariann Sveinsvoll, Fagerheim 144322
2Hvamveien 6, Postboks 100, 2026 SKJETTENHvamveien 6, Postboks 1002026
3Oksenoyveien 16, 1366 LYSAKEROksenoyveien 161366
4Postboks 176, 4098 TANANGERPostboks 1764098
5Verksgaten 3/5, 4013 STAVANGERVerksgaten 3/54013
6Postboks 14, 1305 HASLUMPostboks 141305
7Gamle Aslandsvegen 8, 4355 KVERNALANDGamle Aslandsvegen 84355
Sheet
 
Upvote 0

Forum statistics

Threads
1,226,287
Messages
6,190,069
Members
453,593
Latest member
Mubashar Ali

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