From 20cc610da57ee53448d83285d862a9873e0e3a94 Mon Sep 17 00:00:00 2001 From: Guido Fioravantti Date: Thu, 12 Nov 2015 11:20:12 +0100 Subject: [PATCH] Adds postalcode polygon and renames --- .../expected/60_postalcodes_test.out | 74 ++++++++++++++++ ...90_geocode_ip_test.out => 70_ips_test.out} | 0 .../expected/80_postalcode_point_test.out | 54 ------------ ...ostalcode_point.sql => 60_postalcodes.sql} | 88 +++++++++++++++++++ .../0.0.1/{90_geocode_ip.sql => 70_ips.sql} | 0 ...point_test.sql => 60_postalcodes_test.sql} | 13 +++ ...90_geocode_ip_test.sql => 70_ips_test.sql} | 0 7 files changed, 175 insertions(+), 54 deletions(-) create mode 100644 server/extension/expected/60_postalcodes_test.out rename server/extension/expected/{90_geocode_ip_test.out => 70_ips_test.out} (100%) delete mode 100644 server/extension/expected/80_postalcode_point_test.out rename server/extension/sql/0.0.1/{80_postalcode_point.sql => 60_postalcodes.sql} (52%) rename server/extension/sql/0.0.1/{90_geocode_ip.sql => 70_ips.sql} (100%) rename server/extension/sql/{80_postalcode_point_test.sql => 60_postalcodes_test.sql} (68%) rename server/extension/sql/{90_geocode_ip_test.sql => 70_ips_test.sql} (100%) diff --git a/server/extension/expected/60_postalcodes_test.out b/server/extension/expected/60_postalcodes_test.out new file mode 100644 index 0000000..f777d2b --- /dev/null +++ b/server/extension/expected/60_postalcodes_test.out @@ -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; diff --git a/server/extension/expected/90_geocode_ip_test.out b/server/extension/expected/70_ips_test.out similarity index 100% rename from server/extension/expected/90_geocode_ip_test.out rename to server/extension/expected/70_ips_test.out diff --git a/server/extension/expected/80_postalcode_point_test.out b/server/extension/expected/80_postalcode_point_test.out deleted file mode 100644 index 4044d30..0000000 --- a/server/extension/expected/80_postalcode_point_test.out +++ /dev/null @@ -1,54 +0,0 @@ --- Make sure dbs are clean -DELETE FROM global_postal_code_points; -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 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) - --- Clean dbs -DELETE FROM global_postal_code_points; -DELETE FROM country_decoder; -DELETE FROM available_services; -DELETE FROM admin0_synonyms; diff --git a/server/extension/sql/0.0.1/80_postalcode_point.sql b/server/extension/sql/0.0.1/60_postalcodes.sql similarity index 52% rename from server/extension/sql/0.0.1/80_postalcode_point.sql rename to server/extension/sql/0.0.1/60_postalcodes.sql index b86930f..ca76a8d 100644 --- a/server/extension/sql/0.0.1/80_postalcode_point.sql +++ b/server/extension/sql/0.0.1/60_postalcodes.sql @@ -44,6 +44,48 @@ RETURNS Geometry AS $$ 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; + -------------------------------------------------------------------------------- @@ -94,3 +136,49 @@ RETURNS Geometry AS $$ 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; diff --git a/server/extension/sql/0.0.1/90_geocode_ip.sql b/server/extension/sql/0.0.1/70_ips.sql similarity index 100% rename from server/extension/sql/0.0.1/90_geocode_ip.sql rename to server/extension/sql/0.0.1/70_ips.sql diff --git a/server/extension/sql/80_postalcode_point_test.sql b/server/extension/sql/60_postalcodes_test.sql similarity index 68% rename from server/extension/sql/80_postalcode_point_test.sql rename to server/extension/sql/60_postalcodes_test.sql index 3293178..f822d0f 100644 --- a/server/extension/sql/80_postalcode_point_test.sql +++ b/server/extension/sql/60_postalcodes_test.sql @@ -1,5 +1,6 @@ -- 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; @@ -16,6 +17,13 @@ INSERT INTO global_postal_code_points (the_geom, iso3, postal_code, postal_code_ 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'] @@ -40,8 +48,13 @@ SELECT cdb_geocoder_server.geocode_postalcode_point(session_user, txid_current() 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; diff --git a/server/extension/sql/90_geocode_ip_test.sql b/server/extension/sql/70_ips_test.sql similarity index 100% rename from server/extension/sql/90_geocode_ip_test.sql rename to server/extension/sql/70_ips_test.sql