From f95f5d950e707143c899da6ada88fb308b69900d Mon Sep 17 00:00:00 2001 From: Carla Date: Wed, 11 Nov 2015 12:46:07 +0100 Subject: [PATCH 01/14] Create 30_admin1.sql --- server/extension/sql/0.0.1/30_admin1.sql | 1 + 1 file changed, 1 insertion(+) create mode 100644 server/extension/sql/0.0.1/30_admin1.sql diff --git a/server/extension/sql/0.0.1/30_admin1.sql b/server/extension/sql/0.0.1/30_admin1.sql new file mode 100644 index 0000000..8b13789 --- /dev/null +++ b/server/extension/sql/0.0.1/30_admin1.sql @@ -0,0 +1 @@ + From 8d450a78702975c1ccccb32f7aa8b93fcbe75064 Mon Sep 17 00:00:00 2001 From: Carla Iriberri Date: Wed, 11 Nov 2015 13:33:14 +0100 Subject: [PATCH 02/14] Adds first admin1 function #6 --- server/extension/expected/40_admin1_test.out | 22 +++++++++ server/extension/sql/0.0.1/40_admin1.sql | 50 ++++++++++++++++++++ server/extension/sql/40_admin1_test.sql | 14 ++++++ 3 files changed, 86 insertions(+) create mode 100644 server/extension/expected/40_admin1_test.out create mode 100644 server/extension/sql/0.0.1/40_admin1.sql create mode 100644 server/extension/sql/40_admin1_test.sql diff --git a/server/extension/expected/40_admin1_test.out b/server/extension/expected/40_admin1_test.out new file mode 100644 index 0000000..dc7a839 --- /dev/null +++ b/server/extension/expected/40_admin1_test.out @@ -0,0 +1,22 @@ +-- Check that the public function is callable, even with no data +-- It should return NULL +SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California'); + geocode_admin1_polygons +------------------------- + +(1 row) + +-- Insert some dummy data and geometry to return +INSERT INTO global_province_polygons (synonyms, the_geom) VALUES (Array['Califonia'], 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.geocode_admin1_polygons(session_user, txid_current(), 'California'); + geocode_admin1_polygons +------------------------- + +(1 row) + diff --git a/server/extension/sql/0.0.1/40_admin1.sql b/server/extension/sql/0.0.1/40_admin1.sql new file mode 100644 index 0000000..c8d351d --- /dev/null +++ b/server/extension/sql/0.0.1/40_admin1.sql @@ -0,0 +1,50 @@ +-- Interface of the server extension + +CREATE OR REPLACE FUNCTION geocode_admin1_polygons(user_id name, tx_id bigint, admin1_name text) +RETURNS Geometry AS $$ + plpy.debug('Entering geocode_admin1_polygons') + plpy.debug('user_id = %s' % user_id) + + #-- Access control + #-- TODO: this should be part of cdb python library + if user_id == 'publicuser': + plpy.error('The api_key must be provided') + + #--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._geocode_admin1_polygons($1) AS mypolygon", ["text"]) + rv = plpy.execute(plan, [admin1_name], 1) + + plpy.debug('Returning from Returning from geocode_admin1_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 _geocode_admin1_polygons(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; diff --git a/server/extension/sql/40_admin1_test.sql b/server/extension/sql/40_admin1_test.sql new file mode 100644 index 0000000..e96cbfc --- /dev/null +++ b/server/extension/sql/40_admin1_test.sql @@ -0,0 +1,14 @@ +-- Check that the public function is callable, even with no data +-- It should return NULL +SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California'); + +-- Insert some dummy data and geometry to return +INSERT INTO global_province_polygons (synonyms, the_geom) VALUES (Array['Califonia'], 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.geocode_admin1_polygons(session_user, txid_current(), 'California'); From 93513d695494de580869ce3b3ee8bf4464602af5 Mon Sep 17 00:00:00 2001 From: Carla Iriberri Date: Wed, 11 Nov 2015 14:05:17 +0100 Subject: [PATCH 03/14] Adding a new function --- server/extension/expected/40_admin1_test.out | 36 +++++++++++++ server/extension/sql/0.0.1/40_admin1.sql | 53 ++++++++++++++++++- server/extension/sql/40_admin1_test.sql | 12 ++++- 3 files changed, 98 insertions(+), 3 deletions(-) create mode 100644 server/extension/expected/40_admin1_test.out diff --git a/server/extension/expected/40_admin1_test.out b/server/extension/expected/40_admin1_test.out new file mode 100644 index 0000000..1e5cdc6 --- /dev/null +++ b/server/extension/expected/40_admin1_test.out @@ -0,0 +1,36 @@ +-- Check that the public function is callable, even with no data +-- It should return NULL +SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California'); + geocode_admin1_polygons +------------------------- + +(1 row) + +SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California', 'United States'); + geocode_admin1_polygons +------------------------- + +(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.geocode_admin1_polygons(session_user, txid_current(), 'California'); + geocode_admin1_polygons +-------------------------------------------------------------------------------------------------------------------------------------------------------------------- + 0103000020E61000000100000004000000D0EA37A29AC651C00FD603035B284540FEFCFB379AC651C0C0503E9F5B284540FFDDDD4D96C651C033AC3B284F284540D0EA37A29AC651C00FD603035B284540 +(1 row) + +SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California', 'United States'); + geocode_admin1_polygons +-------------------------------------------------------------------------------------------------------------------------------------------------------------------- + 0103000020E61000000100000004000000D0EA37A29AC651C00FD603035B284540FEFCFB379AC651C0C0503E9F5B284540FFDDDD4D96C651C033AC3B284F284540D0EA37A29AC651C00FD603035B284540 +(1 row) + diff --git a/server/extension/sql/0.0.1/40_admin1.sql b/server/extension/sql/0.0.1/40_admin1.sql index c8d351d..a977201 100644 --- a/server/extension/sql/0.0.1/40_admin1.sql +++ b/server/extension/sql/0.0.1/40_admin1.sql @@ -1,8 +1,9 @@ --- Interface of the server extension +-- Interfacess of the server extension +---- geocode_admin1_polygons(admin1_name text) CREATE OR REPLACE FUNCTION geocode_admin1_polygons(user_id name, tx_id bigint, admin1_name text) RETURNS Geometry AS $$ - plpy.debug('Entering geocode_admin1_polygons') + plpy.debug('Entering geocode_admin1_polygons(admin1_name text)') plpy.debug('user_id = %s' % user_id) #-- Access control @@ -21,11 +22,34 @@ RETURNS Geometry AS $$ return rv[0]["mypolygon"] $$ LANGUAGE plpythonu; +---- geocode_admin1_polygons(admin1_name text, country_name text) +CREATE OR REPLACE FUNCTION geocode_admin1_polygons(user_id name, tx_id bigint, admin1_name text, country_name text) +RETURNS Geometry AS $$ + plpy.debug('Entering geocode_admin1_polygons(admin1_name text, country_name text)') + plpy.debug('user_id = %s' % user_id) + + #-- Access control + #-- TODO: this should be part of cdb python library + if user_id == 'publicuser': + plpy.error('The api_key must be provided') + + #--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._geocode_admin1_polygons($1, $2) AS mypolygon", ["text", "text"]) + rv = plpy.execute(plan, [admin1_name, country_name], 1) + + plpy.debug('Returning from Returning from geocode_admin1_polygons(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 + +---- geocode_admin1_polygons(admin1_name text) CREATE OR REPLACE FUNCTION _geocode_admin1_polygons(admin1_name text) RETURNS Geometry AS $$ DECLARE @@ -48,3 +72,28 @@ RETURNS Geometry AS $$ RETURN ret; END $$ LANGUAGE plpgsql; + +---- geocode_admin1_polygons(admin1_name text, country_name text) +CREATE OR REPLACE FUNCTION _geocode_admin1_polygons(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; + diff --git a/server/extension/sql/40_admin1_test.sql b/server/extension/sql/40_admin1_test.sql index e96cbfc..1620766 100644 --- a/server/extension/sql/40_admin1_test.sql +++ b/server/extension/sql/40_admin1_test.sql @@ -1,9 +1,13 @@ -- Check that the public function is callable, even with no data -- It should return NULL SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California'); +SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), '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, the_geom) VALUES (Array['Califonia'], ST_GeomFromText( +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, @@ -12,3 +16,9 @@ INSERT INTO global_province_polygons (synonyms, the_geom) VALUES (Array['Califon -- This should return the polygon inserted above SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California'); +SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California', 'United States'); + + + + + From 4592dc8644268de7ba3b406b0e86e36e6008df51 Mon Sep 17 00:00:00 2001 From: Carla Date: Wed, 11 Nov 2015 14:06:53 +0100 Subject: [PATCH 04/14] Delete 40_admin1_test.out --- server/extension/expected/40_admin1_test.out | 22 -------------------- 1 file changed, 22 deletions(-) delete mode 100644 server/extension/expected/40_admin1_test.out diff --git a/server/extension/expected/40_admin1_test.out b/server/extension/expected/40_admin1_test.out deleted file mode 100644 index dc7a839..0000000 --- a/server/extension/expected/40_admin1_test.out +++ /dev/null @@ -1,22 +0,0 @@ --- Check that the public function is callable, even with no data --- It should return NULL -SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California'); - geocode_admin1_polygons -------------------------- - -(1 row) - --- Insert some dummy data and geometry to return -INSERT INTO global_province_polygons (synonyms, the_geom) VALUES (Array['Califonia'], 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.geocode_admin1_polygons(session_user, txid_current(), 'California'); - geocode_admin1_polygons -------------------------- - -(1 row) - From 1c44fbbf56ca1165093c89f338745ad7fe4b51c9 Mon Sep 17 00:00:00 2001 From: Guido Fioravantti Date: Wed, 11 Nov 2015 15:38:18 +0100 Subject: [PATCH 05/14] Adds 90_geocode_ip and tests --- ...40_admin1_test.out => 40_admin1_test.out} | 0 .../extension/expected/90_geocode_ip_test.out | 17 ++++++++ server/extension/sql/0.0.1/30_admin1.sql | 1 - server/extension/sql/0.0.1/90_geocode_ip.sql | 40 +++++++++++++++++++ server/extension/sql/90_geocode_ip_test.sql | 9 +++++ 5 files changed, 66 insertions(+), 1 deletion(-) rename server/extension/expected/{40_admin1_test.out => 40_admin1_test.out} (100%) create mode 100644 server/extension/expected/90_geocode_ip_test.out delete mode 100644 server/extension/sql/0.0.1/30_admin1.sql create mode 100644 server/extension/sql/0.0.1/90_geocode_ip.sql create mode 100644 server/extension/sql/90_geocode_ip_test.sql diff --git a/server/extension/expected/40_admin1_test.out b/server/extension/expected/40_admin1_test.out similarity index 100% rename from server/extension/expected/40_admin1_test.out rename to server/extension/expected/40_admin1_test.out diff --git a/server/extension/expected/90_geocode_ip_test.out b/server/extension/expected/90_geocode_ip_test.out new file mode 100644 index 0000000..1f81910 --- /dev/null +++ b/server/extension/expected/90_geocode_ip_test.out @@ -0,0 +1,17 @@ +-- Check that the public function is callable, even with no data +-- It should return NULL +SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0.0'::inet); + geocode_ip_point +------------------ + +(1 row) + +-- Insert dummy data into ip_address_locations +INSERT INTO ip_address_locations VALUES ('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.geocode_ip_point(session_user, txid_current(), '0.0.0.0'::inet); + geocode_ip_point +---------------------------------------------------- + 0101000020E61000003333333333334440AE47E17A14AE0D40 +(1 row) + diff --git a/server/extension/sql/0.0.1/30_admin1.sql b/server/extension/sql/0.0.1/30_admin1.sql deleted file mode 100644 index 8b13789..0000000 --- a/server/extension/sql/0.0.1/30_admin1.sql +++ /dev/null @@ -1 +0,0 @@ - diff --git a/server/extension/sql/0.0.1/90_geocode_ip.sql b/server/extension/sql/0.0.1/90_geocode_ip.sql new file mode 100644 index 0000000..1692a1a --- /dev/null +++ b/server/extension/sql/0.0.1/90_geocode_ip.sql @@ -0,0 +1,40 @@ +-- Interface of the server extension + +CREATE OR REPLACE FUNCTION geocode_ip_point(user_id NAME, tx_id BIGINT, ip INET) +RETURNS Geometry AS $$ + plpy.debug('Entering _geocode_ip_point') + plpy.debug('user_id = %s' % user_id) + + #-- Access control + #-- TODO: this should be part of cdb python library + if user_id == 'publicuser': + plpy.error('The api_key must be provided') + + #--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._geocode_ip_point($1) AS point", ["INET"]) + rv = plpy.execute(plan, [ip], 1) + + plpy.debug('Returning from _geocode_ip_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 _geocode_ip_point(ip INET) +RETURNS Geometry AS $$ + DECLARE + ret Geometry; + BEGIN + SELECT ips.the_geom as geom INTO ret + FROM public.ip_address_locations ips + WHERE ips.network_start_ip = ip; + + RETURN ret; + END +$$ LANGUAGE plpgsql; diff --git a/server/extension/sql/90_geocode_ip_test.sql b/server/extension/sql/90_geocode_ip_test.sql new file mode 100644 index 0000000..337a1ae --- /dev/null +++ b/server/extension/sql/90_geocode_ip_test.sql @@ -0,0 +1,9 @@ +-- Check that the public function is callable, even with no data +-- It should return NULL +SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0.0'::inet); + +-- Insert dummy data into ip_address_locations +INSERT INTO ip_address_locations VALUES ('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.geocode_ip_point(session_user, txid_current(), '0.0.0.0'::inet); From 66fd33da374d12bebddc89a11db0b3d307b7f7fd Mon Sep 17 00:00:00 2001 From: Guido Fioravantti Date: Wed, 11 Nov 2015 15:43:11 +0100 Subject: [PATCH 06/14] Fixes param type for geocode_ip --- server/extension/expected/90_geocode_ip_test.out | 4 ++-- server/extension/sql/0.0.1/90_geocode_ip.sql | 8 ++++---- server/extension/sql/90_geocode_ip_test.sql | 4 ++-- 3 files changed, 8 insertions(+), 8 deletions(-) diff --git a/server/extension/expected/90_geocode_ip_test.out b/server/extension/expected/90_geocode_ip_test.out index 1f81910..db16fa5 100644 --- a/server/extension/expected/90_geocode_ip_test.out +++ b/server/extension/expected/90_geocode_ip_test.out @@ -1,6 +1,6 @@ -- Check that the public function is callable, even with no data -- It should return NULL -SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0.0'::inet); +SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0.0'); geocode_ip_point ------------------ @@ -9,7 +9,7 @@ SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0 -- Insert dummy data into ip_address_locations INSERT INTO ip_address_locations VALUES ('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.geocode_ip_point(session_user, txid_current(), '0.0.0.0'::inet); +SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0.0'); geocode_ip_point ---------------------------------------------------- 0101000020E61000003333333333334440AE47E17A14AE0D40 diff --git a/server/extension/sql/0.0.1/90_geocode_ip.sql b/server/extension/sql/0.0.1/90_geocode_ip.sql index 1692a1a..9e41ac2 100644 --- a/server/extension/sql/0.0.1/90_geocode_ip.sql +++ b/server/extension/sql/0.0.1/90_geocode_ip.sql @@ -1,6 +1,6 @@ -- Interface of the server extension -CREATE OR REPLACE FUNCTION geocode_ip_point(user_id NAME, tx_id BIGINT, ip INET) +CREATE OR REPLACE FUNCTION geocode_ip_point(user_id NAME, tx_id BIGINT, ip TEXT) RETURNS Geometry AS $$ plpy.debug('Entering _geocode_ip_point') plpy.debug('user_id = %s' % user_id) @@ -14,7 +14,7 @@ RETURNS Geometry AS $$ #--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._geocode_ip_point($1) AS point", ["INET"]) + plan = plpy.prepare("SELECT cdb_geocoder_server._geocode_ip_point($1) AS point", ["TEXT"]) rv = plpy.execute(plan, [ip], 1) plpy.debug('Returning from _geocode_ip_point') @@ -26,14 +26,14 @@ $$ LANGUAGE plpythonu; -- Implementation of the server extension -- Note: these functions depend on the cdb_geocoder extension -CREATE OR REPLACE FUNCTION _geocode_ip_point(ip INET) +CREATE OR REPLACE FUNCTION _geocode_ip_point(ip TEXT) RETURNS Geometry AS $$ DECLARE ret Geometry; BEGIN SELECT ips.the_geom as geom INTO ret FROM public.ip_address_locations ips - WHERE ips.network_start_ip = ip; + WHERE ips.network_start_ip = ip::inet; RETURN ret; END diff --git a/server/extension/sql/90_geocode_ip_test.sql b/server/extension/sql/90_geocode_ip_test.sql index 337a1ae..63ff315 100644 --- a/server/extension/sql/90_geocode_ip_test.sql +++ b/server/extension/sql/90_geocode_ip_test.sql @@ -1,9 +1,9 @@ -- Check that the public function is callable, even with no data -- It should return NULL -SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0.0'::inet); +SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0.0'); -- Insert dummy data into ip_address_locations INSERT INTO ip_address_locations VALUES ('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.geocode_ip_point(session_user, txid_current(), '0.0.0.0'::inet); +SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0.0'); From 24c0e01b067cfb38053bae3c1da1db744902e9e1 Mon Sep 17 00:00:00 2001 From: Guido Fioravantti Date: Wed, 11 Nov 2015 16:07:55 +0100 Subject: [PATCH 07/14] Adds limit 1 to _geocode_ip_point --- server/extension/sql/0.0.1/90_geocode_ip.sql | 5 ++++- 1 file changed, 4 insertions(+), 1 deletion(-) diff --git a/server/extension/sql/0.0.1/90_geocode_ip.sql b/server/extension/sql/0.0.1/90_geocode_ip.sql index 9e41ac2..515ae17 100644 --- a/server/extension/sql/0.0.1/90_geocode_ip.sql +++ b/server/extension/sql/0.0.1/90_geocode_ip.sql @@ -30,10 +30,13 @@ CREATE OR REPLACE FUNCTION _geocode_ip_point(ip TEXT) RETURNS Geometry AS $$ DECLARE ret Geometry; + + LIM INTEGER := 1; BEGIN SELECT ips.the_geom as geom INTO ret FROM public.ip_address_locations ips - WHERE ips.network_start_ip = ip::inet; + WHERE ips.network_start_ip = ip::inet + LIMIT LIM; RETURN ret; END From 6e301b0f9e6bb3a2a4691fc3f87778a97c10853d Mon Sep 17 00:00:00 2001 From: Carla Iriberri Date: Wed, 11 Nov 2015 16:29:17 +0100 Subject: [PATCH 08/14] Adds first function for namedplaces #6 --- .../expected/50_namedplaces_test.out | 29 ++++++++++ server/extension/sql/0.0.1/50_namedplaces.sql | 53 +++++++++++++++++++ server/extension/sql/50_namedplaces_test.sql | 17 ++++++ 3 files changed, 99 insertions(+) create mode 100644 server/extension/expected/50_namedplaces_test.out create mode 100644 server/extension/sql/0.0.1/50_namedplaces.sql create mode 100644 server/extension/sql/50_namedplaces_test.sql diff --git a/server/extension/expected/50_namedplaces_test.out b/server/extension/expected/50_namedplaces_test.out new file mode 100644 index 0000000..4178bd8 --- /dev/null +++ b/server/extension/expected/50_namedplaces_test.out @@ -0,0 +1,29 @@ +-- Check that the public function is callable, even with no data +-- It should return NULL +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); + geocode_namedplace +-------------------- + +(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', 'VA', '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', 'VA', ST_GeomFromText( + 'POINT(0.6983 39.26787)',4326) +); +-- This should return the point inserted above +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); + geocode_namedplace +---------------------------------------------------- + 0101000020E6100000637FD93D7958E63F2ECA6C9049A24340 +(1 row) + +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche'); + geocode_namedplace +---------------------------------------------------- + 0101000020E6100000637FD93D7958E63F2ECA6C9049A24340 +(1 row) + diff --git a/server/extension/sql/0.0.1/50_namedplaces.sql b/server/extension/sql/0.0.1/50_namedplaces.sql new file mode 100644 index 0000000..e1561e9 --- /dev/null +++ b/server/extension/sql/0.0.1/50_namedplaces.sql @@ -0,0 +1,53 @@ +-- Interfacess of the server extension + +---- geocode_namedplace(city_name text) +CREATE OR REPLACE FUNCTION geocode_namedplace(user_id name, tx_id bigint, city_name text) +RETURNS Geometry AS $$ + plpy.debug('Entering geocode_namedplace(city_name text)') + plpy.debug('user_id = %s' % user_id) + + #-- Access control + #-- TODO: this should be part of cdb python library + if user_id == 'publicuser': + plpy.error('The api_key must be provided') + + #--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._geocode_namedplace($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; + +---- geocode_admin1_polygons(admin1_name text, country_name text) + +-------------------------------------------------------------------------------- + +-- Implementation of the server extension +-- Note: these functions depend on the cdb_geocoder extension + +---- geocode_namedplace(city_name text) +CREATE OR REPLACE FUNCTION _geocode_namedplace(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; + +---- geocode_namedplace(city_name text, country_name text) + + diff --git a/server/extension/sql/50_namedplaces_test.sql b/server/extension/sql/50_namedplaces_test.sql new file mode 100644 index 0000000..469603b --- /dev/null +++ b/server/extension/sql/50_namedplaces_test.sql @@ -0,0 +1,17 @@ +-- Check that the public function is callable, even with no data +-- It should return NULL +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); + +-- 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', 'VA', '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', 'VA', ST_GeomFromText( + 'POINT(0.6983 39.26787)',4326) +); + +-- This should return the point inserted above +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche'); From f2bcd1b1032ec432d07aca59716e1d4c0b5100ea Mon Sep 17 00:00:00 2001 From: Carla Iriberri Date: Wed, 11 Nov 2015 16:30:34 +0100 Subject: [PATCH 09/14] Killing trailspaces --- server/extension/sql/0.0.1/40_admin1.sql | 12 ++++++------ 1 file changed, 6 insertions(+), 6 deletions(-) diff --git a/server/extension/sql/0.0.1/40_admin1.sql b/server/extension/sql/0.0.1/40_admin1.sql index a977201..8d29e26 100644 --- a/server/extension/sql/0.0.1/40_admin1.sql +++ b/server/extension/sql/0.0.1/40_admin1.sql @@ -58,13 +58,13 @@ RETURNS Geometry AS $$ SELECT geom INTO ret FROM ( SELECT q, ( - SELECT the_geom + SELECT the_geom FROM global_province_polygons - WHERE d.c = ANY (synonyms) + WHERE d.c = ANY (synonyms) ORDER BY frequency DESC LIMIT 1 ) geom FROM ( - SELECT + SELECT trim(replace(lower(admin1_name),'.',' ')) c, admin1_name q ) d ) v; @@ -83,11 +83,11 @@ RETURNS Geometry AS $$ SELECT geom INTO ret FROM ( - SELECT + SELECT q, ( - SELECT the_geom + SELECT the_geom FROM global_province_polygons - WHERE p.c = ANY (synonyms) + WHERE p.c = ANY (synonyms) AND iso3 = p.i ORDER BY frequency DESC LIMIT 1 ) geom From b54c417754e89f62dbf6f53274b86ff209a4bad5 Mon Sep 17 00:00:00 2001 From: Carla Iriberri Date: Wed, 11 Nov 2015 17:17:18 +0100 Subject: [PATCH 10/14] Adding country, city function for namedplaces --- .../expected/50_namedplaces_test.out | 14 +++++++ server/extension/sql/0.0.1/50_namedplaces.sql | 39 ++++++++++++++++++- server/extension/sql/50_namedplaces_test.sql | 5 +++ 3 files changed, 57 insertions(+), 1 deletion(-) diff --git a/server/extension/expected/50_namedplaces_test.out b/server/extension/expected/50_namedplaces_test.out index 4178bd8..b3f4549 100644 --- a/server/extension/expected/50_namedplaces_test.out +++ b/server/extension/expected/50_namedplaces_test.out @@ -14,6 +14,8 @@ INSERT INTO global_cities_points_limited (geoname_id, name, iso2, admin1, admin2 INSERT INTO global_cities_alternates_limited (geoname_id, name, preferred, lowername, admin1_geonameid, iso2, admin1, the_geom) VALUES (3128760, 'Elx', true, 'elx', '000000', 'ES', 'VA', 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'); -- This should return the point inserted above SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); geocode_namedplace @@ -27,3 +29,15 @@ SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elc 0101000020E6100000637FD93D7958E63F2ECA6C9049A24340 (1 row) +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Spain'); + geocode_namedplace +---------------------------------------------------- + 0101000020E6100000637FD93D7958E63F2ECA6C9049A24340 +(1 row) + +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'Spain'); + geocode_namedplace +---------------------------------------------------- + 0101000020E6100000637FD93D7958E63F2ECA6C9049A24340 +(1 row) + diff --git a/server/extension/sql/0.0.1/50_namedplaces.sql b/server/extension/sql/0.0.1/50_namedplaces.sql index e1561e9..9d9a9fd 100644 --- a/server/extension/sql/0.0.1/50_namedplaces.sql +++ b/server/extension/sql/0.0.1/50_namedplaces.sql @@ -22,7 +22,27 @@ RETURNS Geometry AS $$ return rv[0]["mypoint"] $$ LANGUAGE plpythonu; ----- geocode_admin1_polygons(admin1_name text, country_name text) +---- geocode_namedplace(city_name text, country_name text) +CREATE OR REPLACE FUNCTION geocode_namedplace(user_id name, tx_id bigint, city_name text, country_name text) +RETURNS Geometry AS $$ + plpy.debug('Entering geocode_namedplace(city_name text, country_name text)') + plpy.debug('user_id = %s' % user_id) + + #-- Access control + #-- TODO: this should be part of cdb python library + if user_id == 'publicuser': + plpy.error('The api_key must be provided') + + #--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._geocode_namedplace($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; -------------------------------------------------------------------------------- @@ -49,5 +69,22 @@ RETURNS Geometry AS $$ $$ LANGUAGE plpgsql; ---- geocode_namedplace(city_name text, country_name text) +CREATE OR REPLACE FUNCTION _geocode_namedplace(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; diff --git a/server/extension/sql/50_namedplaces_test.sql b/server/extension/sql/50_namedplaces_test.sql index 469603b..4485d60 100644 --- a/server/extension/sql/50_namedplaces_test.sql +++ b/server/extension/sql/50_namedplaces_test.sql @@ -12,6 +12,11 @@ INSERT INTO global_cities_alternates_limited (geoname_id, name, preferred, lower 'POINT(0.6983 39.26787)',4326) ); +-- Insert dummy data into country decoder table +INSERT INTO country_decoder (synonyms, iso2) VALUES (Array['spain'], 'ES'); + -- This should return the point inserted above SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche'); +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Spain'); +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'Spain'); From 50abb76b6b8b843c40a54d9c309ca77e34deb250 Mon Sep 17 00:00:00 2001 From: Guido Fioravantti Date: Wed, 11 Nov 2015 17:48:08 +0100 Subject: [PATCH 11/14] Fixes cdb_geocoder_server.geocode_ip_point --- .../extension/expected/90_geocode_ip_test.out | 2 +- server/extension/sql/0.0.1/90_geocode_ip.sql | 35 +++++++++++++------ server/extension/sql/90_geocode_ip_test.sql | 2 +- 3 files changed, 26 insertions(+), 13 deletions(-) diff --git a/server/extension/expected/90_geocode_ip_test.out b/server/extension/expected/90_geocode_ip_test.out index db16fa5..fb24a88 100644 --- a/server/extension/expected/90_geocode_ip_test.out +++ b/server/extension/expected/90_geocode_ip_test.out @@ -7,7 +7,7 @@ SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0 (1 row) -- Insert dummy data into ip_address_locations -INSERT INTO ip_address_locations VALUES ('0.0.0.0'::inet, (ST_SetSRID(ST_MakePoint('40.40', '3.71'), 4326))); +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.geocode_ip_point(session_user, txid_current(), '0.0.0.0'); geocode_ip_point diff --git a/server/extension/sql/0.0.1/90_geocode_ip.sql b/server/extension/sql/0.0.1/90_geocode_ip.sql index 515ae17..6f9a306 100644 --- a/server/extension/sql/0.0.1/90_geocode_ip.sql +++ b/server/extension/sql/0.0.1/90_geocode_ip.sql @@ -28,16 +28,29 @@ $$ LANGUAGE plpythonu; -- Note: these functions depend on the cdb_geocoder extension CREATE OR REPLACE FUNCTION _geocode_ip_point(ip TEXT) RETURNS Geometry AS $$ - DECLARE - ret Geometry; + DECLARE + ret geocode_ip_v1%rowtype; - LIM INTEGER := 1; - BEGIN - SELECT ips.the_geom as geom INTO ret - FROM public.ip_address_locations ips - WHERE ips.network_start_ip = ip::inet - LIMIT LIM; - - RETURN ret; - END + new_ips INET[]; + old_ips TEXT[]; + BEGIN + BEGIN + IF family(ip::inet) = 6 THEN + new_ips := array_append(new_ips, ip::inet); + old_ips := array_append(old_ips, ip); + ELSE + new_ips := array_append(new_ips, ('::ffff:' || ip)::inet); + old_ips := array_append(old_ips, ip); + END IF; + EXCEPTION WHEN OTHERS THEN + SELECT ip AS q, NULL as geom, FALSE as success INTO ret; + RETURN ret; + END; + FOR ret IN WITH ips AS (SELECT unnest(old_ips) s, unnest(new_ips) 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 s, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success FROM matches + LOOP + RETURN ret.geom; + END LOOP; +END $$ LANGUAGE plpgsql; diff --git a/server/extension/sql/90_geocode_ip_test.sql b/server/extension/sql/90_geocode_ip_test.sql index 63ff315..a53b6bf 100644 --- a/server/extension/sql/90_geocode_ip_test.sql +++ b/server/extension/sql/90_geocode_ip_test.sql @@ -3,7 +3,7 @@ SELECT cdb_geocoder_server.geocode_ip_point(session_user, txid_current(), '0.0.0.0'); -- Insert dummy data into ip_address_locations -INSERT INTO ip_address_locations VALUES ('0.0.0.0'::inet, (ST_SetSRID(ST_MakePoint('40.40', '3.71'), 4326))); +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.geocode_ip_point(session_user, txid_current(), '0.0.0.0'); From 4aa757ac88292d06ae3e81318118442bd4a88537 Mon Sep 17 00:00:00 2001 From: Carla Iriberri Date: Wed, 11 Nov 2015 18:14:22 +0100 Subject: [PATCH 12/14] Adds namedplace function with 3 params #6 --- .../expected/50_namedplaces_test.out | 18 +++++++- server/extension/sql/0.0.1/50_namedplaces.sql | 46 +++++++++++++++++++ server/extension/sql/50_namedplaces_test.sql | 9 +++- 3 files changed, 69 insertions(+), 4 deletions(-) diff --git a/server/extension/expected/50_namedplaces_test.out b/server/extension/expected/50_namedplaces_test.out index b3f4549..2c1c49c 100644 --- a/server/extension/expected/50_namedplaces_test.out +++ b/server/extension/expected/50_namedplaces_test.out @@ -7,15 +7,17 @@ SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx (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', 'VA', 'AL', 34534, 'elche', ST_GeomFromText( +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', 'VA', ST_GeomFromText( +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.geocode_namedplace(session_user, txid_current(), 'Elx'); geocode_namedplace @@ -41,3 +43,15 @@ SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elc 0101000020E6100000637FD93D7958E63F2ECA6C9049A24340 (1 row) +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Valencia', 'Spain'); + geocode_namedplace +---------------------------------------------------- + 0101000020E6100000637FD93D7958E63F2ECA6C9049A24340 +(1 row) + +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'valencia', 'Spain'); + geocode_namedplace +---------------------------------------------------- + 0101000020E6100000637FD93D7958E63F2ECA6C9049A24340 +(1 row) + diff --git a/server/extension/sql/0.0.1/50_namedplaces.sql b/server/extension/sql/0.0.1/50_namedplaces.sql index 9d9a9fd..124aeea 100644 --- a/server/extension/sql/0.0.1/50_namedplaces.sql +++ b/server/extension/sql/0.0.1/50_namedplaces.sql @@ -44,6 +44,28 @@ RETURNS Geometry AS $$ return rv[0]["mypoint"] $$ LANGUAGE plpythonu; +---- geocode_namedplace(city_name text, admin1_name text, country_name text) +CREATE OR REPLACE FUNCTION geocode_namedplace(user_id name, tx_id bigint, city_name text, admin1_name text, country_name text) +RETURNS Geometry AS $$ + plpy.debug('Entering geocode_namedplace(city_name text, admin1_name text, country_name text)') + plpy.debug('user_id = %s' % user_id) + + #-- Access control + #-- TODO: this should be part of cdb python library + if user_id == 'publicuser': + plpy.error('The api_key must be provided') + + #--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._geocode_namedplace($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 @@ -88,3 +110,27 @@ RETURNS Geometry AS $$ END $$ LANGUAGE plpgsql; +---- geocode_namedplace(city_name text, admin1_name text, country_name text) +CREATE OR REPLACE FUNCTION _geocode_namedplace(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; + diff --git a/server/extension/sql/50_namedplaces_test.sql b/server/extension/sql/50_namedplaces_test.sql index 4485d60..7cbc541 100644 --- a/server/extension/sql/50_namedplaces_test.sql +++ b/server/extension/sql/50_namedplaces_test.sql @@ -3,20 +3,25 @@ SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx'); -- 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', 'VA', 'AL', 34534, 'elche', ST_GeomFromText( +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', 'VA', ST_GeomFromText( +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.geocode_namedplace(session_user, txid_current(), 'Elx'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Spain'); SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'Spain'); +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Valencia', 'Spain'); +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'valencia', 'Spain'); From 2b2d0bbc3307f0ec1a315115a45cc7dccb406043 Mon Sep 17 00:00:00 2001 From: Carla Iriberri Date: Wed, 11 Nov 2015 18:24:02 +0100 Subject: [PATCH 13/14] Adding more tests --- .../expected/50_namedplaces_test.out | 30 +++++++++++++++++++ 1 file changed, 30 insertions(+) diff --git a/server/extension/expected/50_namedplaces_test.out b/server/extension/expected/50_namedplaces_test.out index 2c1c49c..e69bbaa 100644 --- a/server/extension/expected/50_namedplaces_test.out +++ b/server/extension/expected/50_namedplaces_test.out @@ -6,6 +6,36 @@ SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx (1 row) +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche'); + geocode_namedplace +-------------------- + +(1 row) + +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Spain'); + geocode_namedplace +-------------------- + +(1 row) + +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'Spain'); + geocode_namedplace +-------------------- + +(1 row) + +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Valencia', 'Spain'); + geocode_namedplace +-------------------- + +(1 row) + +SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'valencia', 'Spain'); + geocode_namedplace +-------------------- + +(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) From c116541b100e3d261edc7908d831041f94bc9b5c Mon Sep 17 00:00:00 2001 From: Guido Fioravantti Date: Wed, 11 Nov 2015 19:25:48 +0100 Subject: [PATCH 14/14] Adds cdb_geocoder_server.geocode_postalcode_point and tests --- .../expected/50_namedplaces_test.out | 30 ------------ .../expected/80_postalcode_point_test.out | 22 +++++++++ .../sql/0.0.1/80_postalcode_point.sql | 48 +++++++++++++++++++ .../sql/80_postalcode_point_test.sql | 14 ++++++ 4 files changed, 84 insertions(+), 30 deletions(-) create mode 100644 server/extension/expected/80_postalcode_point_test.out create mode 100644 server/extension/sql/0.0.1/80_postalcode_point.sql create mode 100644 server/extension/sql/80_postalcode_point_test.sql diff --git a/server/extension/expected/50_namedplaces_test.out b/server/extension/expected/50_namedplaces_test.out index e69bbaa..2c1c49c 100644 --- a/server/extension/expected/50_namedplaces_test.out +++ b/server/extension/expected/50_namedplaces_test.out @@ -6,36 +6,6 @@ SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx (1 row) -SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche'); - geocode_namedplace --------------------- - -(1 row) - -SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Spain'); - geocode_namedplace --------------------- - -(1 row) - -SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'Spain'); - geocode_namedplace --------------------- - -(1 row) - -SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Valencia', 'Spain'); - geocode_namedplace --------------------- - -(1 row) - -SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'valencia', 'Spain'); - geocode_namedplace --------------------- - -(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) diff --git a/server/extension/expected/80_postalcode_point_test.out b/server/extension/expected/80_postalcode_point_test.out new file mode 100644 index 0000000..cb43d40 --- /dev/null +++ b/server/extension/expected/80_postalcode_point_test.out @@ -0,0 +1,22 @@ +-- Check that the public function is callable, even with no data +-- It should return NULL +SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204'); + 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 +); +-- This should return the polygon inserted above +SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204'); + geocode_postalcode_point +---------------------------------------------------- + 0101000020E61000000000000000E040408036B47414764840 +(1 row) + diff --git a/server/extension/sql/0.0.1/80_postalcode_point.sql b/server/extension/sql/0.0.1/80_postalcode_point.sql new file mode 100644 index 0000000..3b67843 --- /dev/null +++ b/server/extension/sql/0.0.1/80_postalcode_point.sql @@ -0,0 +1,48 @@ +-- Interface of the server extension + +CREATE OR REPLACE FUNCTION geocode_postalcode_point(user_id NAME, tx_id BIGINT, code text) +RETURNS Geometry AS $$ + plpy.debug('Entering _geocode_postalcode_point') + plpy.debug('user_id = %s' % user_id) + + #-- Access control + #-- TODO: this should be part of cdb python library + if user_id == 'publicuser': + plpy.error('The api_key must be provided') + + #--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._geocode_postalcode_point($1) AS point", ["text"]) + rv = plpy.execute(plan, [code], 1) + + plpy.debug('Returning from _geocode_postalcode_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 _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; diff --git a/server/extension/sql/80_postalcode_point_test.sql b/server/extension/sql/80_postalcode_point_test.sql new file mode 100644 index 0000000..a6e986f --- /dev/null +++ b/server/extension/sql/80_postalcode_point_test.sql @@ -0,0 +1,14 @@ +-- Check that the public function is callable, even with no data +-- It should return NULL +SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '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 +); + +-- This should return the polygon inserted above +SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204');