Adds postalcode with country

This commit is contained in:
Guido Fioravantti 2015-11-12 11:06:50 +01:00
parent 0df2845076
commit cb19a8ca08
3 changed files with 113 additions and 0 deletions

View File

@ -1,3 +1,8 @@
-- Make sure dbs are clean
DELETE FROM global_postal_code_points;
DELETE FROM country_decoder;
DELETE FROM available_services;
DELETE FROM admin0_synonyms;
-- Check that the public function is callable, even with no data
-- It should return NULL
SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204');
@ -13,6 +18,22 @@ INSERT INTO global_postal_code_points (the_geom, iso3, postal_code, postal_code_
'03204',
3204
);
INSERT INTO country_decoder (iso3, synonyms) VALUES (
'ESP',
Array['spain', 'Spain', 'ESP']
);
INSERT INTO available_services (adm0_a3, admin0, postal_code_points, postal_code_polygons) VALUES (
'ESP',
't',
't',
't'
);
INSERT INTO admin0_synonyms (adm0_a3, name, name_, rank) VALUES (
'ESP',
'Spain',
'spain',
3
);
-- This should return the polygon inserted above
SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204');
geocode_postalcode_point
@ -20,3 +41,14 @@ SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current()
0101000020E61000000000000000E040408036B47414764840
(1 row)
SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204', 'spain');
geocode_postalcode_point
----------------------------------------------------
0101000020E61000000000000000E040408036B47414764840
(1 row)
-- Clean dbs
DELETE FROM global_postal_code_points;
DELETE FROM country_decoder;
DELETE FROM available_services;
DELETE FROM admin0_synonyms;

View File

@ -1,3 +1,5 @@
-- TODO geocode_postalcode_polygon(code text, country text)
-- Interface of the server extension
CREATE OR REPLACE FUNCTION geocode_postalcode_point(user_id NAME, tx_id BIGINT, code text)
@ -21,6 +23,27 @@ RETURNS Geometry AS $$
return rv[0]["point"]
$$ LANGUAGE plpythonu;
CREATE OR REPLACE FUNCTION geocode_postalcode_point(user_id NAME, tx_id BIGINT, code text, country text)
RETURNS Geometry AS $$
plpy.debug('Entering _geocode_postalcode_point')
plpy.debug('user_id = %s' % user_id)
#-- Access control
#-- TODO: this should be part of cdb python library
if user_id == 'publicuser':
plpy.error('The api_key must be provided')
#--TODO: rate limiting check
#--TODO: quota check
#-- Copied from the doc, see http://www.postgresql.org/docs/9.4/static/plpython-database.html
plan = plpy.prepare("SELECT cdb_geocoder_server._geocode_postalcode_point($1, $2) AS point", ["TEXT", "TEXT"])
rv = plpy.execute(plan, [code, country], 1)
plpy.debug('Returning from _geocode_postalcode_point')
return rv[0]["point"]
$$ LANGUAGE plpythonu;
--------------------------------------------------------------------------------
@ -46,3 +69,28 @@ RETURNS Geometry AS $$
RETURN ret;
END
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION _geocode_postalcode_point(code text, country text)
RETURNS Geometry AS $$
DECLARE
ret Geometry;
BEGIN
SELECT geom INTO ret
FROM (
SELECT
q, (
SELECT the_geom
FROM global_postal_code_points
WHERE postal_code = upper(d.q)
AND iso3 = (
SELECT iso3 FROM country_decoder WHERE
lower(country) = ANY (synonyms) LIMIT 1
)
LIMIT 1
) geom
FROM (SELECT code q) d
) v;
RETURN ret;
END
$$ LANGUAGE plpgsql;

View File

@ -1,3 +1,9 @@
-- Make sure dbs are clean
DELETE FROM global_postal_code_points;
DELETE FROM country_decoder;
DELETE FROM available_services;
DELETE FROM admin0_synonyms;
-- Check that the public function is callable, even with no data
-- It should return NULL
SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204');
@ -10,5 +16,32 @@ INSERT INTO global_postal_code_points (the_geom, iso3, postal_code, postal_code_
3204
);
INSERT INTO country_decoder (iso3, synonyms) VALUES (
'ESP',
Array['spain', 'Spain', 'ESP']
);
INSERT INTO available_services (adm0_a3, admin0, postal_code_points, postal_code_polygons) VALUES (
'ESP',
't',
't',
't'
);
INSERT INTO admin0_synonyms (adm0_a3, name, name_, rank) VALUES (
'ESP',
'Spain',
'spain',
3
);
-- This should return the polygon inserted above
SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204');
SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204', 'spain');
-- Clean dbs
DELETE FROM global_postal_code_points;
DELETE FROM country_decoder;
DELETE FROM available_services;
DELETE FROM admin0_synonyms;