From 2eefa8cfd552157e7d1dbcdc5502749788b2211a Mon Sep 17 00:00:00 2001 From: andrewxhill Date: Thu, 4 Sep 2014 10:23:29 -0400 Subject: [PATCH] added CAN filter to postal code poly geocoder --- geocoder/admin0/sql/geocoder.sql | 2 +- geocoder/postal-codes/sql/geocoder.sql | 12 +++++++----- 2 files changed, 8 insertions(+), 6 deletions(-) diff --git a/geocoder/admin0/sql/geocoder.sql b/geocoder/admin0/sql/geocoder.sql index 36f857e..db86171 100644 --- a/geocoder/admin0/sql/geocoder.sql +++ b/geocoder/admin0/sql/geocoder.sql @@ -7,6 +7,6 @@ CREATE OR REPLACE FUNCTION geocode_admin0_polygons(name text[]) BEGIN -- FOR ret IN RETURN QUERY - SELECT d.q, n.the_geom as geom, CASE WHEN s.adm0_a3 IS NULL then FALSE ELSE TRUE END AS success FROM (SELECT q, lower(regexp_replace(q, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text x FROM (SELECT unnest(name) q) g) d LEFT OUTER JOIN admin0_synonyms s ON name_ = d.x LEFT OUTER JOIN ne_admin0_v3 n ON s.adm0_a3 = n.adm0_a3; + SELECT d.q, n.the_geom as geom, CASE WHEN s.adm0_a3 IS NULL then FALSE ELSE TRUE END AS success FROM (SELECT q, lower(regexp_replace(q, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text x FROM (SELECT unnest(name) q) g) d LEFT OUTER JOIN admin0_synonyms s ON name_ = d.x LEFT OUTER JOIN ne_admin0_v3 n ON s.adm0_a3 = n.adm0_a3 GROUP BY d.q, n.the_geom, s.adm0_a3; END $$ LANGUAGE 'plpgsql' SECURITY DEFINER; diff --git a/geocoder/postal-codes/sql/geocoder.sql b/geocoder/postal-codes/sql/geocoder.sql index 4072752..39ef58e 100644 --- a/geocoder/postal-codes/sql/geocoder.sql +++ b/geocoder/postal-codes/sql/geocoder.sql @@ -4,7 +4,11 @@ CREATE OR REPLACE FUNCTION geocode_postalcode_polygons(code text[], inputcountri RETURNS SETOF geocode_namedplace_country_v1 AS $$ 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 @@ -13,12 +17,10 @@ CREATE OR REPLACE FUNCTION geocode_postalcode_polygons(code text[], inputcountri q, c, ( SELECT the_geom FROM postal_code_polygons - WHERE postal_code = upper(d.q) - AND adm0_a3 = ( - SELECT adm0_a3 FROM admin0_synonyms WHERE name_ = lower(regexp_replace(d.c, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text LIMIT 1 - ) + WHERE postal_code = CASE WHEN a = 'CAN' THEN substring(upper(d.q) from 1 for 3) ELSE upper(d.q) END + AND adm0_a3 = a ) geom - FROM (SELECT unnest(code) q, unnest(inputcountries) c) d + FROM (SELECT unnest(code) q, unnest(inputcountries) c, unnest(adm) a) d ) v LOOP RETURN NEXT ret;