git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@4173 248e525c-4dfb-0310-94bc-949c084e9493
189 lines
6.4 KiB
Plaintext
189 lines
6.4 KiB
Plaintext
CREATE OR REPLACE PACKAGE mip_regions IS
|
|
|
|
-- Author : HARDYA
|
|
-- Created : 20/11/2007 14:18:26
|
|
-- Purpose :
|
|
|
|
/** Attempts to validate that the format of the given string matches a standard postcode format
|
|
|
|
This includes the general format of the string, plus any restrictions on character values within
|
|
the overall format.
|
|
|
|
%param p_string the string whose format is to be checked
|
|
%return TRUE if the given string matches a known postcode format
|
|
*/
|
|
FUNCTION valid_postcode_format(p_postcode IN VARCHAR2) RETURN BOOLEAN;
|
|
|
|
/** Find the region with which the given postcode is associated
|
|
|
|
%param p_postcode correctly formatted postcode
|
|
%return region code or NULL
|
|
*/
|
|
FUNCTION get_region_for_postcode(p_postcode IN VARCHAR2)
|
|
RETURN postcodes.regi_code%TYPE;
|
|
END mip_regions;
|
|
/
|
|
CREATE OR REPLACE PACKAGE BODY mip_regions IS
|
|
|
|
/*
|
|
**
|
|
* Postcode format based on the UK Government Data Standards Catalogue
|
|
* http://www.govtalk.gov.uk/gdsc/html/frames/Postcode.htm
|
|
**
|
|
*/
|
|
|
|
/** Attempts to determine whether general the format the given string to match a standard postcode format
|
|
|
|
%param p_string the string whose format is to be checked
|
|
%return a known postcode format or NULL if the string did not match a known postcode format
|
|
{*} ANbNAA e.g. M1 1AA
|
|
{*} ANNbNAA e.g. M60 1NW
|
|
{*} AANbNAA e.g. CR2 6XH
|
|
{*} AANNbNAA e.g. DN55 1PT
|
|
{*} ANAbNAA e.g. W1A 1HP
|
|
{*} AANAbNAA e.g. EC1A 1BB
|
|
*/
|
|
FUNCTION reformat_postcode_string(p_string IN VARCHAR2) RETURN VARCHAR2 IS
|
|
l_return VARCHAR2(8);
|
|
BEGIN
|
|
|
|
IF regexp_like(srcstr => p_string
|
|
,pattern => '^[[:upper:]][[:digit:]] [[:digit:]][[:upper:]]{2}$') THEN
|
|
l_return := 'AN NAA';
|
|
ELSIF regexp_like(srcstr => p_string
|
|
,pattern => '^[[:upper:]][[:digit:]]{2} [[:digit:]][[:upper:]]{2}$') THEN
|
|
l_return := 'ANN NAA';
|
|
ELSIF regexp_like(srcstr => p_string
|
|
,pattern => '^[[:upper:]]{2}[[:digit:]] [[:digit:]][[:upper:]]{2}$') THEN
|
|
l_return := 'AAN NAA';
|
|
ELSIF regexp_like(srcstr => p_string
|
|
,pattern => '^[[:upper:]]{2}[[:digit:]]{2} [[:digit:]][[:upper:]]{2}$') THEN
|
|
l_return := 'AANN NAA';
|
|
ELSIF regexp_like(srcstr => p_string
|
|
,pattern => '^[[:upper:]][[:digit:]][[:upper:]] [[:digit:]][[:upper:]]{2}$') THEN
|
|
l_return := 'ANA NAA';
|
|
ELSIF regexp_like(srcstr => p_string
|
|
,pattern => '^[[:upper:]]{2}[[:digit:]][[:upper:]] [[:digit:]][[:upper:]]{2}$') THEN
|
|
l_return := 'AANA NAA';
|
|
END IF;
|
|
|
|
RETURN l_return;
|
|
END reformat_postcode_string;
|
|
|
|
/** Attempts to validate that the format of the given string matches a standard postcode format
|
|
|
|
This includes the general format of the string, plus any restrictions on character values within
|
|
the overall format.
|
|
|
|
%param p_string the string whose format is to be checked
|
|
%return TRUE if the given string matches a known postcode format
|
|
*/
|
|
FUNCTION valid_postcode_format(p_postcode IN VARCHAR2) RETURN BOOLEAN IS
|
|
l_return BOOLEAN := TRUE;
|
|
l_postcode_format VARCHAR2(8);
|
|
l_postcode VARCHAR2(80) := upper(p_postcode);
|
|
BEGIN
|
|
|
|
IF l_postcode = 'GIR 0AA' THEN
|
|
l_return := TRUE;
|
|
ELSIF length(l_postcode) NOT IN (6
|
|
,7
|
|
,8) THEN
|
|
l_return := FALSE;
|
|
ELSE
|
|
l_postcode_format := reformat_postcode_string(l_postcode);
|
|
|
|
IF l_postcode_format IS NULL THEN
|
|
l_return := FALSE;
|
|
ELSE
|
|
IF instr('QVX'
|
|
,substr(l_postcode
|
|
,1
|
|
,1)) > 0 THEN
|
|
l_return := FALSE;
|
|
ELSIF substr(l_postcode_format
|
|
,2
|
|
,1) = 'A'
|
|
AND instr('IJZ'
|
|
,substr(l_postcode
|
|
,2
|
|
,1)) > 0 THEN
|
|
l_return := FALSE;
|
|
ELSIF substr(l_postcode_format
|
|
,3
|
|
,1) = 'A'
|
|
AND instr('ABCDEFGHJKSTUW'
|
|
,substr(l_postcode
|
|
,3
|
|
,1)) = 0 THEN
|
|
l_return := FALSE;
|
|
ELSIF substr(l_postcode_format
|
|
,4
|
|
,1) = 'A'
|
|
AND instr('ABEHMNPRVWXY'
|
|
,substr(l_postcode
|
|
,4
|
|
,1)) = 0 THEN
|
|
l_return := FALSE;
|
|
ELSE
|
|
-- letters CIKMOV are not used in the second part of the postcode
|
|
FOR l_idx IN instr(l_postcode_format
|
|
,' ') .. length(l_postcode_format) LOOP
|
|
IF substr(l_postcode_format
|
|
,l_idx
|
|
,1) = 'A'
|
|
AND instr('CIKMOV'
|
|
,substr(l_postcode
|
|
,l_idx
|
|
,1)) > 0 THEN
|
|
l_return := FALSE;
|
|
END IF;
|
|
END LOOP;
|
|
END IF;
|
|
END IF;
|
|
END IF;
|
|
|
|
RETURN l_return;
|
|
END valid_postcode_format;
|
|
|
|
/** Find the region with which the given postcode is associated
|
|
|
|
%param p_postcode correctly formatted postcode
|
|
%return region code or NULL
|
|
*/
|
|
FUNCTION get_region_for_postcode(p_postcode IN VARCHAR2)
|
|
RETURN postcodes.regi_code%TYPE IS
|
|
l_regi_code postcodes.regi_code%TYPE;
|
|
l_postcode VARCHAR2(80) := upper(p_postcode);
|
|
BEGIN
|
|
SELECT regi_code
|
|
INTO l_regi_code
|
|
FROM (SELECT regi_code
|
|
,outcode
|
|
,incode
|
|
,decode(outcode || ' ' || incode
|
|
,l_postcode
|
|
,1
|
|
,999) AS accuracy
|
|
FROM postcodes t
|
|
WHERE (outcode || ' ' || incode = l_postcode)
|
|
OR (outcode = substr(l_postcode
|
|
,1
|
|
,instr(l_postcode
|
|
,' ') - 1) AND incode IS NULL)
|
|
ORDER BY 4)
|
|
WHERE rownum < 2;
|
|
|
|
RETURN l_regi_code;
|
|
|
|
EXCEPTION
|
|
WHEN no_data_found THEN
|
|
RETURN NULL;
|
|
END get_region_for_postcode;
|
|
|
|
BEGIN
|
|
-- Initialization
|
|
NULL;
|
|
END mip_regions;
|
|
/
|