2015-11-11 23:29:17 +08:00
|
|
|
-- Interfacess of the server extension
|
|
|
|
|
2015-11-12 18:29:25 +08:00
|
|
|
---- geocode_namedplace_point(city_name text)
|
|
|
|
CREATE OR REPLACE FUNCTION geocode_namedplace_point(user_id name, tx_id bigint, city_name text)
|
2015-11-11 23:29:17 +08:00
|
|
|
RETURNS Geometry AS $$
|
2015-11-12 18:29:25 +08:00
|
|
|
plpy.debug('Entering geocode_namedplace_point(city_name text)')
|
2015-11-11 23:29:17 +08:00
|
|
|
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
|
2015-11-12 18:29:25 +08:00
|
|
|
plan = plpy.prepare("SELECT cdb_geocoder_server._geocode_namedplace_point($1) AS mypoint", ["text"])
|
2015-11-11 23:29:17 +08:00
|
|
|
rv = plpy.execute(plan, [city_name], 1)
|
|
|
|
|
|
|
|
plpy.debug('Returning from Returning from geocode_namedplace')
|
|
|
|
return rv[0]["mypoint"]
|
|
|
|
$$ LANGUAGE plpythonu;
|
|
|
|
|
2015-11-12 18:29:25 +08:00
|
|
|
---- geocode_namedplace_point(city_name text, country_name text)
|
|
|
|
CREATE OR REPLACE FUNCTION geocode_namedplace_point(user_id name, tx_id bigint, city_name text, country_name text)
|
2015-11-12 00:17:18 +08:00
|
|
|
RETURNS Geometry AS $$
|
2015-11-12 18:29:25 +08:00
|
|
|
plpy.debug('Entering geocode_namedplace_point(city_name text, country_name text)')
|
2015-11-12 00:17:18 +08:00
|
|
|
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
|
2015-11-12 18:29:25 +08:00
|
|
|
plan = plpy.prepare("SELECT cdb_geocoder_server._geocode_namedplace_point($1, $2) AS mypoint", ["text", "text"])
|
2015-11-12 00:17:18 +08:00
|
|
|
rv = plpy.execute(plan, [city_name, country_name], 1)
|
|
|
|
|
|
|
|
plpy.debug('Returning from Returning from geocode_namedplace')
|
|
|
|
return rv[0]["mypoint"]
|
|
|
|
$$ LANGUAGE plpythonu;
|
2015-11-11 23:29:17 +08:00
|
|
|
|
2015-11-12 18:29:25 +08:00
|
|
|
---- geocode_namedplace_point(city_name text, admin1_name text, country_name text)
|
|
|
|
CREATE OR REPLACE FUNCTION geocode_namedplace_point(user_id name, tx_id bigint, city_name text, admin1_name text, country_name text)
|
2015-11-12 01:14:22 +08:00
|
|
|
RETURNS Geometry AS $$
|
2015-11-12 18:29:25 +08:00
|
|
|
plpy.debug('Entering geocode_namedplace_point(city_name text, admin1_name text, country_name text)')
|
2015-11-12 01:14:22 +08:00
|
|
|
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
|
2015-11-12 18:29:25 +08:00
|
|
|
plan = plpy.prepare("SELECT cdb_geocoder_server._geocode_namedplace_point($1, $2, $3) AS mypoint", ["text", "text", "text"])
|
2015-11-12 01:14:22 +08:00
|
|
|
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;
|
|
|
|
|
2015-11-11 23:29:17 +08:00
|
|
|
--------------------------------------------------------------------------------
|
|
|
|
|
|
|
|
-- Implementation of the server extension
|
|
|
|
-- Note: these functions depend on the cdb_geocoder extension
|
|
|
|
|
2015-11-12 18:29:25 +08:00
|
|
|
---- geocode_namedplace_point(city_name text)
|
|
|
|
CREATE OR REPLACE FUNCTION _geocode_namedplace_point(city_name text)
|
2015-11-11 23:29:17 +08:00
|
|
|
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;
|
|
|
|
|
2015-11-12 18:29:25 +08:00
|
|
|
---- geocode_namedplace_point(city_name text, country_name text)
|
|
|
|
CREATE OR REPLACE FUNCTION _geocode_namedplace_point(city_name text, country_name text)
|
2015-11-12 00:17:18 +08:00
|
|
|
RETURNS Geometry AS $$
|
|
|
|
DECLARE
|
|
|
|
ret Geometry;
|
|
|
|
BEGIN
|
|
|
|
SELECT geom INTO ret
|
|
|
|
FROM (
|
|
|
|
WITH p AS (SELECT r.s, r.c, (SELECT iso2 FROM country_decoder WHERE lower(r.c) = ANY (synonyms)) i FROM (SELECT city_name AS s, country_name::text AS c) r),
|
|
|
|
best AS (SELECT p.s AS q, p.c AS c, (SELECT gp.the_geom AS geom FROM global_cities_points_limited gp WHERE gp.lowername = lower(p.s) AND gp.iso2 = p.i ORDER BY population DESC LIMIT 1) AS geom FROM p),
|
|
|
|
next AS (SELECT p.s AS q, p.c AS c, (SELECT gp.the_geom FROM global_cities_points_limited gp, global_cities_alternates_limited ga WHERE lower(p.s) = ga.lowername AND gp.iso2 = 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 c = p.c AND geom IS NOT NULL))
|
|
|
|
SELECT geom FROM best WHERE geom IS NOT NULL
|
|
|
|
UNION ALL
|
|
|
|
SELECT geom FROM next
|
|
|
|
) v;
|
2015-11-11 23:29:17 +08:00
|
|
|
|
2015-11-12 00:17:18 +08:00
|
|
|
RETURN ret;
|
|
|
|
END
|
|
|
|
$$ LANGUAGE plpgsql;
|
2015-11-11 23:29:17 +08:00
|
|
|
|
2015-11-12 18:29:25 +08:00
|
|
|
---- geocode_namedplace_point(city_name text, admin1_name text, country_name text)
|
|
|
|
CREATE OR REPLACE FUNCTION _geocode_namedplace_point(city_name text, admin1_name text, country_name text)
|
2015-11-12 01:14:22 +08:00
|
|
|
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;
|
|
|
|
|