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 QuotaService from cartodb_services.metrics import InternalGeocoderConfig plpy.execute("SELECT cdb_dataservices_server._connect_to_redis('{0}')".format(username)) redis_conn = GD["redis_connection_{0}".format(username)]['redis_metrics_connection'] user_geocoder_config = InternalGeocoderConfig(redis_conn, username, orgname) quota_service = QuotaService(user_geocoder_config, redis_conn) 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_geocoder_use() return result else: quota_service.increment_empty_geocoder_use() return None except BaseException as e: import sys, traceback type_, value_, traceback_ = sys.exc_info() quota_service.increment_failed_geocoder_use() error_msg = 'There was an error trying to geocode using admin0 geocoder: {0}'.format(e) plpy.notice(traceback.format_tb(traceback_)) plpy.error(error_msg) finally: quota_service.increment_total_geocoder_use() $$ LANGUAGE plpythonu; 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 QuotaService from cartodb_services.metrics import InternalGeocoderConfig plpy.execute("SELECT cdb_dataservices_server._connect_to_redis('{0}')".format(username)) redis_conn = GD["redis_connection_{0}".format(username)]['redis_metrics_connection'] user_geocoder_config = InternalGeocoderConfig(redis_conn, username, orgname) quota_service = QuotaService(user_geocoder_config, redis_conn) 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_geocoder_use() return result else: quota_service.increment_empty_geocoder_use() return None except BaseException as e: import sys, traceback type_, value_, traceback_ = sys.exc_info() quota_service.increment_failed_geocoder_use() error_msg = 'There was an error trying to geocode using admin0 geocoder: {0}'.format(e) plpy.notice(traceback.format_tb(traceback_)) plpy.error(error_msg) finally: quota_service.increment_total_geocoder_use() $$ LANGUAGE plpythonu; 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 QuotaService from cartodb_services.metrics import InternalGeocoderConfig plpy.execute("SELECT cdb_dataservices_server._connect_to_redis('{0}')".format(username)) redis_conn = GD["redis_connection_{0}".format(username)]['redis_metrics_connection'] user_geocoder_config = InternalGeocoderConfig(redis_conn, username, orgname) quota_service = QuotaService(user_geocoder_config, redis_conn) 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_geocoder_use() return result else: quota_service.increment_empty_geocoder_use() return None except BaseException as e: import sys, traceback type_, value_, traceback_ = sys.exc_info() quota_service.increment_failed_geocoder_use() error_msg = 'There was an error trying to geocode using admin0 geocoder: {0}'.format(e) plpy.notice(traceback.format_tb(traceback_)) plpy.error(error_msg) finally: quota_service.increment_total_geocoder_use() $$ LANGUAGE plpythonu; 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 QuotaService from cartodb_services.metrics import InternalGeocoderConfig plpy.execute("SELECT cdb_dataservices_server._connect_to_redis('{0}')".format(username)) redis_conn = GD["redis_connection_{0}".format(username)]['redis_metrics_connection'] user_geocoder_config = InternalGeocoderConfig(redis_conn, username, orgname) quota_service = QuotaService(user_geocoder_config, redis_conn) 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_geocoder_use() return result else: quota_service.increment_empty_geocoder_use() return None except BaseException as e: import sys, traceback type_, value_, traceback_ = sys.exc_info() quota_service.increment_failed_geocoder_use() error_msg = 'There was an error trying to geocode using admin0 geocoder: {0}'.format(e) plpy.notice(traceback.format_tb(traceback_)) plpy.error(error_msg) finally: quota_service.increment_total_geocoder_use() $$ LANGUAGE plpythonu; -------------------------------------------------------------------------------- -- 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; 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; 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; 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;