Versioned the server tests and created the upgrade and downgrade files
This commit is contained in:
parent
c0cef3dc80
commit
db3eaf31ad
4
server/extension/.gitignore
vendored
4
server/extension/.gitignore
vendored
@ -2,6 +2,4 @@ results/
|
||||
regression.diffs
|
||||
regression.out
|
||||
cdb_geocoder_server--0.0.1.sql
|
||||
cdb_geocoder_server--0.1.0.sql
|
||||
cdb_geocoder_server--0.0.1--0.1.0.sql
|
||||
|
||||
cdb_geocoder_server--0.1.0.sql
|
@ -2,22 +2,13 @@
|
||||
# Once a version is released, it is not meant to be changed. E.g: once version 0.0.1 is out, it SHALL NOT be changed.
|
||||
EXTENSION = cdb_geocoder_server
|
||||
EXTVERSION = $(shell grep default_version $(EXTENSION).control | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/")
|
||||
SED = sed
|
||||
|
||||
UPGRADABLE = \
|
||||
0.0.1 \
|
||||
$(END)
|
||||
|
||||
UPGRADES = \
|
||||
$(shell echo $(UPGRADABLE) | \
|
||||
$(SED) 's/^/$(EXTENSION)--/' | \
|
||||
$(SED) 's/$$/--$(EXTVERSION).sql/' | \
|
||||
$(SED) 's/ /--$(EXTVERSION).sql $(EXTENSION)--/g')
|
||||
|
||||
DATA = $(EXTENSION)--$(EXTVERSION).sql \
|
||||
$(UPGRADES)
|
||||
|
||||
REGRESS = $(notdir $(basename $(wildcard sql/*test.sql)))
|
||||
REGRESS = $(notdir $(basename $(wildcard test/$(EXTVERSION)/sql/*test.sql)))
|
||||
TEST_DIR = test/$(EXTVERSION)
|
||||
REGRESS_OPTS = --inputdir='$(TEST_DIR)' --outputdir='$(TEST_DIR)'
|
||||
|
||||
# postgres build stuff
|
||||
PG_CONFIG = pg_config
|
||||
@ -30,9 +21,6 @@ $(DATA): $(SOURCES_DATA)
|
||||
rm -f $@
|
||||
cat $(SOURCES_DATA) >> $@
|
||||
|
||||
$(EXTENSION)--%--$(EXTVERSION).sql: $(EXTENSION)--$(EXTVERSION).sql
|
||||
cp $< $@
|
||||
|
||||
all: $(DATA)
|
||||
|
||||
# Only meant for development time, do not use once a version is released
|
||||
|
132
server/extension/cdb_geocoder_server--0.0.1--0.1.0.sql
Normal file
132
server/extension/cdb_geocoder_server--0.0.1--0.1.0.sql
Normal file
@ -0,0 +1,132 @@
|
||||
-- Get the Redis configuration from the _conf table --
|
||||
CREATE OR REPLACE FUNCTION cdb_geocoder_server._get_redis_conf_v2(config_key text)
|
||||
RETURNS cdb_geocoder_server._redis_conf_params AS $$
|
||||
conf_query = "SELECT cartodb.CDB_Conf_GetConf('{0}') as conf".format(config_key)
|
||||
conf = plpy.execute(conf_query)[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 $$
|
||||
cache_key = "redis_connection_{0}".format(user_id)
|
||||
if cache_key in GD:
|
||||
return False
|
||||
else:
|
||||
from cartodb_geocoder import redis_helper
|
||||
metadata_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_v2('redis_metadata_config') c;""")[0]
|
||||
metrics_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_v2('redis_metrics_config') c;""")[0]
|
||||
redis_metadata_connection = redis_helper.RedisHelper(metadata_config_params['sentinel_host'],
|
||||
metadata_config_params['sentinel_port'],
|
||||
metadata_config_params['sentinel_master_id'],
|
||||
timeout=metadata_config_params['timeout'],
|
||||
redis_db=metadata_config_params['redis_db']).redis_connection()
|
||||
redis_metrics_connection = redis_helper.RedisHelper(metrics_config_params['sentinel_host'],
|
||||
metrics_config_params['sentinel_port'],
|
||||
metrics_config_params['sentinel_master_id'],
|
||||
timeout=metrics_config_params['timeout'],
|
||||
redis_db=metrics_config_params['redis_db']).redis_connection()
|
||||
GD[cache_key] = {
|
||||
'redis_metadata_connection': redis_metadata_connection,
|
||||
'redis_metrics_connection': redis_metrics_connection,
|
||||
}
|
||||
return True
|
||||
$$ LANGUAGE plpythonu;
|
||||
-- Get the Redis configuration from the _conf table --
|
||||
CREATE OR REPLACE FUNCTION cdb_geocoder_server._get_geocoder_config(username text, orgname text)
|
||||
RETURNS boolean AS $$
|
||||
cache_key = "user_geocoder_config_{0}".format(username)
|
||||
if cache_key in GD:
|
||||
return False
|
||||
else:
|
||||
import json
|
||||
from cartodb_geocoder import config_helper
|
||||
plpy.execute("SELECT cdb_geocoder_server._connect_to_redis('{0}')".format(username))
|
||||
redis_conn = GD["redis_connection_{0}".format(username)]['redis_metadata_connection']
|
||||
heremaps_conf_json = plpy.execute("SELECT cartodb.CDB_Conf_GetConf('heremaps_conf') as heremaps_conf", 1)[0]['heremaps_conf']
|
||||
if not heremaps_conf_json:
|
||||
heremaps_app_id = None
|
||||
heremaps_app_code = None
|
||||
else:
|
||||
heremaps_conf = json.loads(heremaps_conf_json)
|
||||
heremaps_app_id = heremaps_conf['app_id']
|
||||
heremaps_app_code = heremaps_conf['app_code']
|
||||
geocoder_config = config_helper.GeocoderConfig(redis_conn, username, orgname, heremaps_app_id, heremaps_app_code)
|
||||
# --Think about the security concerns with this kind of global cache, it should be only available
|
||||
# --for this user session but...
|
||||
GD[cache_key] = geocoder_config
|
||||
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_v2(username TEXT, orgname TEXT, searchtext TEXT, city TEXT DEFAULT NULL, state_province TEXT DEFAULT NULL, country TEXT DEFAULT NULL)
|
||||
RETURNS Geometry AS $$
|
||||
plpy.execute("SELECT cdb_geocoder_server._connect_to_redis('{0}')".format(username))
|
||||
redis_conn = GD["redis_connection_{0}".format(username)]['redis_metrics_connection']
|
||||
plpy.execute("SELECT cdb_geocoder_server._get_geocoder_config('{0}', '{1}')".format(username, orgname))
|
||||
user_geocoder_config = GD["user_geocoder_config_{0}".format(username)]
|
||||
|
||||
if user_geocoder_config.heremaps_geocoder:
|
||||
here_plan = plpy.prepare("SELECT cdb_geocoder_server._cdb_here_geocode_street_point($1, $2, $3, $4, $5, $6) as point; ", ["text", "text", "text", "text", "text", "text"])
|
||||
return plpy.execute(here_plan, [username, orgname, searchtext, city, state_province, country], 1)[0]['point']
|
||||
elif user_geocoder_config.google_geocoder:
|
||||
google_plan = plpy.prepare("SELECT cdb_geocoder_server._cdb_google_geocode_street_point($1, $2, $3, $4, $5, $6) as point; ", ["text", "text", "text", "text", "text", "text"])
|
||||
return plpy.execute(google_plan, [username, orgname, searchtext, city, state_province, country], 1)[0]['point']
|
||||
else:
|
||||
plpy.error('Requested geocoder is not available')
|
||||
|
||||
$$ LANGUAGE plpythonu;
|
||||
|
||||
CREATE OR REPLACE FUNCTION cdb_geocoder_server._cdb_here_geocode_street_point(username TEXT, orgname TEXT, searchtext TEXT, city TEXT DEFAULT NULL, state_province TEXT DEFAULT NULL, country TEXT DEFAULT NULL)
|
||||
RETURNS Geometry AS $$
|
||||
from heremaps import heremapsgeocoder
|
||||
from cartodb_geocoder import quota_service
|
||||
|
||||
redis_conn = GD["redis_connection_{0}".format(username)]['redis_metrics_connection']
|
||||
user_geocoder_config = GD["user_geocoder_config_{0}".format(username)]
|
||||
|
||||
# -- Check the quota
|
||||
quota_service = quota_service.QuotaService(user_geocoder_config, redis_conn)
|
||||
if not quota_service.check_user_quota():
|
||||
plpy.error('You have reach the limit of your quota')
|
||||
|
||||
try:
|
||||
geocoder = heremapsgeocoder.Geocoder(user_geocoder_config.heremaps_app_id, user_geocoder_config.heremaps_app_code)
|
||||
results = geocoder.geocode_address(searchtext=searchtext, city=city, state=state_province, country=country)
|
||||
coordinates = geocoder.extract_lng_lat_from_result(results[0])
|
||||
quota_service.increment_success_geocoder_use()
|
||||
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']
|
||||
except heremapsgeocoder.EmptyGeocoderResponse:
|
||||
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 here maps geocoder: {0}'.format(e)
|
||||
plpy.notice(traceback.format_tb(traceback_))
|
||||
plpy.error(error_msg)
|
||||
|
||||
$$ LANGUAGE plpythonu;
|
||||
|
||||
CREATE OR REPLACE FUNCTION cdb_geocoder_server._cdb_google_geocode_street_point(username TEXT, orgname TEXT, searchtext TEXT, city TEXT DEFAULT NULL, state_province TEXT DEFAULT NULL, country TEXT DEFAULT NULL)
|
||||
RETURNS Geometry AS $$
|
||||
plpy.error('Google geocoder is not available yet')
|
||||
return None
|
||||
$$ LANGUAGE plpythonu;
|
6
server/extension/cdb_geocoder_server--0.1.0--0.0.1.sql
Normal file
6
server/extension/cdb_geocoder_server--0.1.0--0.0.1.sql
Normal file
@ -0,0 +1,6 @@
|
||||
DROP FUNCTION IF EXISTS cdb_geocoder_server._get_redis_conf_v2(text);
|
||||
DROP FUNCTION IF EXISTS cdb_geocoder_server._connect_to_redis(text);
|
||||
DROP FUNCTION IF EXISTS cdb_geocoder_server._get_geocoder_config(text, text);
|
||||
DROP FUNCTION IF EXISTS cdb_geocoder_server.cdb_geocode_street_point_v2(TEXT, TEXT, TEXT, TEXT, TEXT, TEXT);
|
||||
DROP FUNCTION IF EXISTS cdb_geocoder_server._cdb_here_geocode_street_point(TEXT, TEXT, TEXT, TEXT, TEXT, TEXT);
|
||||
DROP FUNCTION IF EXISTS cdb_geocoder_server._cdb_google_geocode_street_point(TEXT, TEXT, TEXT, TEXT, TEXT, TEXT);
|
2
server/extension/sql/0.1.0/00_header.sql
Normal file
2
server/extension/sql/0.1.0/00_header.sql
Normal file
@ -0,0 +1,2 @@
|
||||
-- Complain if script is sourced in psql, rather than via CREATE EXTENSION
|
||||
\echo Use "CREATE EXTENSION cdb_geocoder_server" to load this file. \quit
|
@ -1,6 +1,13 @@
|
||||
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 --
|
||||
DROP FUNCTION IF EXISTS cdb_geocoder_server._get_redis_conf();
|
||||
CREATE OR REPLACE FUNCTION cdb_geocoder_server._get_redis_conf(config_key text)
|
||||
CREATE OR REPLACE FUNCTION cdb_geocoder_server._get_redis_conf_v2(config_key text)
|
||||
RETURNS cdb_geocoder_server._redis_conf_params AS $$
|
||||
conf_query = "SELECT cartodb.CDB_Conf_GetConf('{0}') as conf".format(config_key)
|
||||
conf = plpy.execute(conf_query)[0]['conf']
|
||||
@ -28,10 +35,10 @@ RETURNS boolean AS $$
|
||||
from cartodb_geocoder import redis_helper
|
||||
metadata_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('redis_metadata_config') c;""")[0]
|
||||
from cdb_geocoder_server._get_redis_conf_v2('redis_metadata_config') c;""")[0]
|
||||
metrics_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('redis_metrics_config') c;""")[0]
|
||||
from cdb_geocoder_server._get_redis_conf_v2('redis_metrics_config') c;""")[0]
|
||||
redis_metadata_connection = redis_helper.RedisHelper(metadata_config_params['sentinel_host'],
|
||||
metadata_config_params['sentinel_port'],
|
||||
metadata_config_params['sentinel_master_id'],
|
||||
|
@ -1,8 +1,5 @@
|
||||
-- We have change arguments so we need to drop the former function
|
||||
DROP FUNCTION IF EXISTS cdb_geocoder_server.cdb_geocode_street_point(TEXT, TEXT, TEXT, TEXT);
|
||||
|
||||
-- Geocodes a street address given a searchtext and a state and/or country
|
||||
CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_street_point(username TEXT, orgname TEXT, searchtext TEXT, city TEXT DEFAULT NULL, state_province TEXT DEFAULT NULL, country TEXT DEFAULT NULL)
|
||||
CREATE OR REPLACE FUNCTION cdb_geocoder_server.cdb_geocode_street_point_v2(username TEXT, orgname TEXT, searchtext TEXT, city TEXT DEFAULT NULL, state_province TEXT DEFAULT NULL, country TEXT DEFAULT NULL)
|
||||
RETURNS Geometry AS $$
|
||||
plpy.execute("SELECT cdb_geocoder_server._connect_to_redis('{0}')".format(username))
|
||||
redis_conn = GD["redis_connection_{0}".format(username)]['redis_metrics_connection']
|
||||
|
37
server/extension/sql/0.1.0/30_admin0.sql
Normal file
37
server/extension/sql/0.1.0/30_admin0.sql
Normal file
@ -0,0 +1,37 @@
|
||||
-- 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;
|
89
server/extension/sql/0.1.0/40_admin1.sql
Normal file
89
server/extension/sql/0.1.0/40_admin1.sql
Normal file
@ -0,0 +1,89 @@
|
||||
-- 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;
|
||||
|
121
server/extension/sql/0.1.0/50_namedplaces.sql
Normal file
121
server/extension/sql/0.1.0/50_namedplaces.sql
Normal file
@ -0,0 +1,121 @@
|
||||
-- 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;
|
||||
|
162
server/extension/sql/0.1.0/60_postalcodes.sql
Normal file
162
server/extension/sql/0.1.0/60_postalcodes.sql
Normal file
@ -0,0 +1,162 @@
|
||||
-- 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;
|
49
server/extension/sql/0.1.0/70_ips.sql
Normal file
49
server/extension/sql/0.1.0/70_ips.sql
Normal file
@ -0,0 +1,49 @@
|
||||
-- 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;
|
15
server/extension/sql/0.1.0/90_geocoder_server_user.sql
Normal file
15
server/extension/sql/0.1.0/90_geocoder_server_user.sql
Normal file
@ -0,0 +1,15 @@
|
||||
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$$;
|
30
server/extension/test/0.1.0/expected/00_install_test.out
Normal file
30
server/extension/test/0.1.0/expected/00_install_test.out
Normal file
@ -0,0 +1,30 @@
|
||||
-- Install dependencies
|
||||
CREATE EXTENSION postgis;
|
||||
CREATE EXTENSION schema_triggers;
|
||||
CREATE EXTENSION plpythonu;
|
||||
CREATE EXTENSION cartodb;
|
||||
CREATE EXTENSION cdb_geocoder;
|
||||
-- Install the extension
|
||||
CREATE EXTENSION cdb_geocoder_server;
|
||||
-- Mock the redis server connection to point to this very test db
|
||||
SELECT cartodb.cdb_conf_setconf('redis_conf', '{"sentinel_host": "localhost", "sentinel_port": 26739, "sentinel_master_id": "mymaster", "timeout": 0.1, "redis_db": 5}');
|
||||
cdb_conf_setconf
|
||||
------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
-- Mock the varnish invalidation function
|
||||
-- (used by cdb_geocoder tests)
|
||||
CREATE OR REPLACE FUNCTION public.cdb_invalidate_varnish(table_name text) RETURNS void AS $$
|
||||
BEGIN
|
||||
RETURN;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
-- Set user quota
|
||||
SELECT cartodb.CDB_SetUserQuotaInBytes(0);
|
||||
cdb_setuserquotainbytes
|
||||
-------------------------
|
||||
0
|
||||
(1 row)
|
||||
|
47
server/extension/test/0.1.0/expected/30_admin0_test.out
Normal file
47
server/extension/test/0.1.0/expected/30_admin0_test.out
Normal file
@ -0,0 +1,47 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin0_polygon('test_user', 'test_orgname', 'Spain');
|
||||
cdb_geocode_admin0_polygon
|
||||
----------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
-- Insert some dummy synonym
|
||||
INSERT INTO admin0_synonyms (name, adm0_a3) VALUES ('Spain', 'ESP');
|
||||
-- Insert some dummy geometry to return
|
||||
INSERT INTO ne_admin0_v3 (adm0_a3, the_geom) VALUES('ESP', ST_GeomFromText(
|
||||
'POLYGON((-71.1031880899493 42.3152774590236,
|
||||
-71.1031627617667 42.3152960829043,
|
||||
-71.102923838298 42.3149156848307,
|
||||
-71.1031880899493 42.3152774590236))',4326)
|
||||
);
|
||||
-- This should return the polygon inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin0_polygon('test_user', 'test_orgname', 'Spain');
|
||||
cdb_geocode_admin0_polygon
|
||||
--------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
0103000020E61000000100000004000000D0EA37A29AC651C00FD603035B284540FEFCFB379AC651C0C0503E9F5B284540FFDDDD4D96C651C033AC3B284F284540D0EA37A29AC651C00FD603035B284540
|
||||
(1 row)
|
||||
|
||||
-- Check for admin0 signatures
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_admin0_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_admin0_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
81
server/extension/test/0.1.0/expected/40_admin1_test.out
Normal file
81
server/extension/test/0.1.0/expected/40_admin1_test.out
Normal file
@ -0,0 +1,81 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon('test_user', 'test_orgname', 'California');
|
||||
cdb_geocode_admin1_polygon
|
||||
----------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon('test_user', 'test_orgname', 'California', 'United States');
|
||||
cdb_geocode_admin1_polygon
|
||||
----------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
-- Insert dummy data into country decoder table
|
||||
INSERT INTO country_decoder (synonyms, iso3) VALUES (Array['united states'], 'USA');
|
||||
-- Insert some dummy data and geometry to return
|
||||
INSERT INTO global_province_polygons (synonyms, iso3, the_geom) VALUES (Array['california'], 'USA', ST_GeomFromText(
|
||||
'POLYGON((-71.1031880899493 42.3152774590236,
|
||||
-71.1031627617667 42.3152960829043,
|
||||
-71.102923838298 42.3149156848307,
|
||||
-71.1031880899493 42.3152774590236))',4326)
|
||||
);
|
||||
-- This should return the polygon inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon('test_user', 'test_orgname', 'California');
|
||||
cdb_geocode_admin1_polygon
|
||||
--------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
0103000020E61000000100000004000000D0EA37A29AC651C00FD603035B284540FEFCFB379AC651C0C0503E9F5B284540FFDDDD4D96C651C033AC3B284F284540D0EA37A29AC651C00FD603035B284540
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon('test_user', 'test_orgname', 'California', 'United States');
|
||||
cdb_geocode_admin1_polygon
|
||||
--------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
0103000020E61000000100000004000000D0EA37A29AC651C00FD603035B284540FEFCFB379AC651C0C0503E9F5B284540FFDDDD4D96C651C033AC3B284F284540D0EA37A29AC651C00FD603035B284540
|
||||
(1 row)
|
||||
|
||||
-- Check for admin1 signatures
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_admin1_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_admin1_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_admin1_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_admin1_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
136
server/extension/test/0.1.0/expected/50_namedplaces_test.out
Normal file
136
server/extension/test/0.1.0/expected/50_namedplaces_test.out
Normal file
@ -0,0 +1,136 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx');
|
||||
cdb_geocode_namedplace_point
|
||||
------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx', 'Spain');
|
||||
cdb_geocode_namedplace_point
|
||||
------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx', 'Valencia', 'Spain');
|
||||
cdb_geocode_namedplace_point
|
||||
------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
-- Insert dummy data into points table
|
||||
INSERT INTO global_cities_points_limited (geoname_id, name, iso2, admin1, admin2, population, lowername, the_geom) VALUES (3128760, 'Elche', 'ES', 'Valencia', 'AL', 34534, 'elche', ST_GeomFromText(
|
||||
'POINT(0.6983 39.26787)',4326)
|
||||
);
|
||||
-- Insert dummy data into alternates table
|
||||
INSERT INTO global_cities_alternates_limited (geoname_id, name, preferred, lowername, admin1_geonameid, iso2, admin1, the_geom) VALUES (3128760, 'Elx', true, 'elx', '000000', 'ES', 'Valencia', ST_GeomFromText(
|
||||
'POINT(0.6983 39.26787)',4326)
|
||||
);
|
||||
-- Insert dummy data into country decoder table
|
||||
INSERT INTO country_decoder (synonyms, iso2) VALUES (Array['spain'], 'ES');
|
||||
-- Insert dummy data into admin1 decoder table
|
||||
INSERT INTO admin1_decoder (admin1, synonyms, iso2) VALUES ('Valencia', Array['valencia', 'Valencia'], 'ES');
|
||||
-- This should return the point inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx');
|
||||
cdb_geocode_namedplace_point
|
||||
----------------------------------------------------
|
||||
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elche');
|
||||
cdb_geocode_namedplace_point
|
||||
----------------------------------------------------
|
||||
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx', 'Spain');
|
||||
cdb_geocode_namedplace_point
|
||||
----------------------------------------------------
|
||||
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elche', 'Spain');
|
||||
cdb_geocode_namedplace_point
|
||||
----------------------------------------------------
|
||||
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx', 'Valencia', 'Spain');
|
||||
cdb_geocode_namedplace_point
|
||||
----------------------------------------------------
|
||||
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elche', 'valencia', 'Spain');
|
||||
cdb_geocode_namedplace_point
|
||||
----------------------------------------------------
|
||||
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
|
||||
(1 row)
|
||||
|
||||
-- Check for namedplaces signatures
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
163
server/extension/test/0.1.0/expected/60_postalcodes_test.out
Normal file
163
server/extension/test/0.1.0/expected/60_postalcodes_test.out
Normal file
@ -0,0 +1,163 @@
|
||||
-- Make sure dbs are clean
|
||||
DELETE FROM global_postal_code_points;
|
||||
DELETE FROM global_postal_code_polygons;
|
||||
DELETE FROM country_decoder;
|
||||
DELETE FROM available_services;
|
||||
DELETE FROM admin0_synonyms;
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_point('test_user', 'test_org', '03204');
|
||||
cdb_geocode_postalcode_point
|
||||
------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
-- Insert dummy data into ip_address_locations
|
||||
INSERT INTO global_postal_code_points (the_geom, iso3, postal_code, postal_code_num) VALUES (
|
||||
'0101000020E61000000000000000E040408036B47414764840',
|
||||
'ESP',
|
||||
'03204',
|
||||
3204
|
||||
);
|
||||
INSERT INTO global_postal_code_polygons (the_geom, iso3, postal_code, postal_code_num) VALUES (
|
||||
'0106000020E610000001000000010300000001000000040000000000000000E000C01F383D7839B740400000000000E000C0AA3C0EDE220F3B4000000000004812404FB7FCCD04893D400000000000E000C01F383D7839B74040',
|
||||
'ESP',
|
||||
'03204',
|
||||
3204
|
||||
);
|
||||
INSERT INTO country_decoder (iso3, synonyms) VALUES (
|
||||
'ESP',
|
||||
Array['spain', 'Spain', 'ESP']
|
||||
);
|
||||
INSERT INTO available_services (adm0_a3, admin0, postal_code_points, postal_code_polygons) VALUES (
|
||||
'ESP',
|
||||
't',
|
||||
't',
|
||||
't'
|
||||
);
|
||||
INSERT INTO admin0_synonyms (adm0_a3, name, name_, rank) VALUES (
|
||||
'ESP',
|
||||
'Spain',
|
||||
'spain',
|
||||
3
|
||||
);
|
||||
-- This should return the polygon inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_point('test_user', 'test_org', '03204');
|
||||
cdb_geocode_postalcode_point
|
||||
----------------------------------------------------
|
||||
0101000020E61000000000000000E040408036B47414764840
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_point('test_user', 'test_org', '03204', 'spain');
|
||||
cdb_geocode_postalcode_point
|
||||
----------------------------------------------------
|
||||
0101000020E61000000000000000E040408036B47414764840
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_polygon('test_user', 'test_org', '03204');
|
||||
cdb_geocode_postalcode_polygon
|
||||
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
0106000020E610000001000000010300000001000000040000000000000000E000C01F383D7839B740400000000000E000C0AA3C0EDE220F3B4000000000004812404FB7FCCD04893D400000000000E000C01F383D7839B74040
|
||||
(1 row)
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_polygon('test_user', 'test_org', '03204', 'spain');
|
||||
cdb_geocode_postalcode_polygon
|
||||
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
0106000020E610000001000000010300000001000000040000000000000000E000C01F383D7839B740400000000000E000C0AA3C0EDE220F3B4000000000004812404FB7FCCD04893D400000000000E000C01F383D7839B74040
|
||||
(1 row)
|
||||
|
||||
-- Clean dbs
|
||||
DELETE FROM global_postal_code_points;
|
||||
DELETE FROM global_postal_code_polygons;
|
||||
DELETE FROM country_decoder;
|
||||
DELETE FROM available_services;
|
||||
DELETE FROM admin0_synonyms;
|
||||
-- Check for namedplaces signatures (point and polygon)
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_postalcode_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_postalcode_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_postalcode_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_postalcode_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_postalcode_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_postalcode_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_postalcode_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_postalcode_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
40
server/extension/test/0.1.0/expected/70_ips_test.out
Normal file
40
server/extension/test/0.1.0/expected/70_ips_test.out
Normal file
@ -0,0 +1,40 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_ipaddress_point('test_user', 'test_orgname', '0.0.0.0');
|
||||
cdb_geocode_ipaddress_point
|
||||
-----------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
-- Insert dummy data into ip_address_locations
|
||||
INSERT INTO ip_address_locations VALUES ('::ffff:0.0.0.0'::inet, (ST_SetSRID(ST_MakePoint('40.40', '3.71'), 4326)));
|
||||
-- This should return the polygon inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_ipaddress_point('test_user', 'test_orgname', '0.0.0.0');
|
||||
cdb_geocode_ipaddress_point
|
||||
----------------------------------------------------
|
||||
0101000020E61000003333333333334440AE47E17A14AE0D40
|
||||
(1 row)
|
||||
|
||||
-- Check for namedplaces signatures (point and polygon)
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_ipaddress_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_ipaddress_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
exists
|
||||
--------
|
||||
t
|
||||
(1 row)
|
||||
|
@ -0,0 +1,5 @@
|
||||
REVOKE EXECUTE ON ALL FUNCTIONS IN SCHEMA cdb_geocoder_server FROM geocoder_api;
|
||||
REVOKE EXECUTE ON ALL FUNCTIONS IN SCHEMA public FROM geocoder_api;
|
||||
REVOKE USAGE ON SCHEMA cdb_geocoder_server FROM geocoder_api;
|
||||
REVOKE USAGE ON SCHEMA public FROM geocoder_api;
|
||||
REVOKE SELECT ON ALL TABLES IN SCHEMA public FROM geocoder_api;
|
24
server/extension/test/0.1.0/sql/00_install_test.sql
Normal file
24
server/extension/test/0.1.0/sql/00_install_test.sql
Normal file
@ -0,0 +1,24 @@
|
||||
-- Install dependencies
|
||||
CREATE EXTENSION postgis;
|
||||
CREATE EXTENSION schema_triggers;
|
||||
CREATE EXTENSION plpythonu;
|
||||
CREATE EXTENSION cartodb;
|
||||
CREATE EXTENSION cdb_geocoder;
|
||||
|
||||
-- Install the extension
|
||||
CREATE EXTENSION cdb_geocoder_server;
|
||||
|
||||
-- Mock the redis server connection to point to this very test db
|
||||
SELECT cartodb.cdb_conf_setconf('redis_conf', '{"sentinel_host": "localhost", "sentinel_port": 26739, "sentinel_master_id": "mymaster", "timeout": 0.1, "redis_db": 5}');
|
||||
|
||||
-- Mock the varnish invalidation function
|
||||
-- (used by cdb_geocoder tests)
|
||||
CREATE OR REPLACE FUNCTION public.cdb_invalidate_varnish(table_name text) RETURNS void AS $$
|
||||
BEGIN
|
||||
RETURN;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
-- Set user quota
|
||||
SELECT cartodb.CDB_SetUserQuotaInBytes(0);
|
32
server/extension/test/0.1.0/sql/30_admin0_test.sql
Normal file
32
server/extension/test/0.1.0/sql/30_admin0_test.sql
Normal file
@ -0,0 +1,32 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin0_polygon('test_user', 'test_orgname', 'Spain');
|
||||
|
||||
-- Insert some dummy synonym
|
||||
INSERT INTO admin0_synonyms (name, adm0_a3) VALUES ('Spain', 'ESP');
|
||||
|
||||
-- Insert some dummy geometry to return
|
||||
INSERT INTO ne_admin0_v3 (adm0_a3, the_geom) VALUES('ESP', ST_GeomFromText(
|
||||
'POLYGON((-71.1031880899493 42.3152774590236,
|
||||
-71.1031627617667 42.3152960829043,
|
||||
-71.102923838298 42.3149156848307,
|
||||
-71.1031880899493 42.3152774590236))',4326)
|
||||
);
|
||||
|
||||
-- This should return the polygon inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin0_polygon('test_user', 'test_orgname', 'Spain');
|
||||
|
||||
-- Check for admin0 signatures
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_admin0_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_admin0_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
48
server/extension/test/0.1.0/sql/40_admin1_test.sql
Normal file
48
server/extension/test/0.1.0/sql/40_admin1_test.sql
Normal file
@ -0,0 +1,48 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon('test_user', 'test_orgname', 'California');
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon('test_user', 'test_orgname', 'California', 'United States');
|
||||
|
||||
-- Insert dummy data into country decoder table
|
||||
INSERT INTO country_decoder (synonyms, iso3) VALUES (Array['united states'], 'USA');
|
||||
|
||||
-- Insert some dummy data and geometry to return
|
||||
INSERT INTO global_province_polygons (synonyms, iso3, the_geom) VALUES (Array['california'], 'USA', ST_GeomFromText(
|
||||
'POLYGON((-71.1031880899493 42.3152774590236,
|
||||
-71.1031627617667 42.3152960829043,
|
||||
-71.102923838298 42.3149156848307,
|
||||
-71.1031880899493 42.3152774590236))',4326)
|
||||
);
|
||||
|
||||
-- This should return the polygon inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon('test_user', 'test_orgname', 'California');
|
||||
SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon('test_user', 'test_orgname', 'California', 'United States');
|
||||
|
||||
-- Check for admin1 signatures
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_admin1_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_admin1_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_admin1_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_admin1_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text');
|
72
server/extension/test/0.1.0/sql/50_namedplaces_test.sql
Normal file
72
server/extension/test/0.1.0/sql/50_namedplaces_test.sql
Normal file
@ -0,0 +1,72 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx');
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx', 'Spain');
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx', 'Valencia', 'Spain');
|
||||
|
||||
-- Insert dummy data into points table
|
||||
INSERT INTO global_cities_points_limited (geoname_id, name, iso2, admin1, admin2, population, lowername, the_geom) VALUES (3128760, 'Elche', 'ES', 'Valencia', 'AL', 34534, 'elche', ST_GeomFromText(
|
||||
'POINT(0.6983 39.26787)',4326)
|
||||
);
|
||||
|
||||
-- Insert dummy data into alternates table
|
||||
INSERT INTO global_cities_alternates_limited (geoname_id, name, preferred, lowername, admin1_geonameid, iso2, admin1, the_geom) VALUES (3128760, 'Elx', true, 'elx', '000000', 'ES', 'Valencia', ST_GeomFromText(
|
||||
'POINT(0.6983 39.26787)',4326)
|
||||
);
|
||||
|
||||
-- Insert dummy data into country decoder table
|
||||
INSERT INTO country_decoder (synonyms, iso2) VALUES (Array['spain'], 'ES');
|
||||
|
||||
-- Insert dummy data into admin1 decoder table
|
||||
INSERT INTO admin1_decoder (admin1, synonyms, iso2) VALUES ('Valencia', Array['valencia', 'Valencia'], 'ES');
|
||||
|
||||
-- This should return the point inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx');
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elche');
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx', 'Spain');
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elche', 'Spain');
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elx', 'Valencia', 'Spain');
|
||||
SELECT cdb_geocoder_server.cdb_geocode_namedplace_point('test_user', 'test_orgname', 'Elche', 'valencia', 'Spain');
|
||||
|
||||
-- Check for namedplaces signatures
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_namedplace_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
117
server/extension/test/0.1.0/sql/60_postalcodes_test.sql
Normal file
117
server/extension/test/0.1.0/sql/60_postalcodes_test.sql
Normal file
@ -0,0 +1,117 @@
|
||||
-- Make sure dbs are clean
|
||||
DELETE FROM global_postal_code_points;
|
||||
DELETE FROM global_postal_code_polygons;
|
||||
DELETE FROM country_decoder;
|
||||
DELETE FROM available_services;
|
||||
DELETE FROM admin0_synonyms;
|
||||
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_point('test_user', 'test_org', '03204');
|
||||
|
||||
-- Insert dummy data into ip_address_locations
|
||||
INSERT INTO global_postal_code_points (the_geom, iso3, postal_code, postal_code_num) VALUES (
|
||||
'0101000020E61000000000000000E040408036B47414764840',
|
||||
'ESP',
|
||||
'03204',
|
||||
3204
|
||||
);
|
||||
|
||||
INSERT INTO global_postal_code_polygons (the_geom, iso3, postal_code, postal_code_num) VALUES (
|
||||
'0106000020E610000001000000010300000001000000040000000000000000E000C01F383D7839B740400000000000E000C0AA3C0EDE220F3B4000000000004812404FB7FCCD04893D400000000000E000C01F383D7839B74040',
|
||||
'ESP',
|
||||
'03204',
|
||||
3204
|
||||
);
|
||||
|
||||
INSERT INTO country_decoder (iso3, synonyms) VALUES (
|
||||
'ESP',
|
||||
Array['spain', 'Spain', 'ESP']
|
||||
);
|
||||
|
||||
INSERT INTO available_services (adm0_a3, admin0, postal_code_points, postal_code_polygons) VALUES (
|
||||
'ESP',
|
||||
't',
|
||||
't',
|
||||
't'
|
||||
);
|
||||
|
||||
INSERT INTO admin0_synonyms (adm0_a3, name, name_, rank) VALUES (
|
||||
'ESP',
|
||||
'Spain',
|
||||
'spain',
|
||||
3
|
||||
);
|
||||
|
||||
-- This should return the polygon inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_point('test_user', 'test_org', '03204');
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_point('test_user', 'test_org', '03204', 'spain');
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_polygon('test_user', 'test_org', '03204');
|
||||
|
||||
SELECT cdb_geocoder_server.cdb_geocode_postalcode_polygon('test_user', 'test_org', '03204', 'spain');
|
||||
|
||||
-- Clean dbs
|
||||
DELETE FROM global_postal_code_points;
|
||||
DELETE FROM global_postal_code_polygons;
|
||||
DELETE FROM country_decoder;
|
||||
DELETE FROM available_services;
|
||||
DELETE FROM admin0_synonyms;
|
||||
|
||||
-- Check for namedplaces signatures (point and polygon)
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_postalcode_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_postalcode_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_postalcode_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_postalcode_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_postalcode_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_postalcode_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_postalcode_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_postalcode_polygon'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text');
|
24
server/extension/test/0.1.0/sql/70_ips_test.sql
Normal file
24
server/extension/test/0.1.0/sql/70_ips_test.sql
Normal file
@ -0,0 +1,24 @@
|
||||
-- Check that the public function is callable, even with no data
|
||||
-- It should return NULL
|
||||
SELECT cdb_geocoder_server.cdb_geocode_ipaddress_point('test_user', 'test_orgname', '0.0.0.0');
|
||||
|
||||
-- Insert dummy data into ip_address_locations
|
||||
INSERT INTO ip_address_locations VALUES ('::ffff:0.0.0.0'::inet, (ST_SetSRID(ST_MakePoint('40.40', '3.71'), 4326)));
|
||||
|
||||
-- This should return the polygon inserted above
|
||||
SELECT cdb_geocoder_server.cdb_geocode_ipaddress_point('test_user', 'test_orgname', '0.0.0.0');
|
||||
|
||||
-- Check for namedplaces signatures (point and polygon)
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = 'cdb_geocode_ipaddress_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text, text, text');
|
||||
|
||||
SELECT exists(SELECT *
|
||||
FROM pg_proc p
|
||||
INNER JOIN pg_namespace ns ON (p.pronamespace = ns.oid)
|
||||
WHERE ns.nspname = 'cdb_geocoder_server'
|
||||
AND proname = '_cdb_geocode_ipaddress_point'
|
||||
AND oidvectortypes(p.proargtypes) = 'text');
|
@ -0,0 +1,5 @@
|
||||
REVOKE EXECUTE ON ALL FUNCTIONS IN SCHEMA cdb_geocoder_server FROM geocoder_api;
|
||||
REVOKE EXECUTE ON ALL FUNCTIONS IN SCHEMA public FROM geocoder_api;
|
||||
REVOKE USAGE ON SCHEMA cdb_geocoder_server FROM geocoder_api;
|
||||
REVOKE USAGE ON SCHEMA public FROM geocoder_api;
|
||||
REVOKE SELECT ON ALL TABLES IN SCHEMA public FROM geocoder_api;
|
Loading…
Reference in New Issue
Block a user