dataservices-api/server/extension/sql/50_namedplaces.sql

174 lines
9.9 KiB
MySQL
Raw Normal View History

2016-03-07 20:03:09 +08:00
---- cdb_geocode_namedplace_point(city_name text)
2018-09-10 18:54:37 +08:00
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_namedplace_point(username text, orgname text, city_name text)
2016-03-07 20:03:09 +08:00
RETURNS Geometry AS $$
import spiexceptions
from cartodb_services.tools import Logger,LoggerConfig
plpy.execute("SELECT cdb_dataservices_server._get_logger_config()")
logger_config = GD["logger_config"]
logger = Logger(logger_config)
try:
2018-09-10 18:54:37 +08:00
street_point = plpy.prepare("SELECT cdb_dataservices_server.cdb_geocode_street_point($1, $2, $3) as point;", ["text", "text", "text"])
return plpy.execute(street_point, [username, orgname, city_name])[0]['point']
except spiexceptions.ExternalRoutineException as e:
2018-01-10 18:55:02 +08:00
import sys
logger.error('Error geocoding namedplace using geocode street point, falling back to internal geocoder', sys.exc_info(), data={"username": username, "orgname": orgname})
2018-09-10 18:54:37 +08:00
internal_plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_internal_geocode_namedplace($1, $2, $3) as point;", ["text", "text", "text"])
return plpy.execute(internal_plan, [username, orgname, city_name])[0]['point']
$$ LANGUAGE plpythonu STABLE PARALLEL RESTRICTED;
2016-03-07 20:03:09 +08:00
---- cdb_geocode_namedplace_point(city_name text, country_name text)
2018-09-10 18:54:37 +08:00
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_namedplace_point(username text, orgname text, city_name text, country_name text)
2016-03-07 20:03:09 +08:00
RETURNS Geometry AS $$
import spiexceptions
from cartodb_services.tools import Logger,LoggerConfig
plpy.execute("SELECT cdb_dataservices_server._get_logger_config()")
logger_config = GD["logger_config"]
logger = Logger(logger_config)
try:
2018-09-10 18:54:37 +08:00
street_point = plpy.prepare("SELECT cdb_dataservices_server.cdb_geocode_street_point($1, $2, $3, NULL, NULL, $4) as point;", ["text", "text", "text", "text"])
return plpy.execute(street_point, [username, orgname, city_name, country_name])[0]['point']
except spiexceptions.ExternalRoutineException as e:
2018-01-10 18:55:02 +08:00
import sys
logger.error('Error geocoding namedplace using geocode street point, falling back to internal geocoder', sys.exc_info(), data={"username": username, "orgname": orgname})
2018-09-10 18:54:37 +08:00
internal_plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_internal_geocode_namedplace($1, $2, $3, NULL, $4) as point;", ["text", "text", "text", "text"])
return plpy.execute(internal_plan, [username, orgname, city_name, country_name])[0]['point']
$$ LANGUAGE plpythonu STABLE PARALLEL RESTRICTED;
---- cdb_geocode_namedplace_point(city_name text, admin1_name text, country_name text)
2018-09-10 18:54:37 +08:00
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_namedplace_point(username text, orgname text, city_name text, admin1_name text, country_name text)
RETURNS Geometry AS $$
import spiexceptions
from cartodb_services.tools import Logger,LoggerConfig
plpy.execute("SELECT cdb_dataservices_server._get_logger_config()")
logger_config = GD["logger_config"]
logger = Logger(logger_config)
try:
2018-09-10 18:54:37 +08:00
street_point = plpy.prepare("SELECT cdb_dataservices_server.cdb_geocode_street_point($1, $2, $3, NULL, $4, $5) as point;", ["text", "text", "text", "text", "text"])
return plpy.execute(street_point, [username, orgname, city_name, admin1_name, country_name])[0]['point']
except spiexceptions.ExternalRoutineException as e:
2018-01-10 18:55:02 +08:00
import sys
logger.error('Error geocoding namedplace using geocode street point, falling back to internal geocoder', sys.exc_info(), data={"username": username, "orgname": orgname})
2018-09-10 18:54:37 +08:00
internal_plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_internal_geocode_namedplace($1, $2, $3, $4, $5) as point;", ["text", "text", "text", "text", "text"])
return plpy.execute(internal_plan, [username, orgname, city_name, admin1_name, country_name])[0]['point']
$$ LANGUAGE plpythonu STABLE PARALLEL RESTRICTED;
2018-09-10 18:54:37 +08:00
CREATE OR REPLACE FUNCTION cdb_dataservices_server._cdb_internal_geocode_namedplace(username text, orgname text, city_name text, admin1_name text DEFAULT NULL, country_name text DEFAULT NULL)
2016-03-07 20:03:09 +08:00
RETURNS Geometry AS $$
from cartodb_services.metrics import QuotaService
from cartodb_services.metrics import InternalGeocoderConfig, metrics
from cartodb_services.tools import Logger,LoggerConfig
2016-03-07 20:03:09 +08:00
plpy.execute("SELECT cdb_dataservices_server._connect_to_redis('{0}')".format(username))
redis_conn = GD["redis_connection_{0}".format(username)]['redis_metrics_connection']
plpy.execute("SELECT cdb_dataservices_server._get_internal_geocoder_config({0}, {1})".format(plpy.quote_nullable(username), plpy.quote_nullable(orgname)))
user_geocoder_config = GD["user_internal_geocoder_config_{0}".format(username)]
2016-03-07 20:03:09 +08:00
plpy.execute("SELECT cdb_dataservices_server._get_logger_config()")
logger_config = GD["logger_config"]
logger = Logger(logger_config)
quota_service = QuotaService(user_geocoder_config, redis_conn)
2018-09-10 18:54:37 +08:00
params = {'username': username, 'orgname': orgname, 'city_name': city_name, 'admin1_name': admin1_name, 'country_name': country_name}
2018-09-06 19:47:50 +08:00
with metrics('cdb_geocode_namedplace_point', user_geocoder_config, logger, params):
try:
if admin1_name and country_name:
plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_geocode_namedplace_point(trim($1), trim($2), trim($3)) AS mypoint", ["text", "text", "text"])
rv = plpy.execute(plan, [city_name, admin1_name, country_name], 1)
elif country_name:
plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_geocode_namedplace_point(trim($1), trim($2)) AS mypoint", ["text", "text"])
rv = plpy.execute(plan, [city_name, country_name], 1)
else:
plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_geocode_namedplace_point(trim($1)) AS mypoint", ["text"])
rv = plpy.execute(plan, [city_name], 1)
result = rv[0]["mypoint"]
if result:
quota_service.increment_success_service_use()
return result
else:
quota_service.increment_empty_service_use()
return None
except BaseException as e:
import sys
quota_service.increment_failed_service_use()
logger.error('Error trying to geocode namedplace point', sys.exc_info(), data={"username": username, "orgname": orgname})
raise Exception('Error trying to geocode namedplace point')
finally:
quota_service.increment_total_service_use()
$$ LANGUAGE plpythonu STABLE PARALLEL RESTRICTED;
2016-03-07 20:03:09 +08:00
--------------------------------------------------------------------------------
-- Implementation of the server extension
-- Note: these functions depend on the cdb_geocoder extension
---- cdb_geocode_namedplace_point(city_name text)
CREATE OR REPLACE FUNCTION cdb_dataservices_server._cdb_geocode_namedplace_point(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 STABLE PARALLEL SAFE;
2016-03-07 20:03:09 +08:00
---- cdb_geocode_namedplace_point(city_name text, country_name text)
CREATE OR REPLACE FUNCTION cdb_dataservices_server._cdb_geocode_namedplace_point(city_name text, country_name text)
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;
RETURN ret;
END
$$ LANGUAGE plpgsql STABLE PARALLEL SAFE;
2016-03-07 20:03:09 +08:00
---- cdb_geocode_namedplace_point(city_name text, admin1_name text, country_name text)
CREATE OR REPLACE FUNCTION cdb_dataservices_server._cdb_geocode_namedplace_point(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 STABLE PARALLEL SAFE;
2016-03-07 20:03:09 +08:00