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

samyscraps01

Board Regular
Joined
Jul 6, 2017
Messages
52
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
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
35,508
Office Version
2010
Platform
Windows
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]
 

samyscraps01

Board Regular
Joined
Jul 6, 2017
Messages
52
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.
 

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
5,146
Hi,

Try this, formula copied down.

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style=";">100 MAPLE STREET, CALIFORNIA, 102030</td><td style="text-align: right;;">100</td><td style="text-align: right;;">100</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">P.O. BOX 10030, CALIFORNIA, 10230</td><td style="text-align: right;;">10030</td><td style="text-align: right;;">10030</td></tr></tbody></table><p style="width:6.4em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet346</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><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: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><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: rgb(218,231,245);color: rgb(22,17,32)">B1</th><td style="text-align:left">=LEFT(<font color="Blue">SUBSTITUTE(<font color="Red">SUBSTITUTE(<font color="Green">MID(<font color="Purple">A1,IFERROR(<font color="Teal">SEARCH(<font color="#FF00FF">"Box",A1</font>)+4,1</font>),99</font>),","," "</font>)," ",REPT(<font color="Green">" ",99</font>)</font>),99</font>)+0</td></tr><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">C1</th><td style="text-align:left">=TRIM(<font color="Blue">LEFT(<font color="Red">SUBSTITUTE(<font color="Green">SUBSTITUTE(<font color="Purple">MID(<font color="Teal">A1,IFERROR(<font color="#FF00FF">SEARCH(<font color="Navy">"Box",A1</font>)+4,1</font>),99</font>),","," "</font>)," ",REPT(<font color="Purple">" ",99</font>)</font>),99</font>)</font>)</td></tr></tbody></table></td></tr></table><br />

Edit: In the rare case that you may have PO Box numbers with leading zeros, use C1 formula instead of B1 formula.
 
Last edited:

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
35,508
Office Version
2010
Platform
Windows
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.
 

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
5,146
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:

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
35,508
Office Version
2010
Platform
Windows
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.
 

Forum statistics

Threads
1,082,309
Messages
5,364,420
Members
400,801
Latest member
julievandermeulen

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top