Adds first function for namedplaces #6
This commit is contained in:
parent
24c0e01b06
commit
6e301b0f9e
29
server/extension/expected/50_namedplaces_test.out
Normal file
29
server/extension/expected/50_namedplaces_test.out
Normal file
@ -0,0 +1,29 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx');
|
||||
geocode_namedplace
|
||||
--------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
-- 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(
|
||||
'POINT(0.6983 39.26787)',4326)
|
||||
);
|
||||
-- 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(
|
||||
'POINT(0.6983 39.26787)',4326)
|
||||
);
|
||||
-- This should return the point inserted above
|
||||
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx');
|
||||
geocode_namedplace
|
||||
----------------------------------------------------
|
||||
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche');
|
||||
geocode_namedplace
|
||||
----------------------------------------------------
|
||||
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
|
||||
(1 row)
|
||||
|
53
server/extension/sql/0.0.1/50_namedplaces.sql
Normal file
53
server/extension/sql/0.0.1/50_namedplaces.sql
Normal file
@ -0,0 +1,53 @@
|
||||
-- Interfacess of the server extension
|
||||
|
||||
---- geocode_namedplace(city_name text)
|
||||
CREATE OR REPLACE FUNCTION geocode_namedplace(user_id name, tx_id bigint, city_name text)
|
||||
RETURNS Geometry AS $$
|
||||
plpy.debug('Entering geocode_namedplace(city_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) AS mypoint", ["text"])
|
||||
rv = plpy.execute(plan, [city_name], 1)
|
||||
|
||||
plpy.debug('Returning from Returning from geocode_namedplace')
|
||||
return rv[0]["mypoint"]
|
||||
$$ LANGUAGE plpythonu;
|
||||
|
||||
---- geocode_admin1_polygons(admin1_name text, country_name text)
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
|
||||
-- Implementation of the server extension
|
||||
-- Note: these functions depend on the cdb_geocoder extension
|
||||
|
||||
---- geocode_namedplace(city_name text)
|
||||
CREATE OR REPLACE FUNCTION _geocode_namedplace(city_name text)
|
||||
RETURNS Geometry AS $$
|
||||
DECLARE
|
||||
ret Geometry;
|
||||
BEGIN
|
||||
SELECT geom INTO ret
|
||||
FROM (
|
||||
WITH best AS (SELECT s AS q, (SELECT the_geom FROM global_cities_points_limited gp WHERE gp.lowername = lower(p.s) ORDER BY population DESC LIMIT 1) AS geom FROM (SELECT city_name as s) p),
|
||||
next AS (SELECT p.s AS q, (SELECT gp.the_geom FROM global_cities_points_limited gp, global_cities_alternates_limited ga WHERE lower(p.s) = ga.lowername AND ga.geoname_id = gp.geoname_id ORDER BY preferred DESC LIMIT 1) geom FROM (SELECT city_name as s) p WHERE p.s NOT IN (SELECT q FROM best WHERE geom IS NOT NULL))
|
||||
SELECT q, geom, TRUE AS success FROM best WHERE geom IS NOT NULL
|
||||
UNION ALL
|
||||
SELECT q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success FROM next
|
||||
) v;
|
||||
|
||||
RETURN ret;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
---- geocode_namedplace(city_name text, country_name text)
|
||||
|
||||
|
17
server/extension/sql/50_namedplaces_test.sql
Normal file
17
server/extension/sql/50_namedplaces_test.sql
Normal file
@ -0,0 +1,17 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx');
|
||||
|
||||
-- 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(
|
||||
'POINT(0.6983 39.26787)',4326)
|
||||
);
|
||||
|
||||
-- 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(
|
||||
'POINT(0.6983 39.26787)',4326)
|
||||
);
|
||||
|
||||
-- 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(), 'Elche');
|
Loading…
Reference in New Issue
Block a user