Cleans countries in postal codes

This commit is contained in:
Carla Iriberri 2015-11-30 16:04:02 +01:00
parent b7562ff6f2
commit 65dab2196a

View File

@ -4,27 +4,27 @@
CREATE OR REPLACE FUNCTION geocode_postalcode_points(code text[], inputcountry text)
RETURNS SETOF geocode_namedplace_v1 AS $$
DECLARE
DECLARE
ret geocode_namedplace_v1%rowtype;
BEGIN
FOR ret IN
SELECT
q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
FROM (
SELECT
SELECT
q, (
SELECT the_geom
SELECT the_geom
FROM global_postal_code_points
WHERE postal_code = upper(d.q)
AND iso3 = (
SELECT iso3 FROM country_decoder WHERE
lower(inputcountry) = ANY (synonyms) LIMIT 1
lower(regexp_replace(inputcountry, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text = ANY (synonyms) LIMIT 1
)
LIMIT 1
) geom
FROM (SELECT unnest(code) q) d
) v
LOOP
LOOP
RETURN NEXT ret;
END LOOP;
RETURN;
@ -35,7 +35,7 @@ $$ LANGUAGE 'plpgsql' SECURITY DEFINER;
CREATE OR REPLACE FUNCTION geocode_postalcode_points(code text[], inputcountries text[])
RETURNS SETOF geocode_place_country_iso_v1 AS $$
DECLARE
DECLARE
ret geocode_place_country_iso_v1%rowtype;
geo GEOMETRY;
BEGIN
@ -44,7 +44,7 @@ CREATE OR REPLACE FUNCTION geocode_postalcode_points(code text[], inputcountries
SELECT
q, c, iso3, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
FROM (
SELECT
SELECT
q, c, (SELECT iso3 FROM country_decoder WHERE
lower(d.c) = ANY (synonyms) LIMIT 1) iso3, (
SELECT the_geom
@ -52,13 +52,13 @@ CREATE OR REPLACE FUNCTION geocode_postalcode_points(code text[], inputcountries
WHERE postal_code = upper(d.q)
AND iso3 = (
SELECT iso3 FROM country_decoder WHERE
lower(d.c) = ANY (synonyms) LIMIT 1
lower(regexp_replace(d.c, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text = ANY (synonyms) LIMIT 1
)
LIMIT 1
) geom
FROM (SELECT unnest(code) q, unnest(inputcountries) c) d
) v
LOOP
LOOP
IF ret.geom IS NULL AND ret.iso3 = 'GBR' THEN
geo := geocode_greatbritain_outward(ret.q);
IF geo IS NOT NULL THEN
@ -76,23 +76,23 @@ $$ LANGUAGE 'plpgsql' SECURITY DEFINER;
CREATE OR REPLACE FUNCTION geocode_postalcode_points(code text[])
RETURNS SETOF geocode_namedplace_v1 AS $$
DECLARE
DECLARE
ret geocode_namedplace_v1%rowtype;
BEGIN
FOR ret IN
SELECT
q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
FROM (
SELECT
SELECT
q, (
SELECT the_geom
SELECT the_geom
FROM global_postal_code_points
WHERE postal_code = upper(d.q)
WHERE postal_code = upper(d.q)
LIMIT 1
) geom
FROM (SELECT unnest(code) q) d
) v
LOOP
LOOP
RETURN NEXT ret;
END LOOP;
RETURN;
@ -103,27 +103,27 @@ $$ LANGUAGE 'plpgsql' SECURITY DEFINER;
CREATE OR REPLACE FUNCTION geocode_postalcode_points(code integer[], inputcountries text[])
RETURNS SETOF geocode_postalint_country_v1 AS $$
DECLARE
DECLARE
ret geocode_postalint_country_v1%rowtype;
BEGIN
FOR ret IN
SELECT
q, c, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
FROM (
SELECT
SELECT
q, c, (
SELECT the_geom
FROM global_postal_code_points
WHERE postal_code_num = d.q
AND iso3 = (
SELECT iso3 FROM country_decoder WHERE
lower(d.c) = ANY (synonyms) LIMIT 1
lower(regexp_replace(d.c, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text = ANY (synonyms) LIMIT 1
)
LIMIT 1
) geom
FROM (SELECT unnest(code) q, unnest(inputcountries) c) d
) v
LOOP
LOOP
RETURN NEXT ret;
END LOOP;
RETURN;
@ -139,18 +139,18 @@ $$ LANGUAGE 'plpgsql' SECURITY DEFINER;
CREATE FUNCTION geocode_postalcode_polygons(code text[], inputcountries text[]) RETURNS SETOF geocode_namedplace_country_v1
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
DECLARE
ret geocode_namedplace_country_v1%rowtype;
adm text[];
BEGIN
SELECT INTO adm array_agg((SELECT adm0_a3 FROM admin0_synonyms WHERE name_ = lower(regexp_replace(b.c, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text LIMIT 1)) FROM (SELECT UNNEST(inputcountries) c) b;
FOR ret IN
SELECT
q, c, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
FROM (
SELECT
SELECT
q, c, (
SELECT the_geom
FROM global_postal_code_polygons
@ -159,7 +159,7 @@ CREATE FUNCTION geocode_postalcode_polygons(code text[], inputcountries text[])
) geom
FROM (SELECT unnest(code) q, unnest(inputcountries) c, unnest(adm) a) d
) v
LOOP
LOOP
RETURN NEXT ret;
END LOOP;
RETURN;
@ -170,7 +170,7 @@ $$;
-- codes array integers, countries array
CREATE OR REPLACE FUNCTION geocode_postalcode_polygons(code integer[], inputcountries text[])
RETURNS SETOF geocode_postalint_country_v1 AS $$
DECLARE
DECLARE
ret geocode_postalint_country_v1%rowtype;
BEGIN
FOR ret IN
@ -184,12 +184,12 @@ BEGIN
WHERE postal_code_num = d.q
AND iso3 = (
SELECT iso3 FROM country_decoder WHERE
lower(d.c) = ANY (synonyms) LIMIT 1
lower(regexp_replace(d.c, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text = ANY (synonyms) LIMIT 1
)
) geom
FROM (SELECT unnest(code) q, unnest(inputcountries) c) d
) v
LOOP
LOOP
RETURN NEXT ret;
END LOOP;
RETURN;
@ -199,7 +199,7 @@ $$ LANGUAGE 'plpgsql' SECURITY DEFINER;
-- codes array text
CREATE OR REPLACE FUNCTION geocode_postalcode_polygons(code text[])
RETURNS SETOF geocode_namedplace_v1 AS $$
DECLARE
DECLARE
ret geocode_namedplace_v1%rowtype;
BEGIN
FOR ret IN
@ -208,14 +208,14 @@ CREATE OR REPLACE FUNCTION geocode_postalcode_polygons(code text[])
FROM (
SELECT
q, (
SELECT the_geom
SELECT the_geom
FROM global_postal_code_polygons
WHERE postal_code = upper(d.q)
WHERE postal_code = upper(d.q)
LIMIT 1
) geom
FROM (SELECT unnest(code) q) d
) v
LOOP
LOOP
RETURN NEXT ret;
END LOOP;
RETURN;
@ -225,26 +225,26 @@ $$ LANGUAGE 'plpgsql' SECURITY DEFINER;
-- codes array text, countries text
CREATE OR REPLACE FUNCTION geocode_postalcode_polygons(code text[], inputcountry text)
RETURNS SETOF geocode_namedplace_v1 AS $$
DECLARE
DECLARE
ret geocode_namedplace_v1%rowtype;
BEGIN
FOR ret IN
SELECT
q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
FROM (
SELECT
SELECT
q, (
SELECT the_geom
SELECT the_geom
FROM global_postal_code_polygons
WHERE postal_code = upper(d.q)
AND iso3 = (
SELECT iso3 FROM country_decoder WHERE
lower(inputcountry) = ANY (synonyms) LIMIT 1
lower(regexp_replace(inputcountry, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text = ANY (synonyms) LIMIT 1
)
) geom
FROM (SELECT unnest(code) q) d
) v
LOOP
LOOP
RETURN NEXT ret;
END LOOP;
RETURN;