-- Complain if script is sourced in psql, rather than via CREATE EXTENSION \echo Use "CREATE EXTENSION cdb_geocoder_server" to load this file. \quit CREATE TYPE cdb_geocoder_server._redis_conf_params AS ( sentinel_host text, sentinel_port int, sentinel_master_id text, redis_db text, timeout float ); -- Get the Redis configuration from the _conf table -- CREATE OR REPLACE FUNCTION cdb_geocoder_server._get_redis_conf() RETURNS cdb_geocoder_server._redis_conf_params AS $$ conf = plpy.execute("SELECT cartodb.CDB_Conf_GetConf('redis_conf') conf")[0]['conf'] if conf is None: plpy.error("There is no redis configuration defined") else: import json params = json.loads(conf) return { "sentinel_host": params['sentinel_host'], "sentinel_port": params['sentinel_port'], "sentinel_master_id": params['sentinel_master_id'], "timeout": params['timeout'], "redis_db": params['redis_db'] } $$ LANGUAGE plpythonu; -- Get the connection to redis from cache or create a new one CREATE OR REPLACE FUNCTION cdb_geocoder_server._connect_to_redis(user_id text) RETURNS boolean AS $$ if user_id in GD and 'redis_connection' in GD[user_id]: return False else: from cartodb_geocoder import redis_helper config_params = plpy.execute("""select c.sentinel_host, c.sentinel_port, c.sentinel_master_id, c.timeout, c.redis_db from cdb_geocoder_server._get_redis_conf() c;""")[0] redis_connection = redis_helper.RedisHelper(config_params['sentinel_host'], config_params['sentinel_port'], config_params['sentinel_master_id'], timeout=config_params['timeout'], redis_db=config_params['redis_db']).redis_connection() GD[user_id] = {'redis_connection': redis_connection} return True $$ LANGUAGE plpythonu;-- Geocodes a street address given a searchtext and a state and/or country CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_street_point(searchtext TEXT, city TEXT DEFAULT NULL, state_province TEXT DEFAULT NULL, country TEXT DEFAULT NULL) RETURNS Geometry AS $$ import json from heremaps import heremapsgeocoder heremaps_conf = json.loads(plpy.execute("SELECT cdb_geocoder_server._get_conf('heremaps')", 1)[0]['get_conf']) app_id = heremaps_conf['geocoder']['app_id'] app_code = heremaps_conf['geocoder']['app_code'] geocoder = heremapsgeocoder.Geocoder(app_id, app_code) results = geocoder.geocode_address(searchtext=searchtext, city=city, state=state_province, country=country) coordinates = geocoder.extract_lng_lat_from_result(results[0]) plan = plpy.prepare("SELECT ST_SetSRID(ST_MakePoint($1, $2), 4326); ", ["double precision", "double precision"]) point = plpy.execute(plan, [coordinates[0], coordinates[1]], 1)[0] return point['st_setsrid'] $$ LANGUAGE plpythonu;-- Interface of the server extension CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_admin0_polygon(username text, orgname text, country_name text) RETURNS Geometry AS $$ plpy.debug('Entering cdb_geocode_admin0_polygons') plpy.debug('user = %s' % username) #--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._cdb_geocode_admin0_polygon($1) AS mypolygon", ["text"]) rv = plpy.execute(plan, [country_name], 1) plpy.debug('Returning from Returning from cdb_geocode_admin0_polygons') return rv[0]["mypolygon"] $$ LANGUAGE plpythonu; -------------------------------------------------------------------------------- -- Implementation of the server extension -- Note: these functions depend on the cdb_geocoder extension CREATE OR REPLACE FUNCTION cdb_geocoder_server._cdb_geocode_admin0_polygon(country_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; BEGIN SELECT n.the_geom as geom INTO ret FROM (SELECT q, lower(regexp_replace(q, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text x FROM (SELECT country_name q) g) d LEFT OUTER JOIN admin0_synonyms s ON name_ = d.x LEFT OUTER JOIN ne_admin0_v3 n ON s.adm0_a3 = n.adm0_a3 GROUP BY d.q, n.the_geom, s.adm0_a3; RETURN ret; END $$ LANGUAGE plpgsql; -- Interfacess of the server extension ---- cdb_geocode_admin1_polygon(admin1_name text) CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_admin1_polygon(username text, orgname text, admin1_name text) RETURNS Geometry AS $$ plpy.debug('Entering cdb_geocode_admin1_polygon(admin1_name text)') plpy.debug('user = %s' % username) #--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._cdb_geocode_admin1_polygon($1) AS mypolygon", ["text"]) rv = plpy.execute(plan, [admin1_name], 1) plpy.debug('Returning from Returning from cdb_geocode_admin1_polygons') return rv[0]["mypolygon"] $$ LANGUAGE plpythonu; ---- cdb_geocode_admin1_polygon(admin1_name text, country_name text) CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_admin1_polygon(username text, orgname text, admin1_name text, country_name text) RETURNS Geometry AS $$ plpy.debug('Entering cdb_geocode_admin1_polygon(admin1_name text, country_name text)') plpy.debug('user = %s' % username) #--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._cdb_geocode_admin1_polygon($1, $2) AS mypolygon", ["text", "text"]) rv = plpy.execute(plan, [admin1_name, country_name], 1) plpy.debug('Returning from Returning from cdb_geocode_admin1_polygon(admin1_name text, country_name text)') return rv[0]["mypolygon"] $$ LANGUAGE plpythonu; -------------------------------------------------------------------------------- -- Implementation of the server extension -- Note: these functions depend on the cdb_geocoder extension ---- cdb_geocode_admin1_polygon(admin1_name text) CREATE OR REPLACE FUNCTION cdb_geocoder_server._cdb_geocode_admin1_polygon(admin1_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; BEGIN SELECT geom INTO ret FROM ( SELECT q, ( SELECT the_geom FROM global_province_polygons WHERE d.c = ANY (synonyms) ORDER BY frequency DESC LIMIT 1 ) geom FROM ( SELECT trim(replace(lower(admin1_name),'.',' ')) c, admin1_name q ) d ) v; RETURN ret; END $$ LANGUAGE plpgsql; ---- cdb_geocode_admin1_polygon(admin1_name text, country_name text) CREATE OR REPLACE FUNCTION cdb_geocoder_server._cdb_geocode_admin1_polygon(admin1_name text, country_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; BEGIN WITH p AS (SELECT r.c, r.q, (SELECT iso3 FROM country_decoder WHERE lower(country_name) = ANY (synonyms)) i FROM (SELECT trim(replace(lower(admin1_name),'.',' ')) c, country_name q) r) SELECT geom INTO ret FROM ( SELECT q, ( SELECT the_geom FROM global_province_polygons WHERE p.c = ANY (synonyms) AND iso3 = p.i ORDER BY frequency DESC LIMIT 1 ) geom FROM p) n; RETURN ret; END $$ LANGUAGE plpgsql; -- Interfacess of the server extension ---- cdb_geocode_namedplace_point(city_name text) CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_namedplace_point(username text, orgname text, city_name text) RETURNS Geometry AS $$ plpy.debug('Entering cdb_geocode_namedplace_point(city_name text)') plpy.debug('user = %s' % username) #--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._cdb_geocode_namedplace_point($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; ---- cdb_geocode_namedplace_point(city_name text, country_name text) CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_namedplace_point(username text, orgname text, city_name text, country_name text) RETURNS Geometry AS $$ plpy.debug('Entering cdb_geocode_namedplace_point(city_name text, country_name text)') plpy.debug('user = %s' % username) #--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._cdb_geocode_namedplace_point($1, $2) AS mypoint", ["text", "text"]) rv = plpy.execute(plan, [city_name, country_name], 1) plpy.debug('Returning from Returning from geocode_namedplace') return rv[0]["mypoint"] $$ LANGUAGE plpythonu; ---- cdb_geocode_namedplace_point(city_name text, admin1_name text, country_name text) CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_namedplace_point(username text, orgname text, city_name text, admin1_name text, country_name text) RETURNS Geometry AS $$ plpy.debug('Entering cdb_geocode_namedplace_point(city_name text, admin1_name text, country_name text)') plpy.debug('user = %s' % username) #--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._cdb_geocode_namedplace_point($1, $2, $3) AS mypoint", ["text", "text", "text"]) 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; -------------------------------------------------------------------------------- -- 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_geocoder_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; ---- cdb_geocode_namedplace_point(city_name text, country_name text) CREATE OR REPLACE FUNCTION cdb_geocoder_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; ---- cdb_geocode_namedplace_point(city_name text, admin1_name text, country_name text) CREATE OR REPLACE FUNCTION cdb_geocoder_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; -- Interface of the server extension CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_postalcode_point(username text, orgname text, code text) RETURNS Geometry AS $$ plpy.debug('Entering _cdb_geocode_postalcode_point') plpy.debug('user = %s' % username) #--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._cdb_geocode_postalcode_point($1) AS point", ["text"]) rv = plpy.execute(plan, [code], 1) plpy.debug('Returning from _cdb_geocode_postalcode_point') return rv[0]["point"] $$ LANGUAGE plpythonu; CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_postalcode_point(username text, orgname text, code text, country text) RETURNS Geometry AS $$ plpy.debug('Entering _cdb_geocode_postalcode_point') plpy.debug('user = %s' % username) #--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._cdb_geocode_postalcode_point($1, $2) AS point", ["TEXT", "TEXT"]) rv = plpy.execute(plan, [code, country], 1) plpy.debug('Returning from _cdb_geocode_postalcode_point') return rv[0]["point"] $$ LANGUAGE plpythonu; CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_postalcode_polygon(username text, orgname text, code text) RETURNS Geometry AS $$ plpy.debug('Entering _cdb_geocode_postalcode_polygon') plpy.debug('user = %s' % username) #--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._cdb_geocode_postalcode_polygon($1) AS polygon", ["text"]) rv = plpy.execute(plan, [code], 1) plpy.debug('Returning from _cdb_geocode_postalcode_polygon') return rv[0]["polygon"] $$ LANGUAGE plpythonu; CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_postalcode_polygon(username text, orgname text, code text, country text) RETURNS Geometry AS $$ plpy.debug('Entering _cdb_geocode_postalcode_point') plpy.debug('user = %s' % username) #--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._cdb_geocode_postalcode_polygon($1, $2) AS polygon", ["TEXT", "TEXT"]) rv = plpy.execute(plan, [code, country], 1) plpy.debug('Returning from _cdb_geocode_postalcode_point') return rv[0]["polygon"] $$ LANGUAGE plpythonu; -------------------------------------------------------------------------------- -- Implementation of the server extension -- Note: these functions depend on the cdb_geocoder extension CREATE OR REPLACE FUNCTION cdb_geocoder_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_geocoder_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_geocoder_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_geocoder_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; -- Interface of the server extension CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_ipaddress_point(username text, orgname text, ip text) RETURNS Geometry AS $$ plpy.debug('Entering _cdb_geocode_ipaddress_point') plpy.debug('user = %s' % username) #--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._cdb_geocode_ipaddress_point($1) AS point", ["TEXT"]) rv = plpy.execute(plan, [ip], 1) plpy.debug('Returning from _cdb_geocode_ipaddress_point') return rv[0]["point"] $$ LANGUAGE plpythonu; -------------------------------------------------------------------------------- -- Implementation of the server extension -- Note: these functions depend on the cdb_geocoder extension CREATE OR REPLACE FUNCTION cdb_geocoder_server._cdb_geocode_ipaddress_point(ip text) RETURNS Geometry AS $$ DECLARE ret Geometry; new_ip INET; BEGIN BEGIN IF family(ip::inet) = 6 THEN new_ip := ip::inet; ELSE new_ip := ('::ffff:' || ip)::inet; END IF; EXCEPTION WHEN OTHERS THEN SELECT NULL as geom INTO ret; RETURN ret; END; WITH ips AS (SELECT ip s, new_ip net), matches AS (SELECT s, (SELECT the_geom FROM ip_address_locations WHERE network_start_ip <= ips.net ORDER BY network_start_ip DESC LIMIT 1) geom FROM ips) SELECT geom INTO ret FROM matches; RETURN ret; END $$ LANGUAGE plpgsql; DO $$ BEGIN IF NOT EXISTS ( SELECT * FROM pg_catalog.pg_user WHERE usename = 'geocoder_api') THEN CREATE USER geocoder_api; END IF; GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA cdb_geocoder_server TO geocoder_api; GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO geocoder_api; GRANT USAGE ON SCHEMA cdb_geocoder_server TO geocoder_api; GRANT USAGE ON SCHEMA public TO geocoder_api; GRANT SELECT ON ALL TABLES IN SCHEMA public TO geocoder_api; END$$;