SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 General SQL Server Forums
 Script Library
 Validate UK postcode
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

SwePeso
Patron Saint of Lost Yaks

Sweden
30281 Posts

Posted - 08/13/2008 :  07:46:05  Show Profile  Visit SwePeso's Homepage  Reply with Quote
CREATE FUNCTION dbo.fnValidatePostCodeUK
(
	@PostCode VARCHAR(8)
)
RETURNS BIT
AS
BEGIN
	RETURN	CASE
			-- AANN NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][ABCDEFGHKLMNOPQRSTUVWXY][0123456789][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			-- AANA NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][ABCDEFGHKLMNOPQRSTUVWXY][0123456789][ABEHMNPRVWXY] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			--  ANN NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][0123456789][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			--  AAN NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][ABCDEFGHKLMNOPQRSTUVWXY][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			--  ANA NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][0123456789][ABCDEFGHJKSTUW] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			--   AN NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			--   Special case GIR 0AA
			WHEN @PostCode LIKE 'GIR 0AA' THEN 1
			-- Not a valid postcode
                        ELSE 0
                END
END


E 12°55'05.25"
N 56°04'39.16"

Edited by - SwePeso on 08/14/2008 02:53:56

SwePeso
Patron Saint of Lost Yaks

Sweden
30281 Posts

Posted - 08/14/2008 :  03:10:17  Show Profile  Visit SwePeso's Homepage  Reply with Quote
declare @TestTab Table (postcode varchar(50) not null)

Insert @TestTab values('SK13 8LY') --Valid
Insert @TestTab values('M1 1AA') --Valid
Insert @TestTab values('M60 1NW') --Valid
Insert @TestTab values('GIR 0AA') --Valid
Insert @TestTab values('CR2 6XH') --Valid
Insert @TestTab values('DN55 1PT') --Valid
Insert @TestTab values('W1A 1HQ') --Valid
Insert @TestTab values('EC1A 1BB') --Valid
Insert @TestTab values('India') --Invalid
Insert @TestTab values('12345') --Invalid
Insert @TestTab values('Glossop SK13 8LY') --Invalid but contains a valid postcode
INSERT @TestTab VALUES('XA1 1AA')  --WHAT WILL THE FUNCTION SAY ABOUT THIS???  WAS JUST A PHAT-PHINGER on "X"
INSERT @TestTab VALUES('AAA 1AA')  --OR HOW ABOUT THIS???

SELECT	PostCode,
	dbo.fnValidatePostCodeUK(PostCode)
FROM	@TestTab



E 12°55'05.25"
N 56°04'39.16"
Go to Top of Page

darkdusky
Aged Yak Warrior

591 Posts

Posted - 10/22/2008 :  10:12:16  Show Profile  Reply with Quote
You can make a small adjustment to check prefix matches actual postcode prefixes. I found these 124 postcode prefixes on a website which said this was the entire set. However this does not include Isle of Man or Isle of Wight, or British Forces postal prefixes.

alter FUNCTION dbo.fnValidatePostCodeUK
(
@PostCode VARCHAR(8)
)
RETURNS BIT
AS
BEGIN
RETURN CASE
-- AANN NAA
WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][ABCDEFGHKLMNOPQRSTUVWXY][0123456789][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
-- AANA NAA
WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][ABCDEFGHKLMNOPQRSTUVWXY][0123456789][ABEHMNPRVWXY] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
-- ANN NAA
WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][0123456789][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
-- AAN NAA
WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][ABCDEFGHKLMNOPQRSTUVWXY][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
-- ANA NAA
WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][0123456789][ABCDEFGHJKSTUW] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
-- AN NAA
WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
-- Special case GIR 0AA
WHEN @PostCode LIKE 'GIR 0AA' THEN 1
--check for actual postcode prefixes
WHEN Left(@Postcode,2) NOT IN ('AB','AL','B','BA','BB','BD','BH','BL','BN','BR','BS','BT','CA','CB','CF','CH','CM','CO','CR','CT','CV','CW','DA','DD','DE','DG','DH','DL','DN','DT','DY','E','EC','EH','EN','EX','FK','FY','G','GL','GU','GY','HA','HD','HG','HP','HR','HS','HU','HX','IG','IM','IP','IV','JE','KA','KT','KW','KY','L','LA','LD','LE','LL','LN','LS','LU','M','ME','MK','ML','N','NE','NG','NN','NP','NR','NW','OL','OX','PA','PE','PH','PL','PO','PR','RG','RH','RM','S','SA','SE','SG','SK','SL','SM','SN','SO','SP','SR','SS','ST','SW','SY','TA','TD','TF','TN','TQ','TR','TS','TW','UB','W','WA','WC','WD','WF','WN','WR','WS','WV','YO','ZE') then 0


-- Not a valid postcode
ELSE 0
END
END
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
30281 Posts

Posted - 10/22/2008 :  10:24:30  Show Profile  Visit SwePeso's Homepage  Reply with Quote
I can't see the use of having an extra NOT IN, when all those combinations are already covered in the previous WHENs...



E 12°55'05.63"
N 56°04'39.26"
Go to Top of Page

darkdusky
Aged Yak Warrior

591 Posts

Posted - 10/23/2008 :  04:57:16  Show Profile  Reply with Quote
The difference is that this will exclude postcodes which fit the correct format but the prefix does not match an actual postcode. For example if some-one enters BX9 5JU the original function will not find a problem but there is no postcode starting with BX. I have included the 124 prefixes of all UK and Northern Ireland postcodes (we could add BFPO - for British Forces). I double-checked and the list does include Isle Of Man [MO] and Isle of Wight [PO]. So now it doesn't just check format it checks if prefix exists. Checking against all of 1.5 million postcodes is impractical but why not check against 140 prefixes for greater robustness?
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
30281 Posts

Posted - 10/23/2008 :  05:04:50  Show Profile  Visit SwePeso's Homepage  Reply with Quote
That's another thing.
It is not IN USE today but is reserved for future use, so it is still valid.



E 12°55'05.63"
N 56°04'39.26"
Go to Top of Page

Arnold Fribble
Yak-finder General

United Kingdom
1961 Posts

Posted - 10/23/2008 :  08:42:11  Show Profile  Reply with Quote
When I gave it a go on the NHS GPs list, I thought you'd missed codes like 'W1[MNPRVXY] %'.
But apparently these got recoded to various other W1 codes back in June 2000 (so all the people still claiming them as their current postcode are wrong!)
ftp://ftp.royalmail.com/Downloads/public/ctf/rm/Royal_Mail_major_recode_historical_2000-2008.pdf

Edited by - Arnold Fribble on 10/23/2008 08:44:00
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
30281 Posts

Posted - 10/23/2008 :  09:25:26  Show Profile  Visit SwePeso's Homepage  Reply with Quote
http://www.govtalk.gov.uk/gdsc/html/frames/PostCode.htm



E 12°55'05.63"
N 56°04'39.26"
Go to Top of Page

darkdusky
Aged Yak Warrior

591 Posts

Posted - 10/23/2008 :  10:37:54  Show Profile  Reply with Quote
I take your point that new postcode prefixes could be added in future but using Arnold's link no new prefixes (first 1 or 2 letters) have been added in at least 6 years. The prefix usually comes from a city or county or region name so it is fairly unlikely that a new city or county will appear, although I accept it can happen.
But then again the general format may also change so this function can never be cast in stone.
My aim was to help catch typos which can slip past format checker. Typos are probably more likely to occur than a new city to springing up.
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
30281 Posts

Posted - 10/23/2008 :  10:54:52  Show Profile  Visit SwePeso's Homepage  Reply with Quote
I see your point. You want active Postcodes, not just the valid ones.
Put your new check first.

http://strangemaps.wordpress.com/2007/05/16/113-the-postcode-map-of-great-britain/



E 12°55'05.63"
N 56°04'39.26"

Edited by - SwePeso on 10/23/2008 10:57:26
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
30281 Posts

Posted - 10/23/2008 :  11:09:47  Show Profile  Visit SwePeso's Homepage  Reply with Quote
CREATE FUNCTION dbo.fnValidatePostCodeUK
(
	@PostCode VARCHAR(8)
)
RETURNS BIT
AS
BEGIN
	RETURN	CASE
			-- Special case GIR 0AA
			WHEN @PostCode LIKE 'GIR 0AA' THEN 1
			-- Current postcode prefixes
			WHEN	LEFT(@Postcode, 2) NOT IN ('AB', 'AL', 'BA', 'BB', 'BD', 'BH', 'BL', 'BN', 'BR', 'BS', 'BT', 'CA', 'CB', 'CF', 'CH', 'CM', 'CO', 'CR', 'CT', 'CV', 'CW', 'DA', 'DD', 'DE', 'DG', 'DH', 'DL', 'DN', 'DT', 'DY', 'EC', 'EH', 'EN', 'EX', 'FK', 'FY', 'GL', 'GU', 'GY', 'HA', 'HD', 'HG', 'HP', 'HR', 'HS', 'HU', 'HX', 'IG', 'IM', 'IP', 'IV', 'JE', 'KA', 'KT', 'KW', 'KY', 'L', 'LA', 'LD', 'LE', 'LL', 'LN', 'LS', 'LU', 'ME', 'MK', 'ML', 'NE', 'NG', 'NN', 'NP', 'NR', 'NW', 'OL', 'OX', 'PA', 'PE', 'PH', 'PL', 'PO', 'PR', 'RG', 'RH', 'RM', 'SA', 'SE', 'SG', 'SK', 'SL', 'SM', 'SN', 'SO', 'SP', 'SR', 'SS', 'ST', 'SW', 'SY', 'TA', 'TD', 'TF', 'TN', 'TQ', 'TR', 'TS', 'TW', 'UB', 'WA', 'WC', 'WD', 'WF', 'WN', 'WR', 'WS', 'WV', 'YO', 'ZE')
				OR WHEN LEFT(@Postcode, 1) NOT IN ('B', 'E', 'G', 'L', 'N', 'S', 'W') THEN 0
			-- AANN NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][ABCDEFGHKLMNOPQRSTUVWXY][0123456789][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			-- AANA NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][ABCDEFGHKLMNOPQRSTUVWXY][0123456789][ABEHMNPRVWXY] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			-- ANN NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][0123456789][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			-- AAN NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][ABCDEFGHKLMNOPQRSTUVWXY][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			-- ANA NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][0123456789][ABCDEFGHJKSTUW] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			-- AN NAA
			WHEN @PostCode LIKE '[ABCDEFGHIJKLMNOPRSTUWYZ][0123456789] [0123456789][ABDEFGHJLNPQRSTUWXYZ][ABDEFGHJLNPQRSTUWXYZ]' THEN 1
			-- Not a valid postcode
			ELSE 0
		END
END



E 12°55'05.63"
N 56°04'39.26"
Go to Top of Page

Delius
Starting Member

United Kingdom
1 Posts

Posted - 11/04/2008 :  16:42:41  Show Profile  Reply with Quote
Thanks for this, it's been very handy. I have made a couple of further changes which I thought I'd share as it may be useful for someone else.
The main thing is that I found neither posted version of the 'Current postcode prefixes' section quite worked for me when comparing an input of 'B22 2AT' against 'BN22 2AT' and 'BX22 2AT'.
So I decided to store the prefix as an additional variable:

IF ISNUMERIC(SUBSTRING(@PostCode,2,1))=1
SET @prefix=LEFT(@PostCode,1)
ELSE SET @prefix=left(@PostCode,2)

Then I changed the CASE statement to:

WHEN @prefix NOT IN ('AB','AL','B','BA','BB','BD','BH','BL','BN','BR','BS', 'BT','CA','CB','CF','CH','CM','CO','CR','CT','CV','CW','DA','DD', 'DE','DG','DH','DL','DN','DT'...etc.) THEN 0

Separating out the prefix like this also makes it easy to bring in additional postcode data (County,Region) if wanted.

The other little thing I did, extraneous to this script probably, but to guard against postcodes that are missing spaces or have them in the wrong place(s) I just normalised the postcode input (of course this could be condensed to a single line):

SET @PostCode=UPPER(Replace(@PostCode,' ',''))
SET @PostCode= LEFT(@PostCode,LEN(@PostCode)-3)+' '+Right(@PostCode,3)

Edited by - Delius on 11/04/2008 16:46:04
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.19 seconds. Powered By: Snitz Forums 2000