Extracting numeric portion of address with p.o. Box help?

samyscraps01

Board Regular
Joined
Jul 6, 2017
Messages
56
the following formula is used for extracting the numeric portion of the home address. However, how can I add onto this formula to give me the numeric portion of the p.o. box. The addresses appear on a single column but the formula leaves the po box cells blank because it's not finding a numeric portion on the left. See example.

=IF(ISERROR(VALUE(LEFT(F1,1))),"",LEFT(F1,FIND(" ",F1)-1))

100 MAPLE STREET, CALIFORNIA, 102030

P.O. BOX 10030, CALIFORNIA, 10230
 

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.
While I can think of non-standard addresses where this formula might fail, I think it will work for the most part for you...
Code:
[table="width: 500"]
[tr]
	[td]=IF(ISNUMBER(-LEFT(A1)),LEFT(A1,FIND(" ",A1)-1),IF(ISNUMBER(RIGHT(LEFT(A1,FIND(",",A1)-1))),TRIM(RIGHT(SUBSTITUTE(LEFT(A1,FIND(",",A1)-1)," ",REPT(" ",99)),99)),""))[/td]
[/tr]
[/table]
 
Upvote 0
The formula still returns a blank on the cells that have a PO Box. Otherwise it still works the same it will return 100 for 100 Maple Street. However, if it says P.O. Box or any deviation of PO P O Box, it will just give me a blank. I would like it to return the numeric portion of the PO Box only, so 10030.
 
Upvote 0
Hi,

Try this, formula copied down.


Book1
ABC
1100 MAPLE STREET, CALIFORNIA, 102030100100
2P.O. BOX 10030, CALIFORNIA, 102301003010030
Sheet346
Cell Formulas
RangeFormula
B1=LEFT(SUBSTITUTE(SUBSTITUTE(MID(A1,IFERROR(SEARCH("Box",A1)+4,1),99),","," ")," ",REPT(" ",99)),99)+0
C1=TRIM(LEFT(SUBSTITUTE(SUBSTITUTE(MID(A1,IFERROR(SEARCH("Box",A1)+4,1),99),","," ")," ",REPT(" ",99)),99))


Edit: In the rare case that you may have PO Box numbers with leading zeros, use C1 formula instead of B1 formula.
 
Last edited:
Upvote 0
The formula still returns a blank on the cells that have a PO Box. Otherwise it still works the same it will return 100 for 100 Maple Street. However, if it says P.O. Box or any deviation of PO P O Box, it will just give me a blank. I would like it to return the numeric portion of the PO Box only, so 10030.
You posted two examples which I assumed were representative of your full body of data... my formula works for your two posted examples. If you have data that is constructed differently from the two examples you posted, you cannot expect us to guess what the differences are and build solutions for them. WIth that said, post examples of data where my formula fails and I (or other volunteers here) will try to address them with a formula.
 
Upvote 0
You posted two examples which I assumed were representative of your full body of data... my formula works for your two posted examples. If you have data that is constructed differently from the two examples you posted, you cannot expect us to guess what the differences are and build solutions for them. WIth that said, post examples of data where my formula fails and I (or other volunteers here) will try to address them with a formula.

Rick, you're missing a minus...

=IF(ISNUMBER(-LEFT(A1)),LEFT(A1,FIND(" ",A1)-1),IF(ISNUMBER(-RIGHT(LEFT(A1,FIND(",",A1)-1))),TRIM(RIGHT(SUBSTITUTE(LEFT(A1,FIND(",",A1)-1)," ",REPT(" ",99)),99)),""))
 
Last edited:
Upvote 0
Rick, you're missing a minus...
Hmm! That minus sign is in the formula on my sheet. I think I know what is happening. I have a set up here where one keyboard and one mouse controls two computers (my laptop and desktop) and the two computers share the clipboard. Sometimes (and I am not sure when or why), the clipboard does not get updated. I remember copying the formula, then testing and realizing it needed that minus sign... I went back and put it in and then copied the formula into my response. It looks like the clipboard did not get updated with the new copy of the formula. This "missing" text problem has happened before and I am guessing what I just described was at the heart of those omissions as well. I will have to try to remember to watch what I copy/paste to make sure the correct copy of what I want to post actually gets posted. In any event, thanks for noticing that omission.
 
Upvote 0

Forum statistics

Threads
1,214,559
Messages
6,120,203
Members
448,951
Latest member
jennlynn

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