Merge pull request #180 from CartoDB/merge-into-one-extension
Merge into one extension
This commit is contained in:
commit
7726f13889
1
geocoder/.gitignore
vendored
Normal file
1
geocoder/.gitignore
vendored
Normal file
@ -0,0 +1 @@
|
||||
db_dumps/
|
@ -1,8 +0,0 @@
|
||||
EXTENSION = cdb_geocoder_admin0
|
||||
DATA = cdb_geocoder_admin0--0.0.1.sql
|
||||
REGRESS = cdb_geocoder_admin0_test
|
||||
|
||||
# postgres build stuff
|
||||
PG_CONFIG = pg_config
|
||||
PGXS := $(shell $(PG_CONFIG) --pgxs)
|
||||
include $(PGXS)
|
@ -1,36 +0,0 @@
|
||||
# CartoDB admin0 geocoder extension
|
||||
Postgres extension for the CartoDB admin0 geocoder. It is meant to contain the functions and related objects needed to geocode by admin0 regions. It is not meant to contain the actual data used to geocode them.
|
||||
|
||||
## Dependencies
|
||||
This extension is thought to be used on top of CartoDB platform. Therefore a cartodb user is required to install the extension onto it.
|
||||
|
||||
The following is a non-comprehensive list of dependencies:
|
||||
|
||||
- Postgres 9.3+
|
||||
- Postgis extension
|
||||
- Schema triggers extension
|
||||
- CartoDB extension
|
||||
|
||||
## Installation into the db cluster
|
||||
This requires root privileges
|
||||
```
|
||||
sudo make all install
|
||||
```
|
||||
|
||||
## Execute tests
|
||||
```
|
||||
PGUSER=postgres make installcheck
|
||||
```
|
||||
|
||||
## Install onto a user's database
|
||||
```
|
||||
psql -U development_cartodb_user_fe3b850a-01c0-48f9-8a26-a82f09e9b53f cartodb_dev_user_fe3b850a-01c0-48f9-8a26-a82f09e9b53f_db
|
||||
```
|
||||
|
||||
and then:
|
||||
|
||||
```sql
|
||||
CREATE EXTENSION cdb_geocoder_admin0;
|
||||
```
|
||||
|
||||
The extension creation in the user's db does not require special privileges. It can be even created from the sql api.
|
@ -1,3 +1,4 @@
|
||||
results/
|
||||
regression.diffs
|
||||
regression.out
|
||||
cdb_geocoder--0.0.1.sql
|
26
geocoder/extension/Makefile
Normal file
26
geocoder/extension/Makefile
Normal file
@ -0,0 +1,26 @@
|
||||
# Makefile to generate the extension out of separate sql source files.
|
||||
# Once a version is released, it is not meant to be changed. E.g: once version 0.0.1 is out, it SHALL NOT be changed.
|
||||
EXTENSION = cdb_geocoder
|
||||
EXTVERSION = $(shell grep default_version $(EXTENSION).control | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/")
|
||||
|
||||
DATA = $(EXTENSION)--$(EXTVERSION).sql
|
||||
|
||||
REGRESS = $(notdir $(basename $(wildcard sql/*test.sql)))
|
||||
|
||||
# postgres build stuff
|
||||
PG_CONFIG = pg_config
|
||||
PGXS := $(shell $(PG_CONFIG) --pgxs)
|
||||
include $(PGXS)
|
||||
|
||||
|
||||
SOURCES_DATA = $(wildcard sql/$(EXTVERSION)/*.sql)
|
||||
|
||||
$(DATA): $(SOURCES_DATA)
|
||||
rm -f $@
|
||||
cat $(SOURCES_DATA) >> $@
|
||||
|
||||
all: $(DATA)
|
||||
|
||||
# Only meant for development time, do not use once a version is released
|
||||
devclean:
|
||||
rm -f $(DATA)
|
45
geocoder/extension/README.md
Normal file
45
geocoder/extension/README.md
Normal file
@ -0,0 +1,45 @@
|
||||
# CartoDB geocoder extension
|
||||
Postgres extension for the CartoDB geocoder. It is meant to contain the functions and related objects needed to provide a geocoding service for administrative areas of level 0, administrative areas of level 1, postal codes, IP addresses and city names. It is not meant to contain the actual data used to geocode them.
|
||||
|
||||
## Dependencies
|
||||
This extension is thought to be used on top of CartoDB platform. Therefore **a cartodb user is required** to install the extension onto it.
|
||||
|
||||
The following is a non-comprehensive list of dependencies:
|
||||
|
||||
- Postgres 9.3+
|
||||
- Postgis extension
|
||||
- Schema triggers extension
|
||||
- CartoDB extension
|
||||
|
||||
## Installation into the db cluster
|
||||
This requires root privileges
|
||||
```
|
||||
sudo make all install
|
||||
```
|
||||
|
||||
## Execute tests
|
||||
```
|
||||
PGUSER=postgres make installcheck
|
||||
```
|
||||
|
||||
## Build, install & test
|
||||
One-liner:
|
||||
```
|
||||
sudo PGUSER=postgres make all install installcheck
|
||||
```
|
||||
|
||||
## Install onto a cartodb user's database
|
||||
|
||||
Remember that **is mandatory to install into a cartodb user's database**
|
||||
|
||||
```
|
||||
psql -U development_cartodb_user_fe3b850a-01c0-48f9-8a26-a82f09e9b53f cartodb_dev_user_fe3b850a-01c0-48f9-8a26-a82f09e9b53f_db
|
||||
```
|
||||
|
||||
and then:
|
||||
|
||||
```sql
|
||||
CREATE EXTENSION cdb_geocoder;
|
||||
```
|
||||
|
||||
The extension creation in the user's db does not require special privileges. It can be even created from the sql api.
|
@ -1,5 +1,5 @@
|
||||
# cdb geocoder admin0 extension
|
||||
comment = 'CartoDB admin0 internal geocoder'
|
||||
# cdb geocoder extension
|
||||
comment = 'CartoDB internal geocoder'
|
||||
default_version = '0.0.1'
|
||||
relocatable = true
|
||||
requires = cartodb
|
14
geocoder/extension/expected/00_install_test.out
Normal file
14
geocoder/extension/expected/00_install_test.out
Normal file
@ -0,0 +1,14 @@
|
||||
-- Install dependencies
|
||||
CREATE EXTENSION postgis;
|
||||
CREATE EXTENSION schema_triggers;
|
||||
CREATE EXTENSION plpythonu;
|
||||
CREATE EXTENSION cartodb;
|
||||
-- Install the extension
|
||||
CREATE EXTENSION cdb_geocoder;
|
||||
-- Mock the varnish invalidation function
|
||||
CREATE OR REPLACE FUNCTION public.cdb_invalidate_varnish(table_name text) RETURNS void AS $$
|
||||
BEGIN
|
||||
RETURN;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
@ -1,8 +1,3 @@
|
||||
CREATE EXTENSION postgis;
|
||||
CREATE EXTENSION schema_triggers;
|
||||
CREATE EXTENSION plpythonu;
|
||||
CREATE EXTENSION cartodb;
|
||||
CREATE EXTENSION cdb_geocoder_admin0;
|
||||
-- Check that the synonym function is callable, should return NULL
|
||||
SELECT (admin0_synonym_lookup(Array['United States', 'ESP'])).*;
|
||||
q | adm0_a3
|
||||
@ -20,13 +15,6 @@ SELECT (geocode_admin0_polygons(Array['Spain', 'USA', ''])).*;
|
||||
USA | | f
|
||||
(3 rows)
|
||||
|
||||
-- Mock the varnish invalidation function
|
||||
CREATE OR REPLACE FUNCTION public.cdb_invalidate_varnish(table_name text) RETURNS void AS $$
|
||||
BEGIN
|
||||
RETURN;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
-- Add a few synonyms
|
||||
COPY admin0_synonyms (name, rank, created_at, updated_at, the_geom, the_geom_webmercator, cartodb_id, adm0_a3, name_) FROM stdin;
|
||||
-- Check that the synonym function is callable, should return their iso codes
|
43
geocoder/extension/expected/20_admin1_test.out
Normal file
43
geocoder/extension/expected/20_admin1_test.out
Normal file
@ -0,0 +1,43 @@
|
||||
-- Check that the geocoding functions are callable, should return NULL
|
||||
SELECT (geocode_admin1_polygons(Array['TX','Cuidad Real', 'sevilla'])).*;
|
||||
q | geom | success
|
||||
-------------+------+---------
|
||||
TX | | f
|
||||
Cuidad Real | | f
|
||||
sevilla | | f
|
||||
(3 rows)
|
||||
|
||||
SELECT (geocode_admin1_polygons(Array['NH', 'Vermont'], 'United States')).*;
|
||||
q | geom | success
|
||||
---------+------+---------
|
||||
NH | | f
|
||||
Vermont | | f
|
||||
(2 rows)
|
||||
|
||||
SELECT (geocode_admin1_polygons(Array['az', 'az'], Array['Ecuador', 'USA'])).*;
|
||||
q | c | geom | success
|
||||
----+---------+------+---------
|
||||
az | Ecuador | | f
|
||||
az | USA | | f
|
||||
(2 rows)
|
||||
|
||||
-- Add a few data to the sources
|
||||
INSERT INTO global_province_polygons (the_geom, synonyms, iso3) VALUES (
|
||||
'0106000020E610000001000000010300000001000000040000000000000000E000C01F383D7839B740400000000000E000C0AA3C0EDE220F3B4000000000004812404FB7FCCD04893D400000000000E000C01F383D7839B74040',
|
||||
Array['vipava','obcina vipava','vipava, obcina'],
|
||||
'SVN'
|
||||
);
|
||||
-- Check that the synonym function is callable, should return true
|
||||
SELECT (geocode_admin1_polygons(Array['obcina vipava'])).success;
|
||||
success
|
||||
---------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
-- Check that it returns the mocked geometry above
|
||||
SELECT (geocode_admin1_polygons(Array['obcina vipava'])).geom;
|
||||
geom
|
||||
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
0106000020E610000001000000010300000001000000040000000000000000E000C01F383D7839B740400000000000E000C0AA3C0EDE220F3B4000000000004812404FB7FCCD04893D400000000000E000C01F383D7839B74040
|
||||
(1 row)
|
||||
|
16
geocoder/extension/expected/30_ipaddr_test.out
Normal file
16
geocoder/extension/expected/30_ipaddr_test.out
Normal file
@ -0,0 +1,16 @@
|
||||
-- Check that the geocoding function is callable, should return success = false
|
||||
SELECT (geocode_ip(Array['100.0.24.0'])).*;
|
||||
q | geom | success
|
||||
------------+------+---------
|
||||
100.0.24.0 | | f
|
||||
(1 row)
|
||||
|
||||
-- Add a few IP sources
|
||||
COPY ip_address_locations (network_start_ip, the_geom, cartodb_id, created_at, updated_at, the_geom_webmercator) FROM stdin;
|
||||
-- Check that the geocoding function is callable, should return success = true
|
||||
SELECT (geocode_ip(Array['2.235.35.0'])).*;
|
||||
q | geom | success
|
||||
------------+----------------------------------------------------+---------
|
||||
2.235.35.0 | 0101000020E610000072F90FE9B7CF22405DFE43FAEDC34640 | t
|
||||
(1 row)
|
||||
|
58
geocoder/extension/expected/40_namedplaces_test.out
Normal file
58
geocoder/extension/expected/40_namedplaces_test.out
Normal file
@ -0,0 +1,58 @@
|
||||
-- Check that the different geocoding functions are callable, should return success = false
|
||||
SELECT (geocode_namedplace(Array['Madrid', 'New York City', 'sunapee'])).*;
|
||||
q | geom | success
|
||||
---------------+------+---------
|
||||
Madrid | | f
|
||||
New York City | | f
|
||||
sunapee | | f
|
||||
(3 rows)
|
||||
|
||||
SELECT (geocode_namedplace(Array['Elche', 'Granada', 'Madrid'], 'Spain')).*;
|
||||
q | c | geom | success
|
||||
---------+-------+------+---------
|
||||
Elche | Spain | | f
|
||||
Granada | Spain | | f
|
||||
Madrid | Spain | | f
|
||||
(3 rows)
|
||||
|
||||
SELECT (geocode_namedplace(Array['sunapee', 'sunapeeee', 'New York City', 'Madrid'], Array['', 'US', 'United States', NULL])).*;
|
||||
q | c | geom | success
|
||||
---------------+---------------+------+---------
|
||||
Madrid | | | f
|
||||
sunapee | | | f
|
||||
sunapeeee | US | | f
|
||||
New York City | United States | | f
|
||||
(4 rows)
|
||||
|
||||
SELECT (geocode_namedplace(Array['Portland', 'Portland', 'New York City'], Array['Maine', 'Oregon', NULL], 'USA')).*;
|
||||
q | a1 | c | geom | success
|
||||
---------------+--------+-----+------+---------
|
||||
New York City | | USA | | f
|
||||
Portland | Maine | USA | | f
|
||||
Portland | Oregon | USA | | f
|
||||
(3 rows)
|
||||
|
||||
SELECT (geocode_namedplace(Array['Portland'], 'Oregon', 'USA')).*;
|
||||
q | a1 | c | geom | success
|
||||
----------+--------+-----+------+---------
|
||||
Portland | Oregon | USA | | f
|
||||
(1 row)
|
||||
|
||||
SELECT (geocode_namedplace(Array['Portland', 'Portland', 'New York City'], Array['Maine', 'Oregon', NULL], Array['USA'])).*;
|
||||
q | a1 | c | geom | success
|
||||
---------------+--------+-----+------+---------
|
||||
New York City | | USA | | f
|
||||
Portland | Oregon | USA | | f
|
||||
Portland | Maine | USA | | f
|
||||
(3 rows)
|
||||
|
||||
-- Add a named place source
|
||||
COPY global_cities_alternates_limited (geoname_id, name, the_geom, created_at, updated_at, the_geom_webmercator, preferred, lowername, cartodb_id, admin1_geonameid, iso2, admin1) FROM stdin;
|
||||
COPY global_cities_points_limited (geoname_id, name, asciiname, altnames, featclass, featcode, iso2, admin1, admin2, population, the_geom, created_at, updated_at, the_geom_webmercator, cartodb_id, lowername) FROM stdin;
|
||||
-- Check that the geocoding function is callable, should return success = true
|
||||
SELECT (geocode_namedplace(Array['Barcelona'])).*
|
||||
q | geom | success
|
||||
-----------+----------------------------------------------------+---------
|
||||
Barcelona | 0101000020E6100000CA15DEE522E653C0A4C2D842902B4540 | t
|
||||
(1 row)
|
||||
|
96
geocoder/extension/expected/50_postalcode_test.out
Normal file
96
geocoder/extension/expected/50_postalcode_test.out
Normal file
@ -0,0 +1,96 @@
|
||||
SELECT (geocode_postalcode_polygons(Array['03204'], Array['Spain'])).*;
|
||||
q | c | geom | success
|
||||
-------+-------+------+---------
|
||||
03204 | Spain | | f
|
||||
(1 row)
|
||||
|
||||
SELECT (geocode_postalcode_polygons(Array['03204'], 'ESP')).*;
|
||||
q | geom | success
|
||||
-------+------+---------
|
||||
03204 | | f
|
||||
(1 row)
|
||||
|
||||
SELECT (geocode_postalcode_polygons(Array['03204'])).*;
|
||||
q | geom | success
|
||||
-------+------+---------
|
||||
03204 | | f
|
||||
(1 row)
|
||||
|
||||
SELECT (geocode_postalcode_points(Array['03204'], 'Spain')).*;
|
||||
q | geom | success
|
||||
-------+------+---------
|
||||
03204 | | f
|
||||
(1 row)
|
||||
|
||||
SELECT (geocode_postalcode_points('{03204}', 'Spain')).*;
|
||||
q | geom | success
|
||||
-------+------+---------
|
||||
03204 | | f
|
||||
(1 row)
|
||||
|
||||
SELECT (geocode_postalcode_points(Array['03204'])).*;
|
||||
q | geom | success
|
||||
-------+------+---------
|
||||
03204 | | f
|
||||
(1 row)
|
||||
|
||||
SELECT (geocode_postalcode_points(Array['03204'], Array['Spain'])).*;
|
||||
q | c | iso3 | geom | success
|
||||
-------+-------+------+------+---------
|
||||
03204 | Spain | | | f
|
||||
(1 row)
|
||||
|
||||
SELECT geocode_greatbritain_outward('YO1 721');
|
||||
geocode_greatbritain_outward
|
||||
------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT (admin0_available_services(Array['Spain'])).*;
|
||||
q | adm0_a3 | postal_code_points | postal_code_polygons
|
||||
-------+---------+--------------------+----------------------
|
||||
Spain | | |
|
||||
(1 row)
|
||||
|
||||
-- Insert mock source data
|
||||
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
|
||||
);
|
||||
INSERT INTO admin0_synonyms (adm0_a3, name, name_, rank) VALUES (
|
||||
'ESP',
|
||||
'ESP',
|
||||
'esp',
|
||||
4
|
||||
);
|
||||
-- Check that the geocoding function is callable, should return success = true
|
||||
SELECT (geocode_postalcode_polygons(Array['03204'], Array['Spain'])).geom;
|
||||
geom
|
||||
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
0106000020E610000001000000010300000001000000040000000000000000E000C01F383D7839B740400000000000E000C0AA3C0EDE220F3B4000000000004812404FB7FCCD04893D400000000000E000C01F383D7839B74040
|
||||
(1 row)
|
||||
|
2
geocoder/extension/sql/0.0.1/00_header.sql
Normal file
2
geocoder/extension/sql/0.0.1/00_header.sql
Normal file
@ -0,0 +1,2 @@
|
||||
-- Complain if script is sourced in psql, rather than via CREATE EXTENSION
|
||||
\echo Use "CREATE EXTENSION cdb_geocoder" to load this file. \quit
|
21
geocoder/extension/sql/0.0.1/05_types.sql
Normal file
21
geocoder/extension/sql/0.0.1/05_types.sql
Normal file
@ -0,0 +1,21 @@
|
||||
-- Response types for admin0 geocoder
|
||||
CREATE TYPE geocode_admin_v1 AS (q TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
CREATE TYPE synonym_lookup_v1 AS (q TEXT, adm0_a3 TEXT);
|
||||
|
||||
-- Response types for admin1 geocoder
|
||||
CREATE TYPE geocode_admin_country_v1 AS (q TEXT, c TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
|
||||
-- Response types for IP addresses geocoder
|
||||
CREATE TYPE geocode_ip_v1 AS (q text, geom geometry, success boolean);
|
||||
|
||||
-- Response types for namedplaces geocoder
|
||||
CREATE TYPE geocode_namedplace_country_v1 AS (q TEXT, c TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
CREATE TYPE geocode_namedplace_v1 AS (q TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
CREATE TYPE geocode_admin1_country_v1 AS (q text, a1 text, c text, geom geometry, success boolean);
|
||||
|
||||
-- Response types for postalcodes geocoder
|
||||
CREATE TYPE geocode_postalint_country_v1 AS (q INT, c TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
CREATE TYPE geocode_place_country_iso_v1 AS (q TEXT, c TEXT, iso3 TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
|
||||
|
||||
CREATE TYPE available_services_v1 AS (q text, adm0_a3 text, postal_code_points boolean, postal_code_polygons boolean);
|
@ -1,10 +1,3 @@
|
||||
-- Complain if script is sourced in psql, rather than via CREATE EXTENSION
|
||||
\echo Use "CREATE EXTENSION cdb_geocoder_admin0" to load this file. \quit
|
||||
|
||||
-- Response types for admin0 geocoder
|
||||
CREATE TYPE geocode_admin_v1 AS (q TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
CREATE TYPE synonym_lookup_v1 AS (q TEXT, adm0_a3 TEXT);
|
||||
|
||||
-- Public API functions --
|
||||
--- Geocoding function ---
|
||||
-- TODO: deal with permissions
|
54
geocoder/extension/sql/0.0.1/15_country_decoder_table.sql
Normal file
54
geocoder/extension/sql/0.0.1/15_country_decoder_table.sql
Normal file
@ -0,0 +1,54 @@
|
||||
CREATE TABLE country_decoder (
|
||||
name text,
|
||||
nativename text,
|
||||
tld text,
|
||||
iso2 text,
|
||||
ccn3 text,
|
||||
iso3 text,
|
||||
currency text,
|
||||
callingcode text,
|
||||
capital text,
|
||||
altspellings text,
|
||||
relevance text,
|
||||
region text,
|
||||
subregion text,
|
||||
language text,
|
||||
languagescodes text,
|
||||
translations text,
|
||||
population text,
|
||||
latlng text,
|
||||
demonym text,
|
||||
borders text,
|
||||
the_geom geometry(Geometry,4326),
|
||||
cartodb_id integer NOT NULL,
|
||||
created_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
updated_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
the_geom_webmercator geometry(Geometry,3857),
|
||||
synbu text[],
|
||||
synonyms text[],
|
||||
users double precision
|
||||
);
|
||||
|
||||
|
||||
CREATE SEQUENCE countries_cartodb_id_seq
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
ALTER SEQUENCE countries_cartodb_id_seq OWNED BY country_decoder.cartodb_id;
|
||||
ALTER TABLE ONLY country_decoder ALTER COLUMN cartodb_id SET DEFAULT nextval('countries_cartodb_id_seq'::regclass);
|
||||
|
||||
ALTER TABLE ONLY country_decoder
|
||||
ADD CONSTRAINT country_decoder_cartodb_id_key UNIQUE (cartodb_id);
|
||||
ALTER TABLE ONLY country_decoder
|
||||
ADD CONSTRAINT country_decoder_pkey PRIMARY KEY (cartodb_id);
|
||||
ALTER TABLE country_decoder CLUSTER ON country_decoder_pkey;
|
||||
|
||||
|
||||
CREATE INDEX country_decoder_the_geom_idx ON country_decoder USING gist (the_geom);
|
||||
CREATE INDEX country_decoder_the_geom_webmercator_idx ON country_decoder USING gist (the_geom_webmercator);
|
||||
|
||||
CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON country_decoder FOR EACH STATEMENT EXECUTE PROCEDURE cartodb.cdb_tablemetadata_trigger();
|
||||
CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON country_decoder FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_the_geom_webmercator();
|
||||
CREATE TRIGGER update_updated_at_trigger BEFORE UPDATE ON country_decoder FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_updated_at();
|
197
geocoder/extension/sql/0.0.1/20_admin1.sql
Normal file
197
geocoder/extension/sql/0.0.1/20_admin1.sql
Normal file
@ -0,0 +1,197 @@
|
||||
-- Public API functions --
|
||||
--- Geocoding function ---
|
||||
-- TODO: deal with permissions
|
||||
CREATE OR REPLACE FUNCTION geocode_admin1_polygons(name text[]) RETURNS SETOF geocode_admin_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_admin_v1%rowtype;
|
||||
BEGIN
|
||||
FOR ret IN
|
||||
SELECT
|
||||
q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
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(unnest(name)),'.',' ')) c, unnest(name) q) d
|
||||
) v
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION geocode_admin1_polygons(name text[], inputcountry text) RETURNS SETOF geocode_admin_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_admin_v1%rowtype;
|
||||
BEGIN
|
||||
|
||||
FOR ret IN WITH
|
||||
p AS (SELECT r.c, r.q, (SELECT iso3 FROM country_decoder WHERE lower(inputcountry) = ANY (synonyms)) i FROM (SELECT trim(replace(lower(unnest(name)),'.',' ')) c, unnest(name) q) r)
|
||||
SELECT
|
||||
q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
FROM (
|
||||
SELECT
|
||||
q, (
|
||||
SELECT the_geom
|
||||
FROM global_province_polygons
|
||||
WHERE p.c = ANY (synonyms)
|
||||
AND iso3 = p.i
|
||||
-- To calculate frequency, I simply counted the number of users
|
||||
-- we had signed up in each country. Countries with more users,
|
||||
-- we favor higher in the geocoder :)
|
||||
ORDER BY frequency DESC LIMIT 1
|
||||
) geom
|
||||
FROM p) n
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION geocode_admin1_polygons(names text[], country text[]) RETURNS SETOF geocode_admin_country_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_admin_country_v1%rowtype;
|
||||
nans TEXT[];
|
||||
BEGIN
|
||||
|
||||
|
||||
SELECT array_agg(p) INTO nans FROM (SELECT unnest(names) p, unnest(country) c) g WHERE c IS NULL;
|
||||
|
||||
IF 0 < array_length(nans, 1) THEN
|
||||
SELECT array_agg(p), array_agg(c) INTO names, country FROM (SELECT unnest(names) p, unnest(country) c) g WHERE c IS NOT NULL;
|
||||
FOR ret IN SELECT g.q, NULL as c, g.geom, g.success FROM (SELECT (geocode_admin1_polygons(nans)).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
|
||||
FOR ret IN WITH
|
||||
p AS (SELECT r.p, r.q, c, (SELECT iso3 FROM country_decoder WHERE lower(r.c) = ANY (synonyms)) i FROM (SELECT trim(replace(lower(unnest(names)),'.',' ')) p, unnest(names) q, unnest(country) c) r)
|
||||
SELECT
|
||||
q, c, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
FROM (
|
||||
SELECT
|
||||
q, c, (
|
||||
SELECT the_geom
|
||||
FROM global_province_polygons
|
||||
WHERE p.p = ANY (synonyms)
|
||||
AND iso3 = p.i
|
||||
-- To calculate frequency, I simply counted the number of users
|
||||
-- we had signed up in each country. Countries with more users,
|
||||
-- we favor higher in the geocoder :)
|
||||
ORDER BY frequency DESC LIMIT 1
|
||||
) geom
|
||||
FROM p) n
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
|
||||
-- Support tables
|
||||
|
||||
CREATE TABLE global_province_polygons (
|
||||
the_geom geometry(Geometry,4326),
|
||||
adm1_code text,
|
||||
objectid_1 integer,
|
||||
diss_me integer,
|
||||
adm1_cod_1 text,
|
||||
iso_3166_2 text,
|
||||
wikipedia text,
|
||||
iso_a2 text,
|
||||
adm0_sr integer,
|
||||
name text,
|
||||
name_alt text,
|
||||
name_local text,
|
||||
type text,
|
||||
type_en text,
|
||||
code_local text,
|
||||
code_hasc text,
|
||||
note text,
|
||||
hasc_maybe text,
|
||||
region text,
|
||||
region_cod text,
|
||||
provnum_ne integer,
|
||||
gadm_level integer,
|
||||
check_me integer,
|
||||
scalerank integer,
|
||||
datarank integer,
|
||||
abbrev text,
|
||||
postal text,
|
||||
area_sqkm double precision,
|
||||
sameascity integer,
|
||||
labelrank integer,
|
||||
featurecla text,
|
||||
name_len integer,
|
||||
mapcolor9 integer,
|
||||
mapcolor13 integer,
|
||||
fips text,
|
||||
fips_alt text,
|
||||
woe_id integer,
|
||||
woe_label text,
|
||||
woe_name text,
|
||||
latitude double precision,
|
||||
longitude double precision,
|
||||
sov_a3 text,
|
||||
iso3 text,
|
||||
adm0_label integer,
|
||||
admin text,
|
||||
geonunit text,
|
||||
gu_a3 text,
|
||||
gn_id integer,
|
||||
gn_name text,
|
||||
gns_id integer,
|
||||
gns_name text,
|
||||
gn_level integer,
|
||||
gn_region text,
|
||||
gn_a1_code text,
|
||||
region_sub text,
|
||||
sub_code text,
|
||||
gns_level integer,
|
||||
gns_lang text,
|
||||
gns_adm1 text,
|
||||
gns_region text,
|
||||
cartodb_id integer NOT NULL,
|
||||
created_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
updated_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
the_geom_webmercator geometry(Geometry,3857),
|
||||
synonyms text[],
|
||||
frequency double precision
|
||||
);
|
||||
|
||||
CREATE SEQUENCE ne_10m_admin_1_states_provinces_cartodb_id_seq
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
ALTER SEQUENCE ne_10m_admin_1_states_provinces_cartodb_id_seq OWNED BY global_province_polygons.cartodb_id;
|
||||
ALTER TABLE ONLY global_province_polygons ALTER COLUMN cartodb_id SET DEFAULT nextval('ne_10m_admin_1_states_provinces_cartodb_id_seq'::regclass);
|
||||
ALTER TABLE ONLY global_province_polygons
|
||||
ADD CONSTRAINT global_province_polygons_cartodb_id_key UNIQUE (cartodb_id);
|
||||
ALTER TABLE ONLY global_province_polygons
|
||||
ADD CONSTRAINT global_province_polygons_pkey PRIMARY KEY (cartodb_id);
|
||||
|
||||
CREATE INDEX global_province_polygons_the_geom_idx ON global_province_polygons USING gist (the_geom);
|
||||
CREATE INDEX global_province_polygons_the_geom_webmercator_idx ON global_province_polygons USING gist (the_geom_webmercator);
|
||||
|
||||
CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON global_province_polygons FOR EACH STATEMENT EXECUTE PROCEDURE cartodb.cdb_tablemetadata_trigger();
|
||||
CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON global_province_polygons FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_the_geom_webmercator();
|
||||
CREATE TRIGGER update_updated_at_trigger BEFORE UPDATE ON global_province_polygons FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_updated_at();
|
74
geocoder/extension/sql/0.0.1/30_ipaddr.sql
Normal file
74
geocoder/extension/sql/0.0.1/30_ipaddr.sql
Normal file
@ -0,0 +1,74 @@
|
||||
-- Public API functions --
|
||||
--- Geocoding function ---
|
||||
-- TODO: deal with permissions
|
||||
|
||||
CREATE OR REPLACE FUNCTION geocode_ip(ip text[]) RETURNS SETOF geocode_ip_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_ip_v1%rowtype;
|
||||
n TEXT;
|
||||
new_ips INET[];
|
||||
old_ips TEXT[];
|
||||
BEGIN
|
||||
FOR n IN SELECT unnest(ip) LOOP
|
||||
BEGIN
|
||||
IF family(n::inet)=6 THEN
|
||||
new_ips := array_append(new_ips, n::inet);
|
||||
old_ips := array_append(old_ips, n);
|
||||
ELSE
|
||||
new_ips := array_append(new_ips, ('::ffff:'||n)::inet);
|
||||
old_ips := array_append(old_ips, n);
|
||||
END IF;
|
||||
EXCEPTION WHEN OTHERS THEN
|
||||
SELECT n AS q, NULL as geom, FALSE as success INTO ret;
|
||||
RETURN NEXT ret;
|
||||
END;
|
||||
END LOOP;
|
||||
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 NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
|
||||
-- Support tables
|
||||
|
||||
CREATE TABLE ip_address_locations (
|
||||
network_start_ip inet,
|
||||
the_geom geometry(Geometry,4326),
|
||||
cartodb_id integer NOT NULL,
|
||||
created_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
updated_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
the_geom_webmercator geometry(Geometry,3857)
|
||||
);
|
||||
|
||||
CREATE SEQUENCE geolite2_city_blocks_cartodb_id_seq
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
ALTER SEQUENCE geolite2_city_blocks_cartodb_id_seq OWNED BY ip_address_locations.cartodb_id;
|
||||
ALTER TABLE ONLY ip_address_locations ALTER COLUMN cartodb_id SET DEFAULT nextval('geolite2_city_blocks_cartodb_id_seq'::regclass);
|
||||
|
||||
|
||||
ALTER TABLE ONLY ip_address_locations
|
||||
ADD CONSTRAINT ip_address_locations_cartodb_id_key UNIQUE (cartodb_id);
|
||||
ALTER TABLE ONLY ip_address_locations
|
||||
ADD CONSTRAINT ip_address_locations_pkey PRIMARY KEY (cartodb_id);
|
||||
|
||||
|
||||
CREATE INDEX ip_address_locations_the_geom_idx ON ip_address_locations USING gist (the_geom);
|
||||
CREATE INDEX ip_address_locations_the_geom_webmercator_idx ON ip_address_locations USING gist (the_geom_webmercator);
|
||||
CREATE INDEX ip_address_locations_startip_idx ON ip_address_locations USING btree (network_start_ip);
|
||||
|
||||
CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON ip_address_locations FOR EACH STATEMENT EXECUTE PROCEDURE cartodb.cdb_tablemetadata_trigger();
|
||||
CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON ip_address_locations FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_the_geom_webmercator();
|
||||
CREATE TRIGGER update_updated_at_trigger BEFORE UPDATE ON ip_address_locations FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_updated_at();
|
||||
|
432
geocoder/extension/sql/0.0.1/40_namedplaces.sql
Normal file
432
geocoder/extension/sql/0.0.1/40_namedplaces.sql
Normal file
@ -0,0 +1,432 @@
|
||||
-- Public API functions --
|
||||
--- Geocoding function ---
|
||||
-- TODO: deal with permissions
|
||||
|
||||
CREATE OR REPLACE FUNCTION geocode_namedplace(places text[], country text[]) RETURNS SETOF geocode_namedplace_country_v1
|
||||
LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_namedplace_country_v1%rowtype;
|
||||
nans TEXT[];
|
||||
BEGIN
|
||||
|
||||
SELECT array_agg(p) INTO nans FROM (SELECT unnest(places) p, unnest(country) c) g WHERE c IS NULL;
|
||||
|
||||
IF 0 < array_length(nans, 1) THEN
|
||||
SELECT array_agg(p), array_agg(c) INTO places, country FROM (SELECT unnest(places) p, unnest(country) c) g WHERE c IS NOT NULL;
|
||||
FOR ret IN SELECT g.q, NULL as c, g.geom, g.success FROM (SELECT (geocode_namedplace(nans)).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
SELECT array_agg(p) INTO nans FROM (SELECT unnest(places) p, unnest(country) c) g WHERE c='';
|
||||
IF 0 < array_length(nans, 1) THEN
|
||||
SELECT array_agg(p), array_agg(c) INTO places, country FROM (SELECT unnest(places) p, unnest(country) c) g WHERE c!='';
|
||||
FOR ret IN SELECT g.q, '' as c, g.geom, g.success FROM (SELECT (geocode_namedplace(nans)).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
FOR ret IN WITH
|
||||
p AS (SELECT r.s, r.c, (SELECT iso2 FROM country_decoder WHERE lower(r.c) = ANY (synonyms)) i FROM (SELECT unnest(places) AS s, unnest(country)::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 q, c, geom, TRUE AS success FROM best WHERE geom IS NOT NULL
|
||||
UNION ALL
|
||||
SELECT q, c, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success FROM next
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION geocode_namedplace(places text[], inputcountry text) RETURNS SETOF geocode_admin_country_v1
|
||||
LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_admin_country_v1%rowtype;
|
||||
isoTwo TEXT := NULL;
|
||||
has_country BOOLEAN;
|
||||
BEGIN
|
||||
has_country := TRUE;
|
||||
-- find the iso2 code for the input country string, else NULL
|
||||
IF inputcountry IS NULL THEN
|
||||
has_country := FALSE;
|
||||
ELSIF inputcountry = '' THEN
|
||||
has_country := FALSE;
|
||||
END IF;
|
||||
|
||||
IF has_country THEN
|
||||
SELECT iso2 INTO isoTwo FROM country_decoder WHERE lower(inputcountry) = ANY (synonyms) LIMIT 1;
|
||||
FOR ret IN WITH
|
||||
best AS (SELECT p.s AS q, (SELECT gp.the_geom AS geom FROM global_cities_points_limited gp WHERE gp.lowername = lower(p.s) AND gp.iso2 = isoTwo ORDER BY population DESC LIMIT 1) AS geom FROM (SELECT unnest(places) 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 gp.iso2 = isoTwo AND ga.geoname_id = gp.geoname_id ORDER BY preferred DESC LIMIT 1) geom FROM (SELECT unnest(places) AS s) p WHERE p.s NOT IN (SELECT q FROM best WHERE geom IS NOT NULL))
|
||||
SELECT q, inputcountry c, geom, TRUE AS success FROM best WHERE geom IS NOT NULL
|
||||
UNION ALL
|
||||
SELECT q, inputcountry c, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success FROM next
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
-- no country included, or iso interpretation found
|
||||
ELSE
|
||||
FOR ret IN
|
||||
SELECT g.q as q, inputcountry as c, g.geom as geom, g.success as success FROM (SELECT (geocode_namedplace(places)).*) g
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION geocode_namedplace(places text[], admin1s text, inputcountry text) RETURNS SETOF geocode_admin1_country_v1
|
||||
LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_admin1_country_v1%rowtype;
|
||||
has_country BOOLEAN;
|
||||
has_admin1s BOOLEAN;
|
||||
admin1s_a TEXT[];
|
||||
BEGIN
|
||||
|
||||
has_country := TRUE;
|
||||
has_admin1s := TRUE;
|
||||
|
||||
IF inputcountry IS NULL THEN
|
||||
has_country := FALSE;
|
||||
ELSIF inputcountry = '' THEN
|
||||
has_country := FALSE;
|
||||
END IF;
|
||||
|
||||
IF admin1s IS NULL THEN
|
||||
has_admin1s := FALSE;
|
||||
ELSIF admin1s = '' THEN
|
||||
has_admin1s := FALSE;
|
||||
END IF;
|
||||
|
||||
-- no country value
|
||||
IF has_country IS FALSE THEN
|
||||
-- no country no admin1 value
|
||||
IF has_admin1s IS FALSE THEN
|
||||
FOR ret IN SELECT g.q, admin1s AS a1, inputcountry as c, g.geom, g.success FROM (SELECT (geocode_namedplace(places)).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
-- no country, has admin1 value
|
||||
ELSE
|
||||
FOR ret IN
|
||||
SELECT g.q, admin1s AS a1, inputcountry as c, g.geom, g.success FROM (
|
||||
SELECT (
|
||||
geocode_namedplace(
|
||||
places,
|
||||
(SELECT array_agg(a) FROM (SELECT admin1s a FROM GENERATE_SERIES(1, Array_Length(places, 1)) s) r),
|
||||
NULL
|
||||
)
|
||||
).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
-- has country value
|
||||
ELSE
|
||||
-- has country, no admin1 value
|
||||
IF has_admin1s IS FALSE THEN
|
||||
FOR ret IN SELECT g.q, admin1s AS a1, inputcountry as c, g.geom, g.success FROM (SELECT (geocode_namedplace(places, inputcountry)).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
-- has country, has admin1 value
|
||||
ELSE
|
||||
FOR ret IN
|
||||
SELECT g.q, admin1s AS a1, inputcountry as c, g.geom, g.success FROM (
|
||||
SELECT (
|
||||
geocode_namedplace(
|
||||
places,
|
||||
(SELECT array_agg(a) FROM (SELECT admin1s a FROM GENERATE_SERIES(1, Array_Length(places, 1)) s) r),
|
||||
inputcountry
|
||||
)
|
||||
).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
END IF;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION geocode_namedplace(places text[], admin1s text[], inputcountry text) RETURNS SETOF geocode_admin1_country_v1
|
||||
LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_admin1_country_v1%rowtype;
|
||||
nans TEXT[];
|
||||
isoTwo TEXT := NULL;
|
||||
has_country BOOLEAN;
|
||||
BEGIN
|
||||
has_country := TRUE;
|
||||
-- find the iso2 code for the input country string, else NULL
|
||||
IF inputcountry IS NULL THEN
|
||||
has_country := FALSE;
|
||||
ELSIF inputcountry = '' THEN
|
||||
has_country := FALSE;
|
||||
END IF;
|
||||
IF has_country THEN
|
||||
SELECT iso2 INTO isoTwo FROM country_decoder WHERE lower(inputcountry) = ANY (synonyms) LIMIT 1;
|
||||
END IF;
|
||||
|
||||
-- find all cases where admin1 is NULL
|
||||
SELECT array_agg(p) INTO nans FROM (SELECT unnest(places) p, unnest(admin1s) c) g WHERE c IS NULL;
|
||||
|
||||
IF 0 < array_length(nans, 1) THEN
|
||||
SELECT array_agg(p), array_agg(c) INTO places, admin1s FROM (SELECT unnest(places) p, unnest(admin1s) c) g WHERE c IS NOT NULL;
|
||||
IF has_country THEN
|
||||
-- geocode our named place without admin1 but with our iso2
|
||||
FOR ret IN SELECT g.q, null AS a1, inputcountry as c, g.geom, g.success FROM (SELECT (geocode_namedplace(nans, inputcountry)).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
ELSE
|
||||
-- geocode our named place without admin1 and without iso2
|
||||
FOR ret IN SELECT g.q, NULL as a1, inputcountry as c, g.geom, g.success FROM (SELECT (geocode_namedplace(nans)).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- find all cases where admin1 is and empty string
|
||||
SELECT array_agg(p) INTO nans FROM (SELECT unnest(places) p, unnest(admin1s) c) g WHERE c='';
|
||||
|
||||
IF 0 < array_length(nans, 1) THEN
|
||||
SELECT array_agg(p), array_agg(c) INTO places, admin1s FROM (SELECT unnest(places) p, unnest(admin1s) c) g WHERE c!='';
|
||||
IF has_country THEN
|
||||
-- geocode our named place without admin1 but with our iso2
|
||||
FOR ret IN
|
||||
SELECT g.q, '' AS a1, inputcountry as c, g.geom, g.success FROM (SELECT (geocode_namedplace(nans, inputcountry)).*) g
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
ELSE
|
||||
-- geocode our named place without admin1 and without iso2
|
||||
FOR ret IN
|
||||
SELECT g.q, '' AS a1, inputcountry as c, g.geom, g.success FROM (SELECT (geocode_namedplace(nans)).*) g
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- geocode all the cases where admin1 is available
|
||||
IF has_country THEN
|
||||
FOR ret IN WITH
|
||||
-- return c=iso2 and search without country
|
||||
p AS (
|
||||
SELECT r.s, r.a1, (SELECT admin1 FROM admin1_decoder WHERE lower(r.a1) = ANY (synonyms) AND admin1_decoder.iso2 = isoTwo LIMIT 1) i FROM (SELECT unnest(places) AS s, unnest(admin1s)::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 q, a1, inputcountry as c, geom, TRUE AS success FROM best WHERE geom IS NOT NULL
|
||||
UNION ALL
|
||||
SELECT q, a1, inputcountry as c, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success FROM next
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
ELSE
|
||||
-- return c=NULL and search without country
|
||||
FOR ret IN WITH
|
||||
p AS (
|
||||
SELECT r.s, r.a1, (SELECT admin1 FROM admin1_decoder WHERE lower(r.a1) = ANY (synonyms) LIMIT 1) i FROM (SELECT unnest(places) AS s, unnest(admin1s)::text AS a1) r WHERE a1 IS NOT NULL and a1 != ''),
|
||||
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 q, a1, inputcountry as c, geom, TRUE AS success FROM best WHERE geom IS NOT NULL
|
||||
UNION ALL
|
||||
SELECT q, a1, inputcountry as c, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success FROM next
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION geocode_namedplace(places text[], admin1s text[], inputcountry text[]) RETURNS SETOF geocode_admin1_country_v1
|
||||
LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_admin1_country_v1%rowtype;
|
||||
BEGIN
|
||||
IF admin1s IS NULL THEN
|
||||
FOR ret IN SELECT g.q as q, NULL as a1, g.c as c, g.geom as geom, g.success as success FROM (SELECT (geocode_namedplace(places, inputcountry)).*) g LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
ELSE
|
||||
FOR ret IN WITH clean AS (SELECT array_agg(p) p, array_agg(a) a, c FROM (SELECT p, a, c FROM (SELECT unnest(places) p, unnest(admin1s) a, unnest(inputcountry) c) z GROUP BY p, a, c) y GROUP BY c)
|
||||
SELECT (geocode_namedplace(p, a, c)).* FROM clean LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
END IF;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION geocode_namedplace(places text[]) RETURNS SETOF geocode_namedplace_v1
|
||||
LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_namedplace_v1%rowtype;
|
||||
BEGIN
|
||||
FOR ret IN 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 unnest(places) 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 unnest(places) 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
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
|
||||
-- Support tables
|
||||
|
||||
CREATE TABLE admin1_decoder (
|
||||
name text,
|
||||
admin1 text,
|
||||
iso2 text,
|
||||
geoname_id integer,
|
||||
cartodb_id integer NOT NULL,
|
||||
created_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
updated_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
the_geom geometry(Geometry,4326),
|
||||
the_geom_webmercator geometry(Geometry,3857),
|
||||
synonyms text[],
|
||||
iso3 text,
|
||||
users double precision
|
||||
);
|
||||
|
||||
|
||||
CREATE SEQUENCE admin1_decoder_cartodb_id_seq
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
ALTER SEQUENCE admin1_decoder_cartodb_id_seq OWNED BY admin1_decoder.cartodb_id;
|
||||
ALTER TABLE ONLY admin1_decoder ALTER COLUMN cartodb_id SET DEFAULT nextval('admin1_decoder_cartodb_id_seq'::regclass);
|
||||
|
||||
|
||||
ALTER TABLE ONLY admin1_decoder
|
||||
ADD CONSTRAINT admin1_decoder_cartodb_id_key UNIQUE (cartodb_id);
|
||||
ALTER TABLE ONLY admin1_decoder
|
||||
ADD CONSTRAINT admin1_decoder_pkey PRIMARY KEY (cartodb_id);
|
||||
|
||||
|
||||
CREATE INDEX admin1_decoder_the_geom_idx ON admin1_decoder USING gist (the_geom);
|
||||
CREATE INDEX admin1_decoder_admin1_idx ON admin1_decoder USING btree (admin1);
|
||||
CREATE INDEX admin1_decoder_geoname_id_idx ON admin1_decoder USING btree (geoname_id);
|
||||
CREATE INDEX admin1_decoder_iso2_idx ON admin1_decoder USING btree (iso2);
|
||||
CREATE INDEX admin1_decoder_iso3_idx ON admin1_decoder USING btree (iso3);
|
||||
CREATE INDEX admin1_decoder_name_idx ON admin1_decoder USING btree (name);
|
||||
|
||||
|
||||
CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON admin1_decoder FOR EACH STATEMENT EXECUTE PROCEDURE cartodb.cdb_tablemetadata_trigger();
|
||||
CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON admin1_decoder FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_the_geom_webmercator();
|
||||
CREATE TRIGGER update_updated_at_trigger BEFORE UPDATE ON admin1_decoder FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_updated_at();
|
||||
|
||||
|
||||
CREATE TABLE global_cities_points_limited (
|
||||
geoname_id integer,
|
||||
name text,
|
||||
asciiname text,
|
||||
altnames text,
|
||||
featclass text,
|
||||
featcode text,
|
||||
iso2 text,
|
||||
cc2 text,
|
||||
admin1 text,
|
||||
admin2 text,
|
||||
admin3 text,
|
||||
admin4 text,
|
||||
population double precision,
|
||||
gtopo30 integer,
|
||||
the_geom geometry(Point,4326),
|
||||
created_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
updated_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
the_geom_webmercator geometry(Geometry,3857),
|
||||
cartodb_id integer NOT NULL,
|
||||
lowername text
|
||||
);
|
||||
|
||||
|
||||
CREATE SEQUENCE points_cities_le_cartodb_id_seq
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
ALTER SEQUENCE points_cities_le_cartodb_id_seq OWNED BY global_cities_points_limited.cartodb_id;
|
||||
ALTER TABLE ONLY global_cities_points_limited ALTER COLUMN cartodb_id SET DEFAULT nextval('points_cities_le_cartodb_id_seq'::regclass);
|
||||
|
||||
ALTER TABLE ONLY global_cities_points_limited
|
||||
ADD CONSTRAINT global_cities_points_limited_cartodb_id_key UNIQUE (cartodb_id);
|
||||
ALTER TABLE ONLY global_cities_points_limited
|
||||
ADD CONSTRAINT global_cities_points_limited_pkey PRIMARY KEY (cartodb_id);
|
||||
|
||||
|
||||
CREATE INDEX global_cities_points_limited_the_geom_idx ON global_cities_points_limited USING gist (the_geom);
|
||||
CREATE INDEX global_cities_points_limited_the_geom_webmercator_idx ON global_cities_points_limited USING gist (the_geom_webmercator);
|
||||
CREATE INDEX global_cities_points_limited_lower_iso2_idx ON global_cities_points_limited USING btree (lowername, iso2);
|
||||
CREATE INDEX global_cities_points_limited_admin1_idx ON global_cities_points_limited USING btree (admin1);
|
||||
CREATE INDEX global_cities_points_limited_geoname_id_idx ON global_cities_points_limited USING btree (geoname_id);
|
||||
|
||||
|
||||
CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON global_cities_points_limited FOR EACH STATEMENT EXECUTE PROCEDURE cartodb.cdb_tablemetadata_trigger();
|
||||
CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON global_cities_points_limited FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_the_geom_webmercator();
|
||||
CREATE TRIGGER update_updated_at_trigger BEFORE UPDATE ON global_cities_points_limited FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_updated_at();
|
||||
|
||||
|
||||
CREATE TABLE global_cities_alternates_limited (
|
||||
geoname_id integer,
|
||||
name text,
|
||||
the_geom geometry(Geometry,4326),
|
||||
created_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
updated_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
the_geom_webmercator geometry(Geometry,3857),
|
||||
preferred boolean,
|
||||
lowername text,
|
||||
cartodb_id integer NOT NULL,
|
||||
admin1_geonameid integer,
|
||||
iso2 text,
|
||||
admin1 text
|
||||
);
|
||||
|
||||
|
||||
CREATE SEQUENCE global_cities_alternates_limited_cartodb_id_seq
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
ALTER SEQUENCE global_cities_alternates_limited_cartodb_id_seq OWNED BY global_cities_alternates_limited.cartodb_id;
|
||||
ALTER TABLE ONLY global_cities_alternates_limited ALTER COLUMN cartodb_id SET DEFAULT nextval('global_cities_alternates_limited_cartodb_id_seq'::regclass);
|
||||
|
||||
ALTER TABLE ONLY global_cities_alternates_limited
|
||||
ADD CONSTRAINT points_cities_alternates_limited_cartodb_id_key UNIQUE (cartodb_id);
|
||||
ALTER TABLE ONLY global_cities_alternates_limited
|
||||
ADD CONSTRAINT global_cities_alternates_limited_pkey PRIMARY KEY (cartodb_id);
|
||||
|
||||
|
||||
CREATE INDEX global_cities_alternates_limited_the_geom_idx ON global_cities_alternates_limited USING gist (the_geom);
|
||||
CREATE INDEX global_cities_alternates_limited_the_geom_webmercator_idx ON global_cities_alternates_limited USING gist (the_geom_webmercator);
|
||||
CREATE INDEX global_cities_alternates_limited_admin1_idx ON global_cities_alternates_limited USING btree (admin1);
|
||||
CREATE INDEX global_cities_alternates_limited_admin1_geonameid_idx ON global_cities_alternates_limited USING btree (admin1_geonameid);
|
||||
CREATE INDEX global_cities_alternates_limited_lowername_idx ON global_cities_alternates_limited USING btree (lowername);
|
||||
|
||||
|
||||
CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON global_cities_alternates_limited FOR EACH STATEMENT EXECUTE PROCEDURE cartodb.cdb_tablemetadata_trigger();
|
||||
CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON global_cities_alternates_limited FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_the_geom_webmercator();
|
||||
CREATE TRIGGER update_updated_at_trigger BEFORE UPDATE ON global_cities_alternates_limited FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_updated_at();
|
||||
|
402
geocoder/extension/sql/0.0.1/50_postalcodes.sql
Normal file
402
geocoder/extension/sql/0.0.1/50_postalcodes.sql
Normal file
@ -0,0 +1,402 @@
|
||||
-- Public API functions --
|
||||
--- Geocoding function ---
|
||||
-- TODO: deal with permissions
|
||||
|
||||
CREATE FUNCTION geocode_postalcode_polygons(code text[], inputcountries text[]) RETURNS SETOF geocode_namedplace_country_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_namedplace_country_v1%rowtype;
|
||||
adm text[];
|
||||
BEGIN
|
||||
|
||||
SELECT INTO adm array_agg((SELECT adm0_a3 FROM admin0_synonyms WHERE name_ = lower(regexp_replace(b.c, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text LIMIT 1)) FROM (SELECT UNNEST(inputcountries) c) b;
|
||||
|
||||
FOR ret IN
|
||||
SELECT
|
||||
q, c, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
FROM (
|
||||
SELECT
|
||||
q, c, (
|
||||
SELECT the_geom
|
||||
FROM global_postal_code_polygons
|
||||
WHERE postal_code = CASE WHEN a = 'CAN' THEN substring(upper(d.q) from 1 for 3) ELSE upper(d.q) END
|
||||
AND iso3 = a
|
||||
) geom
|
||||
FROM (SELECT unnest(code) q, unnest(inputcountries) c, unnest(adm) a) d
|
||||
) v
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
-- TODO: The next function works with an incorrect table
|
||||
|
||||
CREATE FUNCTION geocode_postalcode_polygons(code text[], inputcountry text) RETURNS SETOF geocode_namedplace_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_namedplace_v1%rowtype;
|
||||
BEGIN
|
||||
FOR ret IN
|
||||
SELECT
|
||||
q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
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(inputcountry) = ANY (synonyms) LIMIT 1
|
||||
)
|
||||
) geom
|
||||
FROM (SELECT unnest(code) q) d
|
||||
) v
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
-- TODO: The next function works with an incorrect table
|
||||
|
||||
CREATE FUNCTION geocode_postalcode_polygons(code text[]) RETURNS SETOF geocode_namedplace_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_namedplace_v1%rowtype;
|
||||
BEGIN
|
||||
FOR ret IN
|
||||
SELECT
|
||||
q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
FROM (
|
||||
SELECT
|
||||
q, (
|
||||
SELECT the_geom
|
||||
FROM global_postal_code_polygons
|
||||
WHERE postal_code = upper(d.q)
|
||||
LIMIT 1
|
||||
) geom
|
||||
FROM (SELECT unnest(code) q) d
|
||||
) v
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
------ POINTS ------
|
||||
|
||||
|
||||
CREATE FUNCTION geocode_postalcode_points(code text[], inputcountry text) RETURNS SETOF geocode_namedplace_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_namedplace_v1%rowtype;
|
||||
BEGIN
|
||||
FOR ret IN
|
||||
SELECT
|
||||
q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
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(inputcountry) = ANY (synonyms) LIMIT 1
|
||||
)
|
||||
LIMIT 1
|
||||
) geom
|
||||
FROM (SELECT unnest(code) q) d
|
||||
) v
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
|
||||
CREATE FUNCTION geocode_postalcode_points(code integer[], inputcountries text[]) RETURNS SETOF geocode_postalint_country_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_postalint_country_v1%rowtype;
|
||||
BEGIN
|
||||
FOR ret IN
|
||||
SELECT
|
||||
q, c, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
FROM (
|
||||
SELECT
|
||||
q, c, (
|
||||
SELECT the_geom
|
||||
FROM global_postal_code_points
|
||||
WHERE postal_code_num = d.q
|
||||
AND iso3 = (
|
||||
SELECT iso3 FROM country_decoder WHERE
|
||||
lower(d.c) = ANY (synonyms) LIMIT 1
|
||||
)
|
||||
LIMIT 1
|
||||
) geom
|
||||
FROM (SELECT unnest(code) q, unnest(inputcountries) c) d
|
||||
) v
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
|
||||
CREATE FUNCTION geocode_postalcode_points(code text[]) RETURNS SETOF geocode_namedplace_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_namedplace_v1%rowtype;
|
||||
BEGIN
|
||||
FOR ret IN
|
||||
SELECT
|
||||
q, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
FROM (
|
||||
SELECT
|
||||
q, (
|
||||
SELECT the_geom
|
||||
FROM global_postal_code_points
|
||||
WHERE postal_code = upper(d.q)
|
||||
LIMIT 1
|
||||
) geom
|
||||
FROM (SELECT unnest(code) q) d
|
||||
) v
|
||||
LOOP
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
|
||||
CREATE FUNCTION geocode_postalcode_points(code text[], inputcountries text[]) RETURNS SETOF geocode_place_country_iso_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret geocode_place_country_iso_v1%rowtype;
|
||||
geo GEOMETRY;
|
||||
BEGIN
|
||||
|
||||
FOR ret IN
|
||||
SELECT
|
||||
q, c, iso3, geom, CASE WHEN geom IS NULL THEN FALSE ELSE TRUE END AS success
|
||||
FROM (
|
||||
SELECT
|
||||
q, c, (SELECT iso3 FROM country_decoder WHERE
|
||||
lower(d.c) = ANY (synonyms) LIMIT 1) iso3, (
|
||||
SELECT the_geom
|
||||
FROM global_postal_code_points
|
||||
WHERE postal_code = upper(d.q)
|
||||
AND iso3 = (
|
||||
SELECT iso3 FROM country_decoder WHERE
|
||||
lower(d.c) = ANY (synonyms) LIMIT 1
|
||||
)
|
||||
LIMIT 1
|
||||
) geom
|
||||
FROM (SELECT unnest(code) q, unnest(inputcountries) c) d
|
||||
) v
|
||||
LOOP
|
||||
IF ret.geom IS NULL AND ret.iso3 = 'GBR' THEN
|
||||
geo := geocode_greatbritain_outward(ret.q);
|
||||
IF geo IS NOT NULL THEN
|
||||
ret.geom := geo;
|
||||
ret.success := TRUE;
|
||||
END IF;
|
||||
END IF;
|
||||
RETURN NEXT ret;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
|
||||
CREATE FUNCTION geocode_greatbritain_outward(code text) RETURNS geometry
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
geom GEOMETRY;
|
||||
BEGIN
|
||||
code := trim(code);
|
||||
geom := NULL;
|
||||
IF array_length(string_to_array(code,' '),1) = 2 THEN
|
||||
code := split_part(code, ' ', 1) || ' ' || rpad(substring(split_part(code, ' ', 2), 1, 1), 3, '#');
|
||||
SELECT the_geom INTO geom FROM global_postal_code_points WHERE
|
||||
postal_code = code
|
||||
AND iso3 = 'GBR'
|
||||
LIMIT 1;
|
||||
END IF;
|
||||
RETURN geom;
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
CREATE FUNCTION admin0_available_services(name text[]) RETURNS SETOF available_services_v1
|
||||
LANGUAGE plpgsql SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ret available_services_v1%rowtype;
|
||||
BEGIN RETURN QUERY
|
||||
SELECT d.q, n.adm0_a3, n.postal_code_points, n.postal_code_polygons FROM
|
||||
(
|
||||
SELECT q, lower(regexp_replace(q, '[^a-zA-Z\u00C0-\u00ff]+', '', 'g'))::text x FROM
|
||||
(
|
||||
SELECT unnest(name) q
|
||||
)
|
||||
g) d LEFT OUTER JOIN admin0_synonyms s ON name_ = d.x LEFT OUTER JOIN available_services n ON s.adm0_a3 = n.adm0_a3 GROUP BY d.q, n.adm0_a3, n.postal_code_points, n.postal_code_polygons;
|
||||
END
|
||||
$$;
|
||||
--------------------------------------------------------------------------------
|
||||
|
||||
-- Support tables
|
||||
|
||||
CREATE TABLE global_postal_code_polygons (
|
||||
the_geom geometry(Geometry,4326),
|
||||
zcta5ce10 text,
|
||||
geoid10 text,
|
||||
mtfcc10 text,
|
||||
cartodb_id integer NOT NULL,
|
||||
created_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
updated_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
the_geom_webmercator geometry(Geometry,3857),
|
||||
iso3 text,
|
||||
postal_code text,
|
||||
postal_code_num integer
|
||||
);
|
||||
|
||||
|
||||
CREATE SEQUENCE tl_2013_us_zcta510_cartodb_id_seq
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
ALTER SEQUENCE tl_2013_us_zcta510_cartodb_id_seq OWNED BY global_postal_code_polygons.cartodb_id;
|
||||
ALTER TABLE ONLY global_postal_code_polygons ALTER COLUMN cartodb_id SET DEFAULT nextval('tl_2013_us_zcta510_cartodb_id_seq'::regclass);
|
||||
|
||||
|
||||
ALTER TABLE ONLY global_postal_code_polygons
|
||||
ADD CONSTRAINT global_postal_code_polygons_cartodb_id_key UNIQUE (cartodb_id);
|
||||
ALTER TABLE ONLY global_postal_code_polygons
|
||||
ADD CONSTRAINT global_postal_code_polygons_pkey PRIMARY KEY (cartodb_id);
|
||||
|
||||
|
||||
CREATE INDEX global_postal_code_polygons_the_geom_idx ON global_postal_code_polygons USING gist (the_geom);
|
||||
CREATE INDEX global_postal_code_polygons_the_geom_webmercator_idx ON global_postal_code_polygons USING gist (the_geom_webmercator);
|
||||
CREATE INDEX global_postal_code_polygons_postal_code_idx ON global_postal_code_polygons USING btree (postal_code);
|
||||
CREATE INDEX global_postal_code_polygons_iso3_idx ON global_postal_code_polygons USING btree (iso3);
|
||||
CREATE INDEX global_global_postal_code_polygons_postal_code_num_idx ON global_postal_code_polygons USING btree (postal_code_num);
|
||||
|
||||
|
||||
CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON global_postal_code_polygons FOR EACH STATEMENT EXECUTE PROCEDURE cartodb.cdb_tablemetadata_trigger();
|
||||
CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON global_postal_code_polygons FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_the_geom_webmercator();
|
||||
CREATE TRIGGER update_updated_at_trigger BEFORE UPDATE ON global_postal_code_polygons FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_updated_at();
|
||||
|
||||
|
||||
CREATE TABLE global_postal_code_points (
|
||||
iso2 text,
|
||||
postal_code text,
|
||||
place_name text,
|
||||
admin_name1 text,
|
||||
admin_code1 text,
|
||||
admin_name2 text,
|
||||
admin_code2 text,
|
||||
admin_name3 text,
|
||||
admin_code3 text,
|
||||
accuracy text,
|
||||
the_geom geometry(Geometry,4326),
|
||||
cartodb_id integer NOT NULL,
|
||||
created_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
updated_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
the_geom_webmercator geometry(Geometry,3857),
|
||||
iso3 text,
|
||||
frompoly boolean,
|
||||
postal_code_num integer,
|
||||
datasource text
|
||||
);
|
||||
|
||||
|
||||
CREATE SEQUENCE allcountries_cartodb_id_seq
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
ALTER SEQUENCE allcountries_cartodb_id_seq OWNED BY global_postal_code_points.cartodb_id;
|
||||
ALTER TABLE ONLY global_postal_code_points ALTER COLUMN cartodb_id SET DEFAULT nextval('allcountries_cartodb_id_seq'::regclass);
|
||||
|
||||
|
||||
ALTER TABLE ONLY global_postal_code_points
|
||||
ADD CONSTRAINT global_postal_code_points_cartodb_id_key UNIQUE (cartodb_id);
|
||||
ALTER TABLE ONLY global_postal_code_points
|
||||
ADD CONSTRAINT global_postal_code_points_pkey PRIMARY KEY (cartodb_id);
|
||||
|
||||
|
||||
CREATE INDEX global_postal_code_points_the_geom_idx ON global_postal_code_points USING gist (the_geom);
|
||||
CREATE INDEX global_postal_code_points_the_geom_webmercator_idx ON global_postal_code_points USING gist (the_geom_webmercator);
|
||||
CREATE INDEX global_postal_code_points_postal_code_idx ON global_postal_code_points USING btree (postal_code);
|
||||
CREATE INDEX global_postal_code_points_iso3_idx ON global_postal_code_points USING btree (iso3);
|
||||
CREATE INDEX global_postal_code_points_postal_code_num_idx ON global_postal_code_points USING btree (postal_code_num);
|
||||
|
||||
|
||||
CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON global_postal_code_points FOR EACH STATEMENT EXECUTE PROCEDURE cartodb.cdb_tablemetadata_trigger();
|
||||
CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON global_postal_code_points FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_the_geom_webmercator();
|
||||
CREATE TRIGGER update_updated_at_trigger BEFORE UPDATE ON global_postal_code_points FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_updated_at();
|
||||
|
||||
|
||||
|
||||
CREATE TABLE available_services (
|
||||
adm0_a3 text,
|
||||
admin0 boolean,
|
||||
cartodb_id integer NOT NULL,
|
||||
created_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
updated_at timestamp with time zone DEFAULT now() NOT NULL,
|
||||
the_geom geometry(Geometry,4326),
|
||||
the_geom_webmercator geometry(Geometry,3857),
|
||||
postal_code_points boolean,
|
||||
postal_code_polygons boolean
|
||||
);
|
||||
|
||||
CREATE SEQUENCE available_services_cartodb_id_seq
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
|
||||
ALTER SEQUENCE available_services_cartodb_id_seq OWNED BY available_services.cartodb_id;
|
||||
ALTER TABLE ONLY available_services ALTER COLUMN cartodb_id SET DEFAULT nextval('available_services_cartodb_id_seq'::regclass);
|
||||
|
||||
|
||||
ALTER TABLE ONLY available_services
|
||||
ADD CONSTRAINT available_services_cartodb_id_key UNIQUE (cartodb_id);
|
||||
ALTER TABLE ONLY available_services
|
||||
ADD CONSTRAINT available_services_pkey PRIMARY KEY (cartodb_id);
|
||||
|
||||
|
||||
|
||||
CREATE INDEX available_services_the_geom_idx ON available_services USING gist (the_geom);
|
||||
CREATE INDEX available_services_the_geom_webmercator_idx ON available_services USING gist (the_geom_webmercator);
|
||||
|
||||
|
||||
CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON available_services FOR EACH STATEMENT EXECUTE PROCEDURE cartodb.cdb_tablemetadata_trigger();
|
||||
CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON available_services FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_the_geom_webmercator();
|
||||
CREATE TRIGGER update_updated_at_trigger BEFORE UPDATE ON available_services FOR EACH ROW EXECUTE PROCEDURE cartodb._cdb_update_updated_at();
|
16
geocoder/extension/sql/00_install_test.sql
Normal file
16
geocoder/extension/sql/00_install_test.sql
Normal file
@ -0,0 +1,16 @@
|
||||
-- Install dependencies
|
||||
CREATE EXTENSION postgis;
|
||||
CREATE EXTENSION schema_triggers;
|
||||
CREATE EXTENSION plpythonu;
|
||||
CREATE EXTENSION cartodb;
|
||||
|
||||
-- Install the extension
|
||||
CREATE EXTENSION cdb_geocoder;
|
||||
|
||||
-- Mock the varnish invalidation function
|
||||
CREATE OR REPLACE FUNCTION public.cdb_invalidate_varnish(table_name text) RETURNS void AS $$
|
||||
BEGIN
|
||||
RETURN;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
@ -1,23 +1,9 @@
|
||||
CREATE EXTENSION postgis;
|
||||
CREATE EXTENSION schema_triggers;
|
||||
CREATE EXTENSION plpythonu;
|
||||
CREATE EXTENSION cartodb;
|
||||
CREATE EXTENSION cdb_geocoder_admin0;
|
||||
|
||||
-- Check that the synonym function is callable, should return NULL
|
||||
SELECT (admin0_synonym_lookup(Array['United States', 'ESP'])).*;
|
||||
|
||||
-- Check that the geocoding function is callable, should return success = false
|
||||
SELECT (geocode_admin0_polygons(Array['Spain', 'USA', ''])).*;
|
||||
|
||||
-- Mock the varnish invalidation function
|
||||
CREATE OR REPLACE FUNCTION public.cdb_invalidate_varnish(table_name text) RETURNS void AS $$
|
||||
BEGIN
|
||||
RETURN;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
-- Add a few synonyms
|
||||
COPY admin0_synonyms (name, rank, created_at, updated_at, the_geom, the_geom_webmercator, cartodb_id, adm0_a3, name_) FROM stdin;
|
||||
United States 0 2014-09-30 10:13:28.383426+00 2014-09-30 10:13:28.383426+00 \N \N 29614 USA unitedstates
|
18
geocoder/extension/sql/20_admin1_test.sql
Normal file
18
geocoder/extension/sql/20_admin1_test.sql
Normal file
@ -0,0 +1,18 @@
|
||||
-- Check that the geocoding functions are callable, should return NULL
|
||||
SELECT (geocode_admin1_polygons(Array['TX','Cuidad Real', 'sevilla'])).*;
|
||||
SELECT (geocode_admin1_polygons(Array['NH', 'Vermont'], 'United States')).*;
|
||||
SELECT (geocode_admin1_polygons(Array['az', 'az'], Array['Ecuador', 'USA'])).*;
|
||||
|
||||
-- Add a few data to the sources
|
||||
INSERT INTO global_province_polygons (the_geom, synonyms, iso3) VALUES (
|
||||
'0106000020E610000001000000010300000001000000040000000000000000E000C01F383D7839B740400000000000E000C0AA3C0EDE220F3B4000000000004812404FB7FCCD04893D400000000000E000C01F383D7839B74040',
|
||||
Array['vipava','obcina vipava','vipava, obcina'],
|
||||
'SVN'
|
||||
);
|
||||
|
||||
-- Check that the synonym function is callable, should return true
|
||||
SELECT (geocode_admin1_polygons(Array['obcina vipava'])).success;
|
||||
|
||||
-- Check that it returns the mocked geometry above
|
||||
SELECT (geocode_admin1_polygons(Array['obcina vipava'])).geom;
|
||||
|
14
geocoder/extension/sql/30_ipaddr_test.sql
Normal file
14
geocoder/extension/sql/30_ipaddr_test.sql
Normal file
@ -0,0 +1,14 @@
|
||||
-- Check that the geocoding function is callable, should return success = false
|
||||
SELECT (geocode_ip(Array['100.0.24.0'])).*;
|
||||
|
||||
-- Add a few IP sources
|
||||
COPY ip_address_locations (network_start_ip, the_geom, cartodb_id, created_at, updated_at, the_geom_webmercator) FROM stdin;
|
||||
::ffff:2.235.35.0 0101000020E610000072F90FE9B7CF22405DFE43FAEDC34640 2821226 2014-08-25 10:35:51.665546+00 2014-08-25 10:35:51.665546+00 0101000020110F000010801778FBF32F4109868FF8BCC35541
|
||||
::ffff:31.7.187.0 \N 2783250 2014-08-25 10:35:51.665546+00 2014-08-25 10:35:51.665546+00 \N
|
||||
::ffff:64.110.146.0 \N 2783251 2014-08-25 10:35:51.665546+00 2014-08-25 10:35:51.665546+00 \N
|
||||
::ffff:72.5.198.0 \N 2783252 2014-08-25 10:35:51.665546+00 2014-08-25 10:35:51.665546+00 \N
|
||||
::ffff:77.73.184.0 \N 2783253 2014-08-25 10:35:51.665546+00 2014-08-25 10:35:51.665546+00 \N
|
||||
\.
|
||||
|
||||
-- Check that the geocoding function is callable, should return success = true
|
||||
SELECT (geocode_ip(Array['2.235.35.0'])).*;
|
20
geocoder/extension/sql/40_namedplaces_test.sql
Normal file
20
geocoder/extension/sql/40_namedplaces_test.sql
Normal file
@ -0,0 +1,20 @@
|
||||
-- Check that the different geocoding functions are callable, should return success = false
|
||||
SELECT (geocode_namedplace(Array['Madrid', 'New York City', 'sunapee'])).*;
|
||||
SELECT (geocode_namedplace(Array['Elche', 'Granada', 'Madrid'], 'Spain')).*;
|
||||
SELECT (geocode_namedplace(Array['sunapee', 'sunapeeee', 'New York City', 'Madrid'], Array['', 'US', 'United States', NULL])).*;
|
||||
SELECT (geocode_namedplace(Array['Portland', 'Portland', 'New York City'], Array['Maine', 'Oregon', NULL], 'USA')).*;
|
||||
SELECT (geocode_namedplace(Array['Portland'], 'Oregon', 'USA')).*;
|
||||
SELECT (geocode_namedplace(Array['Portland', 'Portland', 'New York City'], Array['Maine', 'Oregon', NULL], Array['USA'])).*;
|
||||
|
||||
-- Add a named place source
|
||||
COPY global_cities_alternates_limited (geoname_id, name, the_geom, created_at, updated_at, the_geom_webmercator, preferred, lowername, cartodb_id, admin1_geonameid, iso2, admin1) FROM stdin;
|
||||
3128760 barcelona \N 2014-02-11 18:23:18.115612+00 2014-02-25 16:41:15.278786+00 \N t barcelona 7530944 409419 \N 56
|
||||
\.
|
||||
|
||||
COPY global_cities_points_limited (geoname_id, name, asciiname, altnames, featclass, featcode, iso2, admin1, admin2, population, the_geom, created_at, updated_at, the_geom_webmercator, cartodb_id, lowername) FROM stdin;
|
||||
2421056 Barcelona Barcelona P PPLA ES B 185 0101000020E6100000CA15DEE522E653C0A4C2D842902B4540 2015-06-13 14:48:34.341372+00 2015-06-15 16:53:41.067784+00 0101000020110F00000643969A73E660C10FF27276F0E15341 8653176 barcelona
|
||||
\.
|
||||
|
||||
-- Check that the geocoding function is callable, should return success = true
|
||||
SELECT (geocode_namedplace(Array['Barcelona'])).*
|
||||
|
54
geocoder/extension/sql/50_postalcode_test.sql
Normal file
54
geocoder/extension/sql/50_postalcode_test.sql
Normal file
@ -0,0 +1,54 @@
|
||||
SELECT (geocode_postalcode_polygons(Array['03204'], Array['Spain'])).*;
|
||||
SELECT (geocode_postalcode_polygons(Array['03204'], 'ESP')).*;
|
||||
SELECT (geocode_postalcode_polygons(Array['03204'])).*;
|
||||
SELECT (geocode_postalcode_points(Array['03204'], 'Spain')).*;
|
||||
SELECT (geocode_postalcode_points('{03204}', 'Spain')).*;
|
||||
SELECT (geocode_postalcode_points(Array['03204'])).*;
|
||||
SELECT (geocode_postalcode_points(Array['03204'], Array['Spain'])).*;
|
||||
SELECT geocode_greatbritain_outward('YO1 721');
|
||||
SELECT (admin0_available_services(Array['Spain'])).*;
|
||||
|
||||
-- Insert mock source data
|
||||
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
|
||||
);
|
||||
|
||||
INSERT INTO admin0_synonyms (adm0_a3, name, name_, rank) VALUES (
|
||||
'ESP',
|
||||
'ESP',
|
||||
'esp',
|
||||
4
|
||||
);
|
||||
|
||||
-- Check that the geocoding function is callable, should return success = true
|
||||
SELECT (geocode_postalcode_polygons(Array['03204'], Array['Spain'])).geom;
|
||||
|
25
geocoder/geocoder_download_dumps
Executable file
25
geocoder/geocoder_download_dumps
Executable file
@ -0,0 +1,25 @@
|
||||
#!/bin/bash
|
||||
|
||||
TARGET_DIR=db_dumps
|
||||
BASE_URL=https://s3.amazonaws.com/data.cartodb.net/geocoding/dumps
|
||||
VERSION=0.0.1
|
||||
|
||||
DUMP_LIST="admin0_synonyms.sql
|
||||
available_services.sql
|
||||
country_decoder.sql
|
||||
admin1_decoder.sql
|
||||
global_cities_alternates_limited.sql
|
||||
global_cities_points_limited.sql
|
||||
global_postal_code_points.sql
|
||||
global_province_polygons.sql
|
||||
ip_address_locations.sql
|
||||
ne_admin0_v3.sql
|
||||
global_postal_code_polygons.sql"
|
||||
|
||||
mkdir -p $TARGET_DIR
|
||||
|
||||
for file in $DUMP_LIST; do
|
||||
url="${BASE_URL}/${VERSION}/$file"
|
||||
|
||||
wget --directory-prefix=$TARGET_DIR $url
|
||||
done
|
43
geocoder/geocoder_restore_dump
Executable file
43
geocoder/geocoder_restore_dump
Executable file
@ -0,0 +1,43 @@
|
||||
#!/bin/bash
|
||||
|
||||
function usage() {
|
||||
cat <<EOF
|
||||
|
||||
Usage:
|
||||
$(basename $0) DBUSER DBNAME *.sql
|
||||
|
||||
E.g:
|
||||
$(basename $0) development_cartodb_user_87ddf981-25c7-4538-9910-0eb4342f2483 cartodb_dev_user_87ddf981-25c7-4538-9910-0eb4342f2483_db dumps/*.sql
|
||||
|
||||
EOF
|
||||
}
|
||||
|
||||
|
||||
if [ "$#" -lt "3" ]; then
|
||||
usage
|
||||
exit 1
|
||||
fi
|
||||
|
||||
DBUSER=$1
|
||||
DBNAME=$2
|
||||
shift; shift;
|
||||
DUMP_FILES="$@"
|
||||
|
||||
echo
|
||||
echo "About to import the following files: ${DUMP_FILES}"
|
||||
for i in $DUMP_FILES; do
|
||||
echo
|
||||
echo "Importing ${i}..."
|
||||
psql \
|
||||
--username=${DBUSER} \
|
||||
--dbname=${DBNAME} \
|
||||
--set=ON_ERROR_STOP=on \
|
||||
--single-transaction \
|
||||
--file=${i} || exit 1
|
||||
echo "Done with ${i}."
|
||||
echo
|
||||
done
|
||||
|
||||
|
||||
echo
|
||||
echo "** Everything OK **"
|
@ -1,5 +0,0 @@
|
||||
-- Response types for postal codes geocoder
|
||||
CREATE TYPE geocode_namedplace_v1 AS (q TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
CREATE TYPE geocode_place_country_iso_v1 AS (q TEXT, c TEXT, iso3 TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
CREATE TYPE geocode_namedplace_country_v1 AS (q TEXT, c TEXT, geom GEOMETRY, success BOOLEAN);
|
||||
CREATE TYPE geocode_postalint_country_v1 AS (q INT, c TEXT, geom GEOMETRY, success BOOLEAN);
|
Loading…
Reference in New Issue
Block a user