dataservices-api/server/extension/sql/60_postalcodes.sql
manmorjim dd907ac2bc Using @@plpythonu@@ variable
PG12 migration #6237
2020-02-24 16:12:27 +01:00

267 lines
11 KiB
PL/PgSQL

CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_postalcode_point(username text, orgname text, code text)
RETURNS Geometry AS $$
from cartodb_services.metrics import metrics
from cartodb_services.metrics import QuotaService
from cartodb_services.metrics import InternalGeocoderConfig
from cartodb_services.tools import Logger,LoggerConfig
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)]
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)
params = {'username': username, 'orgname': orgname, 'code': code}
with metrics('cdb_geocode_postalcode_point', user_geocoder_config, logger, params):
try:
plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_geocode_postalcode_point(trim($1)) AS mypoint", ["text"])
rv = plpy.execute(plan, [code], 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 postal code point', sys.exc_info(), data={"username": username, "orgname": orgname})
raise Exception('Error trying to geocode postal code point')
finally:
quota_service.increment_total_service_use()
$$ LANGUAGE @@plpythonu@@ STABLE PARALLEL RESTRICTED;
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_postalcode_point(username text, orgname text, code double precision)
RETURNS Geometry AS $$
SELECT cdb_dataservices_server.cdb_geocode_postalcode_point(username, orgname, code::text);
$$ LANGUAGE SQL STABLE PARALLEL RESTRICTED;
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_postalcode_point(username text, orgname text, code text, country text)
RETURNS Geometry AS $$
from cartodb_services.metrics import metrics
from cartodb_services.metrics import QuotaService
from cartodb_services.metrics import InternalGeocoderConfig
from cartodb_services.tools import Logger,LoggerConfig
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)]
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)
with metrics('cdb_geocode_postalcode_point', user_geocoder_config, logger):
try:
plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_geocode_postalcode_point(trim($1), trim($2)) AS mypoint", ["TEXT", "TEXT"])
rv = plpy.execute(plan, [code, country], 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 postal code point', sys.exc_info(), data={"username": username, "orgname": orgname})
raise Exception('Error trying to geocode postal code point')
finally:
quota_service.increment_total_service_use()
$$ LANGUAGE @@plpythonu@@ STABLE PARALLEL RESTRICTED;
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_postalcode_point(username text, orgname text, code double precision, country text)
RETURNS Geometry AS $$
SELECT cdb_dataservices_server.cdb_geocode_postalcode_point(username, orgname, code::text, country);
$$ LANGUAGE SQL STABLE PARALLEL RESTRICTED;
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_postalcode_polygon(username text, orgname text, code text)
RETURNS Geometry AS $$
from cartodb_services.metrics import metrics
from cartodb_services.metrics import QuotaService
from cartodb_services.metrics import InternalGeocoderConfig
from cartodb_services.tools import Logger,LoggerConfig
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)]
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)
with metrics('cdb_geocode_postalcode_point', user_geocoder_config, logger):
try:
plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_geocode_postalcode_polygon(trim($1)) AS mypolygon", ["text"])
rv = plpy.execute(plan, [code], 1)
result = rv[0]["mypolygon"]
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 postal code polygon', sys.exc_info(), data={"username": username, "orgname": orgname})
raise Exception('Error trying to geocode postal code polygon')
finally:
quota_service.increment_total_service_use()
$$ LANGUAGE @@plpythonu@@ STABLE PARALLEL RESTRICTED;
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_postalcode_polygon(username text, orgname text, code double precision)
RETURNS Geometry AS $$
SELECT cdb_dataservices_server.cdb_geocode_postalcode_polygon(username, orgname, code::text)
$$ LANGUAGE SQL STABLE PARALLEL RESTRICTED;
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_postalcode_polygon(username text, orgname text, code text, country text)
RETURNS Geometry AS $$
from cartodb_services.metrics import metrics
from cartodb_services.metrics import QuotaService
from cartodb_services.metrics import InternalGeocoderConfig
from cartodb_services.tools import Logger,LoggerConfig
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)]
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)
with metrics('cdb_geocode_postalcode_point', user_geocoder_config, logger):
try:
plan = plpy.prepare("SELECT cdb_dataservices_server._cdb_geocode_postalcode_polygon(trim($1), trim($2)) AS mypolygon", ["TEXT", "TEXT"])
rv = plpy.execute(plan, [code, country], 1)
result = rv[0]["mypolygon"]
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 postal code polygon', sys.exc_info(), data={"username": username, "orgname": orgname})
raise Exception('Error trying to geocode postal code polygon')
finally:
quota_service.increment_total_service_use()
$$ LANGUAGE @@plpythonu@@ STABLE PARALLEL RESTRICTED;
CREATE OR REPLACE FUNCTION cdb_dataservices_server.cdb_geocode_postalcode_polygon(username text, orgname text, code double precision, country text)
RETURNS Geometry AS $$
SELECT cdb_dataservices_server.cdb_geocode_postalcode_polygon(username, orgname, code::text, country);
$$ LANGUAGE SQL STABLE PARALLEL RESTRICTED;
--------------------------------------------------------------------------------
-- Implementation of the server extension
-- Note: these functions depend on the cdb_geocoder extension
CREATE OR REPLACE FUNCTION cdb_dataservices_server._cdb_geocode_postalcode_point(code 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)
LIMIT 1
) geom
FROM (SELECT code q) d
) v;
RETURN ret;
END
$$ LANGUAGE plpgsql STABLE PARALLEL SAFE;
CREATE OR REPLACE FUNCTION cdb_dataservices_server._cdb_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 STABLE PARALLEL SAFE;
CREATE OR REPLACE FUNCTION cdb_dataservices_server._cdb_geocode_postalcode_polygon(code text)
RETURNS Geometry AS $$
DECLARE
ret Geometry;
BEGIN
SELECT geom INTO ret
FROM (
SELECT
q, (
SELECT the_geom
FROM global_postal_code_polygons
WHERE postal_code = upper(d.q)
LIMIT 1
) geom
FROM (SELECT code q) d
) v;
RETURN ret;
END
$$ LANGUAGE plpgsql STABLE PARALLEL SAFE;
CREATE OR REPLACE FUNCTION cdb_dataservices_server._cdb_geocode_postalcode_polygon(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_polygons
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 STABLE PARALLEL SAFE;