1 drop table import_npi_log;
2 CREATE TABLE import_npi_log (
11 drop table IF EXISTS word;
19 country_code varchar(2),
20 search_name_count INTEGER,
23 SELECT AddGeometryColumn('word', 'location', 4326, 'GEOMETRY', 2);
24 CREATE INDEX idx_word_word_id on word USING BTREE (word_id);
25 CREATE INDEX idx_word_word_token on word USING BTREE (word_token);
26 GRANT SELECT ON word TO "www-data" ;
27 DROP SEQUENCE seq_word;
28 CREATE SEQUENCE seq_word start 1;
30 drop table IF EXISTS location_property CASCADE;
31 CREATE TABLE location_property (
34 parent_place_id BIGINT,
38 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
40 CREATE TABLE location_property_aux () INHERITS (location_property);
41 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
42 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
43 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
45 CREATE TABLE location_property_tiger () INHERITS (location_property);
46 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id);
47 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id);
48 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber);
50 drop table IF EXISTS search_name_blank CASCADE;
51 CREATE TABLE search_name_blank (
56 country_code varchar(2),
57 name_vector integer[],
58 nameaddress_vector integer[]
60 SELECT AddGeometryColumn('search_name_blank', 'centroid', 4326, 'GEOMETRY', 2);
62 drop table IF EXISTS search_name;
63 CREATE TABLE search_name () INHERITS (search_name_blank);
64 CREATE INDEX search_name_name_vector_idx ON search_name USING GIN (name_vector gin__int_ops) WITH (fastupdate = off);
65 CREATE INDEX searchnameplacesearch_search_nameaddress_vector_idx ON search_name USING GIN (nameaddress_vector gin__int_ops) WITH (fastupdate = off);
66 CREATE INDEX idx_search_name_centroid ON search_name USING GIST (centroid);
67 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id);
69 drop table IF EXISTS place_addressline;
70 CREATE TABLE place_addressline (
72 address_place_id BIGINT,
76 cached_rank_address integer
78 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id);
79 CREATE INDEX idx_place_addressline_address_place_id on place_addressline USING BTREE (address_place_id);
81 drop table IF EXISTS place_boundingbox CASCADE;
82 CREATE TABLE place_boundingbox (
91 CREATE INDEX idx_place_boundingbox_place_id on place_boundingbox USING BTREE (place_id);
92 SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
93 CREATE INDEX idx_place_boundingbox_outline ON place_boundingbox USING GIST (outline);
94 GRANT SELECT on place_boundingbox to "www-data" ;
95 GRANT INSERT on place_boundingbox to "www-data" ;
98 CREATE TABLE country (
99 country_code varchar(2),
101 country_default_language_code varchar(2)
103 SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
104 insert into country select iso3166::varchar(2), 'name:en'->cntry_name, null,
105 ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
106 CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
107 CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
110 CREATE TABLE placex (
111 place_id BIGINT NOT NULL,
123 country_code varchar(2),
125 parent_place_id BIGINT,
126 linked_place_id BIGINT,
127 rank_address INTEGER,
130 indexed_status INTEGER,
131 indexed_date TIMESTAMP,
132 geometry_sector INTEGER
134 SELECT AddGeometryColumn('placex', 'geometry', 4326, 'GEOMETRY', 2);
135 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id);
136 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id);
137 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search);
138 CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address);
139 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry);
140 CREATE INDEX idx_placex_parent_place_id ON placex USING BTREE (parent_place_id) where parent_place_id IS NOT NULL;
142 DROP SEQUENCE seq_place;
143 CREATE SEQUENCE seq_place start 1;
144 GRANT SELECT on placex to "www-data" ;
145 GRANT UPDATE ON placex to "www-data" ;
146 GRANT SELECT ON search_name to "www-data" ;
147 GRANT DELETE on search_name to "www-data" ;
148 GRANT INSERT on search_name to "www-data" ;
149 GRANT SELECT on place_addressline to "www-data" ;
150 GRANT INSERT ON place_addressline to "www-data" ;
151 GRANT DELETE on place_addressline to "www-data" ;
152 GRANT SELECT ON seq_word to "www-data" ;
153 GRANT UPDATE ON seq_word to "www-data" ;
154 GRANT INSERT ON word to "www-data" ;
155 GRANT SELECT on country to "www-data" ;