| 
                
                    | 
                            
                                | Author | Topic |  
                                    | SwePesoPatron Saint of Lost Yaks
 
 
                                        30421 Posts | 
                                            
                                            |  Posted - 2008-08-13 : 07:46:05 
 |  
                                            | [code]CREATE FUNCTION dbo.fnValidatePostCodeUK(	@PostCode VARCHAR(8))RETURNS BITASBEGIN	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                ENDEND[/code] E 12°55'05.25"N 56°04'39.16"
 |  |  
                                    | SwePesoPatron Saint of Lost Yaks
 
 
                                    30421 Posts | 
                                        
                                          |  Posted - 2008-08-14 : 03:10:17 
 |  
                                          | [code]declare @TestTab Table (postcode varchar(50) not null)Insert @TestTab values('SK13 8LY') --ValidInsert @TestTab values('M1 1AA') --ValidInsert @TestTab values('M60 1NW') --ValidInsert @TestTab values('GIR 0AA') --ValidInsert @TestTab values('CR2 6XH') --ValidInsert @TestTab values('DN55 1PT') --ValidInsert @TestTab values('W1A 1HQ') --ValidInsert @TestTab values('EC1A 1BB') --ValidInsert @TestTab values('India') --InvalidInsert @TestTab values('12345') --InvalidInsert @TestTab values('Glossop SK13 8LY') --Invalid but contains a valid postcodeINSERT @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[/code] E 12°55'05.25"N 56°04'39.16"
 |  
                                          |  |  |  
                                    | darkduskyAged Yak Warrior
 
 
                                    591 Posts | 
                                        
                                          |  Posted - 2008-10-22 : 10:12:16 
 |  
                                          | 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 BITASBEGIN	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                ENDEND |  
                                          |  |  |  
                                    | SwePesoPatron Saint of Lost Yaks
 
 
                                    30421 Posts | 
                                        
                                          |  Posted - 2008-10-22 : 10:24:30 
 |  
                                          | 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"
 |  
                                          |  |  |  
                                    | darkduskyAged Yak Warrior
 
 
                                    591 Posts | 
                                        
                                          |  Posted - 2008-10-23 : 04:57:16 
 |  
                                          | 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? |  
                                          |  |  |  
                                    | SwePesoPatron Saint of Lost Yaks
 
 
                                    30421 Posts | 
                                        
                                          |  Posted - 2008-10-23 : 05:04:50 
 |  
                                          | 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"
 |  
                                          |  |  |  
                                    | Arnold FribbleYak-finder General
 
 
                                    1961 Posts | 
                                        
                                          |  Posted - 2008-10-23 : 08:42:11 
 |  
                                          | 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 |  
                                          |  |  |  
                                    | SwePesoPatron Saint of Lost Yaks
 
 
                                    30421 Posts | 
                                        
                                          |  Posted - 2008-10-23 : 09:25:26 
 |  
                                          | http://www.govtalk.gov.uk/gdsc/html/frames/PostCode.htm E 12°55'05.63"N 56°04'39.26"
 |  
                                          |  |  |  
                                    | darkduskyAged Yak Warrior
 
 
                                    591 Posts | 
                                        
                                          |  Posted - 2008-10-23 : 10:37:54 
 |  
                                          | 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. |  
                                          |  |  |  
                                    | SwePesoPatron Saint of Lost Yaks
 
 
                                    30421 Posts |  |  
                                    | SwePesoPatron Saint of Lost Yaks
 
 
                                    30421 Posts | 
                                        
                                          |  Posted - 2008-10-23 : 11:09:47 
 |  
                                          | [code]CREATE FUNCTION dbo.fnValidatePostCodeUK(	@PostCode VARCHAR(8))RETURNS BITASBEGIN	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		ENDEND[/code] E 12°55'05.63"N 56°04'39.26"
 |  
                                          |  |  |  
                                    | DeliusStarting Member
 
 
                                    1 Post | 
                                        
                                          |  Posted - 2008-11-04 : 16:42:41 
 |  
                                          | 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))=1SET @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 0Separating 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) |  
                                          |  |  |  
                                |  |  |  |