+ Reply to Thread
Results 1 to 6 of 6

Adding Canadian Postal Codes to Excel 07

  1. #1
    Registered User
    Join Date
    05-21-2009
    Location
    Alberta, Canada
    MS-Off Ver
    Excel 2007
    Posts
    5

    Adding Canadian Postal Codes to Excel 07

    Hi, I searched the FAQ's and have spent considerable time searching online. It there a way to get cells to only accept different postal code formats?

    Canada is letter number letter space number letter number, ie: A2B 3E4 the letter should be only put in in caps. Any help would be appreciated.

    Thanks

  2. #2
    Forum Expert teylyn's Avatar
    Join Date
    10-28-2008
    Location
    New Zealand
    MS-Off Ver
    Excel 365 Insider Fast
    Posts
    11,372

    Re: Adding Canadian Postal Codes to Excel 07

    Hi,

    it's not pretty, but it can be done with data validation. You basically need to check if

    1. the string entered is exactly 7 characters
    =LEN(A1)=7
    2. the leftmost character is an upper case character, which is a code between 65 ("A") and 90 ("Z")
    =AND(CODE(LEFT(A2,1))>=65,CODE(LEFT(A2,1))<=90)
    3. the second character is a number
    =ISNUMBER(VALUE(MID(A1,2,1)))
    4. the third character is an upper case character
    =AND(CODE(MID(A1,3,1))>=65,CODE(MID(A1,3,1))<=90)
    5. the fourth character is a blank, i.e. Code is 32
    =CODE(MID(A1,4,1))=32
    6. the fifth character is a number
    =ISNUMBER(VALUE(MID(A1,5,1)))
    7. the sixth character is an upper case character
    =AND(CODE(MID(A1,6,1))>=65,CODE(MID(A1,6,1))<=90)
    8. the seventh character is a number
    =ISNUMBER(VALUE(MID(A1,7,1)))

    Putting it all together into one formula makes:

    Please Login or Register  to view this content.
    (As I said, it's not pretty) :-)

    This is the formula we would need to use for data validation. Unfortunately, it is more than 255 characters long, so Excel 2003 won't accept it. So we have to shorten it a bit. Instead of validating each number in the above, we try and hit three numbers in one go, adding them up and checking if the result is a number. If not, one of the characters must be invalid. If it is a number, then all three characters must be numbers, too.

    =ISNUMBER(VALUE(MID(A1,2,1))+VALUE(MID(A1,5,1))+VALUE(MID(A1,7,1)))

    After replacing the ISNUMBER bits with the new version, the formula looks like this:

    Please Login or Register  to view this content.
    Now, copy this formula from this forum, then go and click cell A1 in your spreadsheet.

    Click Data - Validation
    Select Custom, click the formula box and paste the formula. Click the other tabs to enter helpful messages for your user. Click OK.

    Now you can test it in cell A1. If it behaves the way you want it, copy A1, then Paste Special - Validation onto all cells where you want this check applied.

    hth

  3. #3
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Adding Canadian Postal Codes to Excel 07

    How about using Data|Validation >> Custom formula:

    Please Login or Register  to view this content.
    Assuming you are validating cell A1.
    Last edited by NBVC; 05-21-2009 at 10:23 PM. Reason: Added Space allowance
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  4. #4
    Forum Expert teylyn's Avatar
    Join Date
    10-28-2008
    Location
    New Zealand
    MS-Off Ver
    Excel 365 Insider Fast
    Posts
    11,372

    Re: Adding Canadian Postal Codes to Excel 07

    @NBVC: much more elegant. Never used Exact before. Must keep in mind! thanks for that

  5. #5
    Registered User
    Join Date
    05-21-2009
    Location
    Alberta, Canada
    MS-Off Ver
    Excel 2007
    Posts
    5

    Re: Adding Canadian Postal Codes to Excel 07

    Thanks for your help. I am using Excel 2007, would the first one be best (the long one) of the one in the second post, the "exact" formula?

    Thanks again.

    Doug

  6. #6
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Adding Canadian Postal Codes to Excel 07

    They should both work in XL2007.. the 2nd is shorter and uses less manipulations...

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1