Adds cdb_geocoder_server.geocode_postalcode_point and tests
This commit is contained in:
parent
2b2d0bbc33
commit
c116541b10
@ -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)
|
||||
|
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)
|
||||
|
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;
|
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');
|
Loading…
Reference in New Issue
Block a user