CREATE OR REPLACE PACKAGE postcode AS
FUNCTION tidy(p_postcode IN VARCHAR2) RETURN VARCHAR2;
PROCEDURE split (p_postcode IN VARCHAR2,
p_area OUT VARCHAR2,
p_district OUT VARCHAR2,
p_sector OUT VARCHAR2,
p_unit OUT VARCHAR2);
PROCEDURE split (p_postcode IN VARCHAR2,
p_outcode OUT VARCHAR2,
p_incode OUT VARCHAR2);
FUNCTION area(p_postcode IN VARCHAR2) RETURN VARCHAR2;
FUNCTION district(p_postcode IN VARCHAR2) RETURN VARCHAR2;
FUNCTION sector(p_postcode IN VARCHAR2) RETURN VARCHAR2;
FUNCTION unit(p_postcode IN VARCHAR2) RETURN VARCHAR2;
FUNCTION outcode(p_postcode IN VARCHAR2) RETURN VARCHAR2;
FUNCTION incode(p_postcode IN VARCHAR2) RETURN VARCHAR2;
END postcode;
/
CREATE OR REPLACE PACKAGE BODY postcode AS
g_postcode VARCHAR2(32767);
g_area VARCHAR2(8);
g_district VARCHAR2(8);
g_sector VARCHAR2(8);
g_unit VARCHAR2(8);
FUNCTION tidy(p_postcode IN VARCHAR2) RETURN VARCHAR2 IS
v_squash VARCHAR2(7);
v_pattern VARCHAR2(7);
v_tidy VARCHAR2(8);
BEGIN
v_squash := SUBSTR(REPLACE(UPPER(p_postcode),' ',''),1,7);
v_pattern := TRANSLATE(v_squash,
'ABCDEFGHIJKLMNOPQRSTUVWXYZ1234567890',
'XXXXXXXXXXXXXXXXXXXXXXXXXX9999999999');
IF v_pattern = 'X99XX' THEN
v_tidy := SUBSTR(v_squash,1,2)||' '||SUBSTR(v_squash,3);
ELSIF v_pattern IN ('XX99XX','X999XX','X9X9XX') THEN
v_tidy := SUBSTR(v_squash,1,3)||' '||SUBSTR(v_squash,4);
ELSIF v_pattern IN ('XX999XX','XX9X9XX') THEN
v_tidy := SUBSTR(v_squash,1,4)||' '||SUBSTR(v_squash,5);
ELSIF v_squash= 'GIR0AA' THEN
v_tidy := 'GIR 0AA';
ELSE
v_tidy := SUBSTR(UPPER(p_postcode),1,8); -- Could return NULL here
END IF;
RETURN v_tidy;
END;
/* ------------------------------------------------------------------- */
PROCEDURE split (p_postcode IN VARCHAR2,
p_area OUT VARCHAR2,
p_district OUT VARCHAR2,
p_sector OUT VARCHAR2,
p_unit OUT VARCHAR2) IS
v_tidy VARCHAR2(8);
v_pos NUMBER := 1;
v_len NUMBER;
v_char VARCHAR2(1);
BEGIN
IF p_postcode IS NULL THEN
NULL;
ELSIF p_postcode = g_postcode THEN
p_area := g_area;
p_district := g_district;
p_sector := g_sector;
p_unit := g_unit;
ELSE
v_tidy := tidy(p_postcode);
v_len := LENGTH(v_tidy);
LOOP
EXIT WHEN v_pos > v_len;
v_char := SUBSTR(v_tidy,v_pos,1);
IF v_char IN ('1','2','3','4','5','6','7','8','9','0',' ') THEN
EXIT;
ELSE
p_area := p_area||v_char;
END IF;
v_pos := v_pos + 1;
END LOOP;
LOOP
EXIT WHEN v_pos > v_len;
v_char := SUBSTR(v_tidy,v_pos,1);
IF v_char = ' ' THEN
EXIT;
ELSE
p_district := p_district||v_char;
END IF;
v_pos := v_pos + 1;
END LOOP;
p_sector := SUBSTR(v_tidy,v_pos+1,1);
p_unit := SUBSTR(v_tidy,v_pos+2,2);
g_postcode := p_postcode;
g_area := p_area;
g_district := p_district;
g_sector := p_sector;
g_unit := p_unit;
END IF;
END;
PROCEDURE split (p_postcode IN VARCHAR2,
p_outcode OUT VARCHAR2,
p_incode OUT VARCHAR2) IS
v_area VARCHAR2(8);
v_district VARCHAR2(8);
v_sector VARCHAR2(8);
v_unit VARCHAR2(8);
BEGIN
split(p_postcode,v_area,v_district,v_sector,v_unit);
p_outcode := v_area||v_district;
p_incode := v_sector||v_unit;
END;
/* ------------------------------------------------------------------- */
FUNCTION area(p_postcode IN VARCHAR2) RETURN VARCHAR2 IS
v_area VARCHAR2(8);
v_district VARCHAR2(8);
v_sector VARCHAR2(8);
v_unit VARCHAR2(8);
BEGIN
split(p_postcode,v_area,v_district,v_sector,v_unit);
RETURN v_area;
END;
/* ------------------------------------------------------------------- */
FUNCTION district(p_postcode IN VARCHAR2) RETURN VARCHAR2 IS
v_area VARCHAR2(8);
v_district VARCHAR2(8);
v_sector VARCHAR2(8);
v_unit VARCHAR2(8);
BEGIN
split(p_postcode,v_area,v_district,v_sector,v_unit);
RETURN v_district;
END;
/* ------------------------------------------------------------------- */
FUNCTION sector(p_postcode IN VARCHAR2) RETURN VARCHAR2 IS
v_area VARCHAR2(8);
v_district VARCHAR2(8);
v_sector VARCHAR2(8);
v_unit VARCHAR2(8);
BEGIN
split(p_postcode,v_area,v_district,v_sector,v_unit);
RETURN v_sector;
END;
/* ------------------------------------------------------------------- */
FUNCTION unit(p_postcode IN VARCHAR2) RETURN VARCHAR2 IS
v_area VARCHAR2(8);
v_district VARCHAR2(8);
v_sector VARCHAR2(8);
v_unit VARCHAR2(8);
BEGIN
split(p_postcode,v_area,v_district,v_sector,v_unit);
RETURN v_unit;
END;
/* ------------------------------------------------------------------- */
FUNCTION outcode(p_postcode IN VARCHAR2) RETURN VARCHAR2 IS
v_area VARCHAR2(8);
v_district VARCHAR2(8);
v_sector VARCHAR2(8);
v_unit VARCHAR2(8);
BEGIN
split(p_postcode,v_area,v_district,v_sector,v_unit);
RETURN v_area||v_district;
END;
/* ------------------------------------------------------------------- */
FUNCTION incode(p_postcode IN VARCHAR2) RETURN VARCHAR2 IS
v_area VARCHAR2(8);
v_district VARCHAR2(8);
v_sector VARCHAR2(8);
v_unit VARCHAR2(8);
BEGIN
split(p_postcode,v_area,v_district,v_sector,v_unit);
RETURN v_sector||v_unit;
END;
END postcode;
/