How to break zipcodes fileds with leading zeros

  • CREATE TABLE #ZIPS (ZIP Varchar(5))

    INSERT INTO #ZIPs Values ('09876')

    INSERT INTO #ZIPs Values ('34876')

    INSERT INTO #ZIPs Values ('09446')

    INSERT INTO #ZIPs Values ('02376')

    INSERT INTO #ZIPs Values ('49876')

    INSERT INTO #ZIPs Values ('29876')

    INSERT INTO #ZIPs Values ('69876')

    INSERT INTO #ZIPs Values ('79876')

    INSERT INTO #ZIPs Values ('99976')

    INSERT INTO #ZIPs Values ('00076')

    INSERT INTO #ZIPs Values ('59006')

    INSERT INTO #ZIPs Values ('70076')

    INSERT INTO #ZIPs Values ('89006')

    INSERT INTO #ZIPs Values ('10876')

    INSERT INTO #ZIPs Values ('10076')

    How to make this slabs for example

    Anything between 00000 to 10000 THEN 1

    Anything between 10000 to 20000 THEN 2

    Anything between 20000 to 30000 THEN 3

    so on

    Can you please help me other than this way below

    SELECT CASE WHEN zip< '10000' THEN 1

    WHEN ZIp<'20000' THEN 2

    ...

    ....

    ...

    WHEN ZIP < '90000' THEN 0

    END

    FROM #ZIPs

    Thanks

    ASita

  • Why doesn't the CASE work for you?

  • I would like to see if any other alternatives were there. other than Case.. Please

     

    Thank you

  • asita wrote:

    I would like to see if any other alternatives were there. other than Case.. Please

    Thank you

    Heh... more likely, it's probably an interview question. 😉  It's a good one, IMHO, as well.

    I think the last value in your case for <90000 is incorrect but I get the gist of what you're trying to do.

    Here's an alternative to such things using just basic integer math. EDIT: There's more than one way...  There may be additional methods but these are two of the obvious ways.

     SELECT *
    ,Slab1 = (ZIP/10000+1)%10
    ,Slab2 = (LEFT(ZIP,1)+1)%10
    FROM #ZIPS
    ;

    And thank you for posting the readily consumable test data! 🙂

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • I'm unsure what value a leading '9' should yield as the slab#, it's not really clear from your OP.

    SELECT 
    LEFT(ZIP, 1) + CASE WHEN SUBSTRING(ZIP, 2, 4) = '0000' THEN 0 ELSE 1 END AS slab#,
    ZIP
    FROM #ZIPS

    Edit: If leading '9' should yield a '0' result, then:

    SELECT 
    (LEFT(ZIP, 1) + CASE WHEN SUBSTRING(ZIP, 2, 4) = '0000' THEN 0 ELSE 1 END) % 10 AS slab#,
    ZIP
    FROM #ZIPS

    • This reply was modified 2 years, 10 months ago by  ScottPletcher.

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • Create a table with the zip code ranges - then use an outer/cross apply to lookup the range.  Or use a CTE to create a table with the range and a join using BETWEEN to pull the specific row from the range.

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

  • Or...

     Select *
    , ZipRange = (z.ZIP / 10000) + 1
    From #ZIPs z;

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

  • I like the cross apply, but not sure it's needed here.

    Going back to the original, asita, is the goal to bucket rows for a report of some sort? what's the reasoning behind breaking up zip codes?

    In some sense, the LEFT() approach from Scott is one I like a lot, perhaps as a computed column for quick reporting.

  • Steve Jones - SSC Editor wrote:

    I like the cross apply, but not sure it's needed here.

    Going back to the original, asita, is the goal to bucket rows for a report of some sort? what's the reasoning behind breaking up zip codes?

    In some sense, the LEFT() approach from Scott is one I like a lot, perhaps as a computed column for quick reporting.

    Just throwing out ideas - which it seemed the OP wanted.

    The table lookup would be a better option if there are more columns that you would want available.  For example, if you wanted an SlabID, SlabName, SlabMnemonic, SlabDescription - and other information about that slab.  For any type of table lookup you can use BETWEEN in the join if you have a start/end range - or apply with top 1 if you only have the start of the range.

    If you are only using US zip codes - and the first 5 digits - then you should not have any issues using divide by 10000 (I don't think there are any US zip codes with letters).

    FWIW - any time I see someone looking to code categories like this I would recommend building a table to manage the categories.  At some point, someone will want to change the categories and then you would need to modify it in multiple areas.

     

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

  • Thank you for your inputs I apologize for my mistake in my sample the last case statement is 9. not 0.

     

    Thank you for all your assistance and guidance

  • Thank you Jeffery,

     

    Can you please give one sample with couple records. much helpful. with the join and CTE..

     

    Thank you

    Asiti

  • According to your sample data and results, the "Answer" you marked is not correct.  For example, you stated that '10000' should return a 1 -- "Anything between 00000 to 10000 THEN 1" -- but that code returns a 2.

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • ScottPletcher wrote:

    According to your sample data and results, the "Answer" you marked is not correct.  For example, you stated that '10000' should return a 1 -- "Anything between 00000 to 10000 THEN 1" -- but that code returns a 2.

    I assumed that the OP actually wants categories for 00000 thru 09999, 10000 through 19999 - which makes more sense than including 10000 in category 1, 20000 in category 2, etc.

    With that said - I still would recommend building a category table instead of calculating the value.

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

  • asita wrote:

    Thank you Jeffery,

    Can you please give one sample with couple records. much helpful. with the join and CTE..

    Thank you

    Asiti

    First - you need a table of categories - with a start/end of range.  Then it is simple:

    Select *
    From Zips z
    Inner Join SlabRange sr On z.Zip Between sr.SlabStart And sr.SlabEnd;

     

     

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

  • asita wrote:

    Thank you for your inputs I apologize for my mistake in my sample the last case statement is 9. not 0.

    Thank you for all your assistance and guidance

    Ok... that does not match what your other case statements imply.

    Your other case statements imply the following...

    1. Anything that starts with a 0 (00000-09999 or < 10000) should be "slabbed" as a "1"
    2. Anything that starts with a 1 (10000-19999 or < 20000) should be "slabbed" as a "2"
    3. Anything that starts with a 2(20000-29999 or < 30000) should be "slabbed" as a "3"
    4. As you say... "etc, etc".

    You DO NOT NEED A RANGE TABLE FOR THIS.

    [EDIT]  Just to clarify that line above, you don't need a table to do this simple calculation.  However (as I admit to on the second page of this post), Jeffrey Williams IS CORRECT about needing a table for this.  I go into it a bit more in detail later in my apology to him BUT the table IS needed for "Documentation Purposes to Explain and Estoteric Value" and, even if the meaning were totally obvious, the table is needed for purposes of DRI.

    What you need is to correctly identify what you want to do with the ranges of zip codes, which are mathematical in nature, and then just assign it with a single mathematical formula (like I did on my original post on this thread), which will ALWAYS be faster than a JOIN for a lookup. (see EDIT above)

    We just need to know what the actual "gazintas" are to solve this problem. 😉

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 15 posts - 1 through 15 (of 31 total)

You must be logged in to reply to this topic. Login to reply