Reply
blocke
Frequent Visitor

Leading zeroes in zip codes

I am trying to use zip codes to make a heat map but when I import the data from excel, the zeroes infront of certain zip codes are removed. I have tried formatting the zip column as text as suggested in other posts. Are there any other work arounds that I could try?

 

Thanks

1 ACCEPTED SOLUTION
avatar user
Anonymous
Not applicable

Hey @blocke

 

You can create a calculated column to insert the leading 0's back in. So let's say that you have three zip codes (76342, 08976, and 00323). One has no leading 0's, one has 1, and one has 2. Based on what I'm gathering, when you import them in you are seeing 76342, 8976, 323. You can then create a calculated column to append necessary 0's on front depending on the size of the number like this:

 

RealZipCode = 
SWITCH(
    TRUE(),
    LEN('Table'[ZipCode]) = 5, 'Table'[ZipCode],
    LEN('Table'[ZipCode]) = 4, "0" & 'Table'[ZipCode],
    LEN('Table'[ZipCode]) = 3, "00" & 'Table'[ZipCode]
)

You end up with output that looks like:

 

ZipCode.PNG

 

Hope this helps,

Parker

View solution in original post

6 REPLIES 6
Hollys83
Frequent Visitor

None of the solutions worked for me but adding a prefix did. 

avatar user
Anonymous
Not applicable

You can also use this:

= Text.PadStart([Zip],5,"0")
RMGAM
Regular Visitor

=Text.PadStart([ZipCode], 5, "0")

avatar user
Anonymous
Not applicable

I know that this was marked as solved, but I also had this issue and fixed it by changing the table column data type definition in Power BI's query editor from int64 to text.

 

Example:  = Table.TransformColumnTypes(Table1_Table,{{"Zip Code", type text}, {"City", type text}, {"County", type text}})

avatar user
Anonymous
Not applicable

Hey @blocke

 

You can create a calculated column to insert the leading 0's back in. So let's say that you have three zip codes (76342, 08976, and 00323). One has no leading 0's, one has 1, and one has 2. Based on what I'm gathering, when you import them in you are seeing 76342, 8976, 323. You can then create a calculated column to append necessary 0's on front depending on the size of the number like this:

 

RealZipCode = 
SWITCH(
    TRUE(),
    LEN('Table'[ZipCode]) = 5, 'Table'[ZipCode],
    LEN('Table'[ZipCode]) = 4, "0" & 'Table'[ZipCode],
    LEN('Table'[ZipCode]) = 3, "00" & 'Table'[ZipCode]
)

You end up with output that looks like:

 

ZipCode.PNG

 

Hope this helps,

Parker

ZIP = RIGHT("00000" & 'myaddresses'[myzip], 5)

 

avatar user

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.

Top Solution Authors (Last Month)
Top Kudoed Authors (Last Month)