Adds namedplace function with 3 params #6

This commit is contained in:
Carla Iriberri 2015-11-11 18:14:22 +01:00
parent b54c417754
commit 4aa757ac88
3 changed files with 69 additions and 4 deletions

View File

@ -7,15 +7,17 @@ SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx
(1 row) (1 row)
-- Insert dummy data into points table -- Insert dummy data into points table
INSERT INTO global_cities_points_limited (geoname_id, name, iso2, admin1, admin2, population, lowername, the_geom) VALUES (3128760, 'Elche', 'ES', 'VA', 'AL', 34534, 'elche', ST_GeomFromText( INSERT INTO global_cities_points_limited (geoname_id, name, iso2, admin1, admin2, population, lowername, the_geom) VALUES (3128760, 'Elche', 'ES', 'Valencia', 'AL', 34534, 'elche', ST_GeomFromText(
'POINT(0.6983 39.26787)',4326) 'POINT(0.6983 39.26787)',4326)
); );
-- Insert dummy data into alternates table -- Insert dummy data into alternates table
INSERT INTO global_cities_alternates_limited (geoname_id, name, preferred, lowername, admin1_geonameid, iso2, admin1, the_geom) VALUES (3128760, 'Elx', true, 'elx', '000000', 'ES', 'VA', ST_GeomFromText( INSERT INTO global_cities_alternates_limited (geoname_id, name, preferred, lowername, admin1_geonameid, iso2, admin1, the_geom) VALUES (3128760, 'Elx', true, 'elx', '000000', 'ES', 'Valencia', ST_GeomFromText(
'POINT(0.6983 39.26787)',4326) 'POINT(0.6983 39.26787)',4326)
); );
-- Insert dummy data into country decoder table -- Insert dummy data into country decoder table
INSERT INTO country_decoder (synonyms, iso2) VALUES (Array['spain'], 'ES'); INSERT INTO country_decoder (synonyms, iso2) VALUES (Array['spain'], 'ES');
-- Insert dummy data into admin1 decoder table
INSERT INTO admin1_decoder (admin1, synonyms, iso2) VALUES ('Valencia', Array['valencia', 'Valencia'], 'ES');
-- This should return the point inserted above -- This should return the point inserted above
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx');
geocode_namedplace geocode_namedplace
@ -41,3 +43,15 @@ SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elc
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340 0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
(1 row) (1 row)
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Valencia', 'Spain');
geocode_namedplace
----------------------------------------------------
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'valencia', 'Spain');
geocode_namedplace
----------------------------------------------------
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
(1 row)

View File

@ -44,6 +44,28 @@ RETURNS Geometry AS $$
return rv[0]["mypoint"] return rv[0]["mypoint"]
$$ LANGUAGE plpythonu; $$ LANGUAGE plpythonu;
---- geocode_namedplace(city_name text, admin1_name text, country_name text)
CREATE OR REPLACE FUNCTION geocode_namedplace(user_id name, tx_id bigint, city_name text, admin1_name text, country_name text)
RETURNS Geometry AS $$
plpy.debug('Entering geocode_namedplace(city_name text, admin1_name text, country_name text)')
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_namedplace($1, $2, $3) AS mypoint", ["text", "text", "text"])
rv = plpy.execute(plan, [city_name, admin1_name, country_name], 1)
plpy.debug('Returning from Returning from geocode_namedplace')
return rv[0]["mypoint"]
$$ LANGUAGE plpythonu;
-------------------------------------------------------------------------------- --------------------------------------------------------------------------------
-- Implementation of the server extension -- Implementation of the server extension
@ -88,3 +110,27 @@ RETURNS Geometry AS $$
END END
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
---- geocode_namedplace(city_name text, admin1_name text, country_name text)
CREATE OR REPLACE FUNCTION _geocode_namedplace(city_name text, admin1_name text, country_name text)
RETURNS Geometry AS $$
DECLARE
ret Geometry;
BEGIN
SELECT geom INTO ret
FROM (
WITH inputcountry AS (
SELECT iso2 as isoTwo FROM country_decoder WHERE lower(country_name) = ANY (synonyms) LIMIT 1
),
p AS (
SELECT r.s, r.a1, (SELECT admin1 FROM admin1_decoder, inputcountry WHERE lower(r.a1) = ANY (synonyms) AND admin1_decoder.iso2 = inputcountry.isoTwo LIMIT 1) i FROM (SELECT city_name AS s, admin1_name::text AS a1) r),
best AS (SELECT p.s AS q, p.a1 as a1, (SELECT gp.the_geom AS geom FROM global_cities_points_limited gp WHERE gp.lowername = lower(p.s) AND gp.admin1 = p.i ORDER BY population DESC LIMIT 1) AS geom FROM p),
next AS (SELECT p.s AS q, p.a1 AS a1, (SELECT gp.the_geom FROM global_cities_points_limited gp, global_cities_alternates_limited ga WHERE lower(p.s) = ga.lowername AND ga.admin1 = p.i AND ga.geoname_id = gp.geoname_id ORDER BY preferred DESC LIMIT 1) geom FROM p WHERE p.s NOT IN (SELECT q FROM best WHERE geom IS NOT NULL))
SELECT geom FROM best WHERE geom IS NOT NULL
UNION ALL
SELECT geom FROM next
) v;
RETURN ret;
END
$$ LANGUAGE plpgsql;

View File

@ -3,20 +3,25 @@
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx');
-- Insert dummy data into points table -- Insert dummy data into points table
INSERT INTO global_cities_points_limited (geoname_id, name, iso2, admin1, admin2, population, lowername, the_geom) VALUES (3128760, 'Elche', 'ES', 'VA', 'AL', 34534, 'elche', ST_GeomFromText( INSERT INTO global_cities_points_limited (geoname_id, name, iso2, admin1, admin2, population, lowername, the_geom) VALUES (3128760, 'Elche', 'ES', 'Valencia', 'AL', 34534, 'elche', ST_GeomFromText(
'POINT(0.6983 39.26787)',4326) 'POINT(0.6983 39.26787)',4326)
); );
-- Insert dummy data into alternates table -- Insert dummy data into alternates table
INSERT INTO global_cities_alternates_limited (geoname_id, name, preferred, lowername, admin1_geonameid, iso2, admin1, the_geom) VALUES (3128760, 'Elx', true, 'elx', '000000', 'ES', 'VA', ST_GeomFromText( INSERT INTO global_cities_alternates_limited (geoname_id, name, preferred, lowername, admin1_geonameid, iso2, admin1, the_geom) VALUES (3128760, 'Elx', true, 'elx', '000000', 'ES', 'Valencia', ST_GeomFromText(
'POINT(0.6983 39.26787)',4326) 'POINT(0.6983 39.26787)',4326)
); );
-- Insert dummy data into country decoder table -- Insert dummy data into country decoder table
INSERT INTO country_decoder (synonyms, iso2) VALUES (Array['spain'], 'ES'); INSERT INTO country_decoder (synonyms, iso2) VALUES (Array['spain'], 'ES');
-- Insert dummy data into admin1 decoder table
INSERT INTO admin1_decoder (admin1, synonyms, iso2) VALUES ('Valencia', Array['valencia', 'Valencia'], 'ES');
-- This should return the point inserted above -- This should return the point inserted above
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx');
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche');
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Spain'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Spain');
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'Spain'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'Spain');
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Valencia', 'Spain');
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'valencia', 'Spain');