1 drop table import_status;
2 CREATE TABLE import_status (
3 lastimportdate timestamp NOT NULL
5 GRANT SELECT ON import_status TO "www-data" ;
7 drop table import_osmosis_log;
8 CREATE TABLE import_osmosis_log (
16 --drop table IF EXISTS query_log;
17 CREATE TABLE query_log (
24 CREATE INDEX idx_query_log ON query_log USING BTREE (starttime);
25 GRANT INSERT ON query_log TO "www-data" ;
27 CREATE TABLE new_query_log (
39 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
40 GRANT INSERT ON new_query_log TO "www-data" ;
41 GRANT UPDATE ON new_query_log TO "www-data" ;
42 GRANT SELECT ON new_query_log TO "www-data" ;
44 create view vw_search_query_log as SELECT substr(query, 1, 50) AS query, starttime, endtime - starttime AS duration, substr(useragent, 1, 20) as
45 useragent, language, results, ipaddress FROM new_query_log WHERE type = 'search' ORDER BY starttime DESC;
47 --drop table IF EXISTS report_log;
48 CREATE TABLE report_log (
55 GRANT INSERT ON report_log TO "www-data" ;
57 drop table IF EXISTS word;
65 country_code varchar(2),
66 search_name_count INTEGER
68 SELECT AddGeometryColumn('word', 'location', 4326, 'GEOMETRY', 2);
69 CREATE INDEX idx_word_word_id on word USING BTREE (word_id);
70 CREATE INDEX idx_word_word_token on word USING BTREE (word_token);
71 CREATE INDEX idx_word_trigram ON word USING gin(word_trigram gin_trgm_ops);
72 GRANT SELECT ON word TO "www-data" ;
73 DROP SEQUENCE seq_word;
74 CREATE SEQUENCE seq_word start 1;
76 drop table IF EXISTS location_area CASCADE;
77 CREATE TABLE location_area (
78 partition varchar(10),
80 country_code VARCHAR(2),
82 rank_search INTEGER NOT NULL,
83 rank_address INTEGER NOT NULL,
86 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
87 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
89 CREATE TABLE location_area_large () INHERITS (location_area);
90 CREATE TABLE location_area_roadnear () INHERITS (location_area);
91 CREATE TABLE location_area_roadfar () INHERITS (location_area);
93 drop table IF EXISTS search_name;
94 CREATE TABLE search_name (
98 country_code varchar(2),
99 name_vector integer[],
100 nameaddress_vector integer[]
102 CREATE INDEX search_name_name_vector_idx ON search_name USING GIN (name_vector gin__int_ops);
103 CREATE INDEX searchnameplacesearch_search_nameaddress_vector_idx ON search_name USING GIN (nameaddress_vector gin__int_ops);
104 SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
105 CREATE INDEX idx_search_name_centroid ON search_name USING GIST (centroid);
106 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id);
108 drop table IF EXISTS place_addressline;
109 CREATE TABLE place_addressline (
111 address_place_id INTEGER,
115 cached_rank_address integer
117 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id);
118 CREATE INDEX idx_place_addressline_address_place_id on place_addressline USING BTREE (address_place_id);
120 drop table IF EXISTS place_boundingbox CASCADE;
121 CREATE TABLE place_boundingbox (
130 CREATE INDEX idx_place_boundingbox_place_id on place_boundingbox USING BTREE (place_id);
131 SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
132 CREATE INDEX idx_place_boundingbox_outline ON place_boundingbox USING GIST (outline);
133 GRANT SELECT on place_boundingbox to "www-data" ;
134 GRANT INSERT on place_boundingbox to "www-data" ;
136 drop table IF EXISTS reverse_cache;
137 CREATE TABLE reverse_cache (
138 latlonzoomid integer,
139 country_code varchar(2),
142 GRANT SELECT on reverse_cache to "www-data" ;
143 GRANT INSERT on reverse_cache to "www-data" ;
144 CREATE INDEX idx_reverse_cache_latlonzoomid ON reverse_cache USING BTREE (latlonzoomid);
147 CREATE TABLE country (
148 country_code varchar(2),
150 country_default_language_code varchar(2)
152 SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
153 insert into country select iso3166::varchar(2), 'name:en'->cntry_name, null,
154 ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
155 CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
156 CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
159 CREATE TABLE placex (
160 place_id INTEGER NOT NULL,
161 partition varchar(10),
172 country_code varchar(2),
174 street_place_id INTEGER,
175 rank_address INTEGER,
177 indexed_status INTEGER,
178 indexed_date TIMESTAMP,
179 geometry_sector INTEGER
181 SELECT AddGeometryColumn('placex', 'geometry', 4326, 'GEOMETRY', 2);
182 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id);
183 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id);
184 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search);
185 CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address);
186 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry);
188 --CREATE INDEX idx_placex_indexed ON placex USING BTREE (indexed);
190 CREATE INDEX idx_placex_pending ON placex USING BTREE (rank_search) where indexed_status > 0;
191 CREATE INDEX idx_placex_pendingsector ON placex USING BTREE (rank_search,geometry_sector) where indexed_status > 0;
193 --CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search) where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
195 CREATE INDEX idx_placex_street_place_id ON placex USING BTREE (street_place_id) where street_place_id IS NOT NULL;
196 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed_status > 0 and class='place' and type='houses';
198 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);
199 CLUSTER placex USING idx_placex_sector;
201 DROP SEQUENCE seq_place;
202 CREATE SEQUENCE seq_place start 1;
203 GRANT SELECT on placex to "www-data" ;
204 GRANT UPDATE ON placex to "www-data" ;
205 GRANT SELECT ON search_name to "www-data" ;
206 GRANT DELETE on search_name to "www-data" ;
207 GRANT INSERT on search_name to "www-data" ;
208 GRANT SELECT on place_addressline to "www-data" ;
209 GRANT INSERT ON place_addressline to "www-data" ;
210 GRANT DELETE on place_addressline to "www-data" ;
211 GRANT SELECT ON seq_word to "www-data" ;
212 GRANT UPDATE ON seq_word to "www-data" ;
213 GRANT INSERT ON word to "www-data" ;
214 GRANT SELECT ON planet_osm_ways to "www-data" ;
215 GRANT SELECT ON planet_osm_rels to "www-data" ;
216 GRANT SELECT on location_area to "www-data" ;
217 GRANT SELECT on country to "www-data" ;
219 -- insert creates the location tagbles, creates location indexes if indexed == true
220 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
221 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
223 -- update insert creates the location tables
224 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
225 FOR EACH ROW EXECUTE PROCEDURE placex_update();
227 -- diff update triggers
228 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
229 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
230 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
231 FOR EACH ROW EXECUTE PROCEDURE place_delete();
232 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
233 FOR EACH ROW EXECUTE PROCEDURE place_insert();
235 alter table placex add column geometry_sector INTEGER;
236 alter table placex add column indexed_status INTEGER;
237 alter table placex add column indexed_date TIMESTAMP;
239 update placex set geometry_sector = geometry_sector(geometry);
240 drop index idx_placex_pendingbylatlon;
241 drop index idx_placex_interpolation;
242 drop index idx_placex_sector;
243 CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search)
244 where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
245 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed = false and class='place' and type='houses';
246 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);