Merge pull request #23 from CartoDB/add-missing-functions

Add missing functions
This commit is contained in:
Rafa de la Torre 2015-11-12 12:27:31 +01:00
commit 6efebdc668
20 changed files with 443 additions and 175 deletions

View File

@ -2,3 +2,4 @@ results/
regression.diffs
regression.out
cdb_geocoder_server--0.0.1.sql

View File

@ -1,8 +1,8 @@
-- Check that the public function is callable, even with no data
-- It should return NULL
SELECT cdb_geocoder_server.geocode_admin0_polygons(session_user, txid_current(), 'Spain');
geocode_admin0_polygons
-------------------------
SELECT cdb_geocoder_server.geocode_admin0_polygon(session_user, txid_current(), 'Spain');
geocode_admin0_polygon
------------------------
(1 row)
@ -16,8 +16,8 @@ INSERT INTO ne_admin0_v3 (adm0_a3, the_geom) VALUES('ESP', ST_GeomFromText(
-71.1031880899493 42.3152774590236))',4326)
);
-- This should return the polygon inserted above
SELECT cdb_geocoder_server.geocode_admin0_polygons(session_user, txid_current(), 'Spain');
geocode_admin0_polygons
SELECT cdb_geocoder_server.geocode_admin0_polygon(session_user, txid_current(), 'Spain');
geocode_admin0_polygon
--------------------------------------------------------------------------------------------------------------------------------------------------------------------
0103000020E61000000100000004000000D0EA37A29AC651C00FD603035B284540FEFCFB379AC651C0C0503E9F5B284540FFDDDD4D96C651C033AC3B284F284540D0EA37A29AC651C00FD603035B284540
(1 row)

View File

@ -1,14 +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');
geocode_admin1_polygons
-------------------------
SELECT cdb_geocoder_server.geocode_admin1_polygon(session_user, txid_current(), 'California');
geocode_admin1_polygon
------------------------
(1 row)
SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California', 'United States');
geocode_admin1_polygons
-------------------------
SELECT cdb_geocoder_server.geocode_admin1_polygon(session_user, txid_current(), 'California', 'United States');
geocode_admin1_polygon
------------------------
(1 row)
@ -22,14 +22,14 @@ INSERT INTO global_province_polygons (synonyms, iso3, the_geom) VALUES (Array['c
-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
SELECT cdb_geocoder_server.geocode_admin1_polygon(session_user, txid_current(), 'California');
geocode_admin1_polygon
--------------------------------------------------------------------------------------------------------------------------------------------------------------------
0103000020E61000000100000004000000D0EA37A29AC651C00FD603035B284540FEFCFB379AC651C0C0503E9F5B284540FFDDDD4D96C651C033AC3B284F284540D0EA37A29AC651C00FD603035B284540
(1 row)
SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California', 'United States');
geocode_admin1_polygons
SELECT cdb_geocoder_server.geocode_admin1_polygon(session_user, txid_current(), 'California', 'United States');
geocode_admin1_polygon
--------------------------------------------------------------------------------------------------------------------------------------------------------------------
0103000020E61000000100000004000000D0EA37A29AC651C00FD603035B284540FEFCFB379AC651C0C0503E9F5B284540FFDDDD4D96C651C033AC3B284F284540D0EA37A29AC651C00FD603035B284540
(1 row)

View File

@ -1,8 +1,38 @@
-- 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
--------------------
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx');
geocode_namedplace_point
--------------------------
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche');
geocode_namedplace_point
--------------------------
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx', 'Spain');
geocode_namedplace_point
--------------------------
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche', 'Spain');
geocode_namedplace_point
--------------------------
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx', 'Valencia', 'Spain');
geocode_namedplace_point
--------------------------
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche', 'valencia', 'Spain');
geocode_namedplace_point
--------------------------
(1 row)
@ -49,38 +79,38 @@ 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
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx');
geocode_namedplace_point
----------------------------------------------------
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche');
geocode_namedplace
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche');
geocode_namedplace_point
----------------------------------------------------
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Spain');
geocode_namedplace
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx', 'Spain');
geocode_namedplace_point
----------------------------------------------------
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'Spain');
geocode_namedplace
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche', 'Spain');
geocode_namedplace_point
----------------------------------------------------
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elx', 'Valencia', 'Spain');
geocode_namedplace
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx', 'Valencia', 'Spain');
geocode_namedplace_point
----------------------------------------------------
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
(1 row)
SELECT cdb_geocoder_server.geocode_namedplace(session_user, txid_current(), 'Elche', 'valencia', 'Spain');
geocode_namedplace
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche', 'valencia', 'Spain');
geocode_namedplace_point
----------------------------------------------------
0101000020E6100000637FD93D7958E63F2ECA6C9049A24340
(1 row)

View File

@ -0,0 +1,74 @@
-- 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.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
);
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.geocode_postalcode_point(session_user, txid_current(), '03204');
geocode_postalcode_point
----------------------------------------------------
0101000020E61000000000000000E040408036B47414764840
(1 row)
SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204', 'spain');
geocode_postalcode_point
----------------------------------------------------
0101000020E61000000000000000E040408036B47414764840
(1 row)
SELECT cdb_geocoder_server.geocode_postalcode_polygon(session_user, txid_current(), '03204');
geocode_postalcode_polygon
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
0106000020E610000001000000010300000001000000040000000000000000E000C01F383D7839B740400000000000E000C0AA3C0EDE220F3B4000000000004812404FB7FCCD04893D400000000000E000C01F383D7839B74040
(1 row)
SELECT cdb_geocoder_server.geocode_postalcode_polygon(session_user, txid_current(), '03204', 'spain');
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;

View File

@ -1,22 +0,0 @@
-- 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)

View File

@ -1,5 +1,5 @@
-- Geocodes a street address given a searchtext and a state and/or country
CREATE OR REPLACE FUNCTION cdb_geocoder_server.geocode_street(searchtext TEXT, city TEXT DEFAULT NULL, state_province TEXT DEFAULT NULL, country TEXT DEFAULT NULL)
CREATE OR REPLACE FUNCTION cdb_geocoder_server.geocode_street_point(searchtext TEXT, city TEXT DEFAULT NULL, state_province TEXT DEFAULT NULL, country TEXT DEFAULT NULL)
RETURNS Geometry
AS $$
import json

View File

@ -1,6 +1,6 @@
-- Interface of the server extension
CREATE OR REPLACE FUNCTION cdb_geocoder_server.geocode_admin0_polygons(user_id name, tx_id bigint, country_name text)
CREATE OR REPLACE FUNCTION cdb_geocoder_server.geocode_admin0_polygon(user_id name, tx_id bigint, country_name text)
RETURNS Geometry AS $$
plpy.debug('Entering geocode_admin0_polygons')
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_admin0_polygons($1) AS mypolygon", ["text"])
plan = plpy.prepare("SELECT cdb_geocoder_server._geocode_admin0_polygon($1) AS mypolygon", ["text"])
rv = plpy.execute(plan, [country_name], 1)
plpy.debug('Returning from Returning from geocode_admin0_polygons')
@ -26,7 +26,7 @@ $$ LANGUAGE plpythonu;
-- Implementation of the server extension
-- Note: these functions depend on the cdb_geocoder extension
CREATE OR REPLACE FUNCTION cdb_geocoder_server._geocode_admin0_polygons(country_name text)
CREATE OR REPLACE FUNCTION cdb_geocoder_server._geocode_admin0_polygon(country_name text)
RETURNS Geometry AS $$
DECLARE
ret Geometry;

View File

@ -1,9 +1,9 @@
-- 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)
---- geocode_admin1_polygon(admin1_name text)
CREATE OR REPLACE FUNCTION geocode_admin1_polygon(user_id name, tx_id bigint, admin1_name text)
RETURNS Geometry AS $$
plpy.debug('Entering geocode_admin1_polygons(admin1_name text)')
plpy.debug('Entering geocode_admin1_polygon(admin1_name text)')
plpy.debug('user_id = %s' % user_id)
#-- Access control
@ -15,17 +15,17 @@ 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_admin1_polygons($1) AS mypolygon", ["text"])
plan = plpy.prepare("SELECT cdb_geocoder_server._geocode_admin1_polygon($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;
---- 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)
---- geocode_admin1_polygon(admin1_name text, country_name text)
CREATE OR REPLACE FUNCTION geocode_admin1_polygon(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('Entering geocode_admin1_polygon(admin1_name text, country_name text)')
plpy.debug('user_id = %s' % user_id)
#-- Access control
@ -37,10 +37,10 @@ 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_admin1_polygons($1, $2) AS mypolygon", ["text", "text"])
plan = plpy.prepare("SELECT cdb_geocoder_server._geocode_admin1_polygon($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)')
plpy.debug('Returning from Returning from geocode_admin1_polygon(admin1_name text, country_name text)')
return rv[0]["mypolygon"]
$$ LANGUAGE plpythonu;
@ -49,8 +49,8 @@ $$ 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)
---- geocode_admin1_polygon(admin1_name text)
CREATE OR REPLACE FUNCTION _geocode_admin1_polygon(admin1_name text)
RETURNS Geometry AS $$
DECLARE
ret Geometry;
@ -73,8 +73,8 @@ RETURNS Geometry AS $$
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)
---- geocode_admin1_polygon(admin1_name text, country_name text)
CREATE OR REPLACE FUNCTION _geocode_admin1_polygon(admin1_name text, country_name text)
RETURNS Geometry AS $$
DECLARE
ret Geometry;

View File

@ -1,9 +1,9 @@
-- 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)
---- geocode_namedplace_point(city_name text)
CREATE OR REPLACE FUNCTION geocode_namedplace_point(user_id name, tx_id bigint, city_name text)
RETURNS Geometry AS $$
plpy.debug('Entering geocode_namedplace(city_name text)')
plpy.debug('Entering geocode_namedplace_point(city_name text)')
plpy.debug('user_id = %s' % user_id)
#-- Access control
@ -15,17 +15,17 @@ 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_namedplace($1) AS mypoint", ["text"])
plan = plpy.prepare("SELECT cdb_geocoder_server._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;
---- 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)
---- geocode_namedplace_point(city_name text, country_name text)
CREATE OR REPLACE FUNCTION geocode_namedplace_point(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('Entering geocode_namedplace_point(city_name text, country_name text)')
plpy.debug('user_id = %s' % user_id)
#-- Access control
@ -37,17 +37,17 @@ 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_namedplace($1, $2) AS mypoint", ["text", "text"])
plan = plpy.prepare("SELECT cdb_geocoder_server._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;
---- 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)
---- geocode_namedplace_point(city_name text, admin1_name text, country_name text)
CREATE OR REPLACE FUNCTION geocode_namedplace_point(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('Entering geocode_namedplace_point(city_name text, admin1_name text, country_name text)')
plpy.debug('user_id = %s' % user_id)
#-- Access control
@ -59,7 +59,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_namedplace($1, $2, $3) AS mypoint", ["text", "text", "text"])
plan = plpy.prepare("SELECT cdb_geocoder_server._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')
@ -71,8 +71,8 @@ $$ LANGUAGE plpythonu;
-- 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)
---- geocode_namedplace_point(city_name text)
CREATE OR REPLACE FUNCTION _geocode_namedplace_point(city_name text)
RETURNS Geometry AS $$
DECLARE
ret Geometry;
@ -90,8 +90,8 @@ RETURNS Geometry AS $$
END
$$ LANGUAGE plpgsql;
---- geocode_namedplace(city_name text, country_name text)
CREATE OR REPLACE FUNCTION _geocode_namedplace(city_name text, country_name text)
---- geocode_namedplace_point(city_name text, country_name text)
CREATE OR REPLACE FUNCTION _geocode_namedplace_point(city_name text, country_name text)
RETURNS Geometry AS $$
DECLARE
ret Geometry;
@ -110,8 +110,8 @@ 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)
---- geocode_namedplace_point(city_name text, admin1_name text, country_name text)
CREATE OR REPLACE FUNCTION _geocode_namedplace_point(city_name text, admin1_name text, country_name text)
RETURNS Geometry AS $$
DECLARE
ret Geometry;

View File

@ -0,0 +1,184 @@
-- TODO geocode_postalcode_polygon(code text, country text)
-- 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;
CREATE OR REPLACE FUNCTION geocode_postalcode_point(user_id NAME, tx_id BIGINT, code text, country 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, $2) AS point", ["TEXT", "TEXT"])
rv = plpy.execute(plan, [code, country], 1)
plpy.debug('Returning from _geocode_postalcode_point')
return rv[0]["point"]
$$ LANGUAGE plpythonu;
CREATE OR REPLACE FUNCTION geocode_postalcode_polygon(user_id NAME, tx_id BIGINT, code text)
RETURNS Geometry AS $$
plpy.debug('Entering _geocode_postalcode_polygon')
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_polygon($1) AS polygon", ["text"])
rv = plpy.execute(plan, [code], 1)
plpy.debug('Returning from _geocode_postalcode_polygon')
return rv[0]["polygon"]
$$ LANGUAGE plpythonu;
CREATE OR REPLACE FUNCTION geocode_postalcode_polygon(user_id NAME, tx_id BIGINT, code text, country 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_polygon($1, $2) AS polygon", ["TEXT", "TEXT"])
rv = plpy.execute(plan, [code, country], 1)
plpy.debug('Returning from _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 _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 _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 _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 _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;

View File

@ -29,28 +29,26 @@ $$ LANGUAGE plpythonu;
CREATE OR REPLACE FUNCTION _geocode_ip_point(ip TEXT)
RETURNS Geometry AS $$
DECLARE
ret geocode_ip_v1%rowtype;
ret Geometry;
new_ips INET[];
old_ips TEXT[];
new_ip INET;
BEGIN
BEGIN
IF family(ip::inet) = 6 THEN
new_ips := array_append(new_ips, ip::inet);
old_ips := array_append(old_ips, ip);
new_ip := ip::inet;
ELSE
new_ips := array_append(new_ips, ('::ffff:' || ip)::inet);
old_ips := array_append(old_ips, ip);
new_ip := ('::ffff:' || ip)::inet;
END IF;
EXCEPTION WHEN OTHERS THEN
SELECT ip AS q, NULL as geom, FALSE as success INTO ret;
SELECT NULL as geom INTO ret;
RETURN ret;
END;
FOR ret IN WITH ips AS (SELECT unnest(old_ips) s, unnest(new_ips) net),
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 s, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success FROM matches
LOOP
RETURN ret.geom;
END LOOP;
SELECT geom INTO ret
FROM matches;
RETURN ret;
END
$$ LANGUAGE plpgsql;

View File

@ -1,48 +0,0 @@
-- 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;

View File

@ -1,6 +1,6 @@
-- Check that the public function is callable, even with no data
-- It should return NULL
SELECT cdb_geocoder_server.geocode_admin0_polygons(session_user, txid_current(), 'Spain');
SELECT cdb_geocoder_server.geocode_admin0_polygon(session_user, txid_current(), 'Spain');
-- Insert some dummy synonym
INSERT INTO admin0_synonyms (name, adm0_a3) VALUES ('Spain', 'ESP');
@ -14,4 +14,4 @@ INSERT INTO ne_admin0_v3 (adm0_a3, the_geom) VALUES('ESP', ST_GeomFromText(
);
-- This should return the polygon inserted above
SELECT cdb_geocoder_server.geocode_admin0_polygons(session_user, txid_current(), 'Spain');
SELECT cdb_geocoder_server.geocode_admin0_polygon(session_user, txid_current(), 'Spain');

View File

@ -1,7 +1,7 @@
-- 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');
SELECT cdb_geocoder_server.geocode_admin1_polygon(session_user, txid_current(), 'California');
SELECT cdb_geocoder_server.geocode_admin1_polygon(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');
@ -15,8 +15,8 @@ INSERT INTO global_province_polygons (synonyms, iso3, the_geom) VALUES (Array['c
);
-- 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');
SELECT cdb_geocoder_server.geocode_admin1_polygon(session_user, txid_current(), 'California');
SELECT cdb_geocoder_server.geocode_admin1_polygon(session_user, txid_current(), 'California', 'United States');

View File

@ -1,6 +1,11 @@
-- 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');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx', 'Spain');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche', 'Spain');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx', 'Valencia', 'Spain');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche', '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(
@ -19,9 +24,9 @@ INSERT INTO country_decoder (synonyms, iso2) VALUES (Array['spain'], 'ES');
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');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx', 'Spain');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche', 'Spain');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elx', 'Valencia', 'Spain');
SELECT cdb_geocoder_server.geocode_namedplace_point(session_user, txid_current(), 'Elche', 'valencia', 'Spain');

View File

@ -0,0 +1,60 @@
-- 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.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
);
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.geocode_postalcode_point(session_user, txid_current(), '03204');
SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current(), '03204', 'spain');
SELECT cdb_geocoder_server.geocode_postalcode_polygon(session_user, txid_current(), '03204');
SELECT cdb_geocoder_server.geocode_postalcode_polygon(session_user, txid_current(), '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;

View File

@ -1,14 +0,0 @@
-- 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');