Merge pull request #21 from CartoDB/implement_server_functions
Implement server functions
This commit is contained in:
commit
4e7525cc88
36
server/extension/expected/40_admin1_test.out
Normal file
36
server/extension/expected/40_admin1_test.out
Normal file
@ -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)
|
||||||
|
|
57
server/extension/expected/50_namedplaces_test.out
Normal file
57
server/extension/expected/50_namedplaces_test.out
Normal file
@ -0,0 +1,57 @@
|
|||||||
|
-- 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', '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.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)
|
||||||
|
|
||||||
|
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)
|
||||||
|
|
||||||
|
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)
|
||||||
|
|
22
server/extension/expected/80_postalcode_point_test.out
Normal file
22
server/extension/expected/80_postalcode_point_test.out
Normal file
@ -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)
|
||||||
|
|
17
server/extension/expected/90_geocode_ip_test.out
Normal file
17
server/extension/expected/90_geocode_ip_test.out
Normal file
@ -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');
|
||||||
|
geocode_ip_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.geocode_ip_point(session_user, txid_current(), '0.0.0.0');
|
||||||
|
geocode_ip_point
|
||||||
|
----------------------------------------------------
|
||||||
|
0101000020E61000003333333333334440AE47E17A14AE0D40
|
||||||
|
(1 row)
|
||||||
|
|
99
server/extension/sql/0.0.1/40_admin1.sql
Normal file
99
server/extension/sql/0.0.1/40_admin1.sql
Normal file
@ -0,0 +1,99 @@
|
|||||||
|
-- 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(admin1_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) 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)
|
||||||
|
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
|
||||||
|
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;
|
||||||
|
|
||||||
|
---- 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;
|
||||||
|
|
136
server/extension/sql/0.0.1/50_namedplaces.sql
Normal file
136
server/extension/sql/0.0.1/50_namedplaces.sql
Normal file
@ -0,0 +1,136 @@
|
|||||||
|
-- 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_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;
|
||||||
|
|
||||||
|
---- 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
|
||||||
|
-- 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)
|
||||||
|
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;
|
||||||
|
|
||||||
|
---- 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;
|
||||||
|
|
48
server/extension/sql/0.0.1/80_postalcode_point.sql
Normal file
48
server/extension/sql/0.0.1/80_postalcode_point.sql
Normal file
@ -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;
|
56
server/extension/sql/0.0.1/90_geocode_ip.sql
Normal file
56
server/extension/sql/0.0.1/90_geocode_ip.sql
Normal file
@ -0,0 +1,56 @@
|
|||||||
|
-- Interface of the server extension
|
||||||
|
|
||||||
|
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)
|
||||||
|
|
||||||
|
#-- 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", ["TEXT"])
|
||||||
|
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 TEXT)
|
||||||
|
RETURNS Geometry AS $$
|
||||||
|
DECLARE
|
||||||
|
ret geocode_ip_v1%rowtype;
|
||||||
|
|
||||||
|
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;
|
24
server/extension/sql/40_admin1_test.sql
Normal file
24
server/extension/sql/40_admin1_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.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, 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');
|
||||||
|
SELECT cdb_geocoder_server.geocode_admin1_polygons(session_user, txid_current(), 'California', 'United States');
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
27
server/extension/sql/50_namedplaces_test.sql
Normal file
27
server/extension/sql/50_namedplaces_test.sql
Normal file
@ -0,0 +1,27 @@
|
|||||||
|
-- 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', '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.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');
|
14
server/extension/sql/80_postalcode_point_test.sql
Normal file
14
server/extension/sql/80_postalcode_point_test.sql
Normal file
@ -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');
|
9
server/extension/sql/90_geocode_ip_test.sql
Normal file
9
server/extension/sql/90_geocode_ip_test.sql
Normal file
@ -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');
|
||||||
|
|
||||||
|
-- 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.geocode_ip_point(session_user, txid_current(), '0.0.0.0');
|
Loading…
Reference in New Issue
Block a user