1 drop table if exists import_status;
2 CREATE TABLE import_status (
3 lastimportdate timestamp NOT NULL,
7 GRANT SELECT ON import_status TO "{www-user}" ;
9 drop table if exists import_osmosis_log;
10 CREATE TABLE import_osmosis_log (
19 CREATE TABLE new_query_log (
32 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
33 GRANT INSERT ON new_query_log TO "{www-user}" ;
34 GRANT UPDATE ON new_query_log TO "{www-user}" ;
35 GRANT SELECT ON new_query_log TO "{www-user}" ;
37 GRANT SELECT ON TABLE country_name TO "{www-user}";
38 GRANT SELECT ON TABLE gb_postcode TO "{www-user}";
40 drop table IF EXISTS word;
47 country_code varchar(2),
48 search_name_count INTEGER,
51 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
52 GRANT SELECT ON word TO "{www-user}" ;
53 DROP SEQUENCE IF EXISTS seq_word;
54 CREATE SEQUENCE seq_word start 1;
56 drop table IF EXISTS location_area CASCADE;
57 CREATE TABLE location_area (
61 rank_search SMALLINT NOT NULL,
62 rank_address SMALLINT NOT NULL,
63 country_code VARCHAR(2),
66 centroid GEOMETRY(Point, 4326),
67 geometry GEOMETRY(Geometry, 4326)
70 CREATE TABLE location_area_large () INHERITS (location_area);
72 drop table IF EXISTS location_property CASCADE;
73 CREATE TABLE location_property (
75 parent_place_id BIGINT,
79 centroid GEOMETRY(Point, 4326)
82 CREATE TABLE location_property_aux () INHERITS (location_property);
83 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
84 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
85 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
86 GRANT SELECT ON location_property_aux TO "{www-user}";
88 CREATE TABLE location_property_tiger (
90 parent_place_id BIGINT,
95 interpolationtype TEXT,
97 GRANT SELECT ON location_property_tiger TO "{www-user}";
99 drop table if exists location_property_osmline;
100 CREATE TABLE location_property_osmline (
101 place_id BIGINT NOT NULL,
103 parent_place_id BIGINT,
104 geometry_sector INTEGER,
105 indexed_date TIMESTAMP,
109 indexed_status SMALLINT,
111 interpolationtype TEXT,
114 country_code VARCHAR(2)
116 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
117 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
118 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
119 GRANT SELECT ON location_property_osmline TO "{www-user}";
121 drop table IF EXISTS search_name;
122 CREATE TABLE search_name (
125 search_rank SMALLINT,
126 address_rank SMALLINT,
127 name_vector integer[],
128 nameaddress_vector integer[],
129 country_code varchar(2),
130 centroid GEOMETRY(Geometry, 4326)
132 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
134 drop table IF EXISTS place_addressline;
135 CREATE TABLE place_addressline (
137 address_place_id BIGINT,
139 cached_rank_address SMALLINT,
143 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
145 drop table if exists placex;
146 CREATE TABLE placex (
147 place_id BIGINT NOT NULL,
148 parent_place_id BIGINT,
149 linked_place_id BIGINT,
151 indexed_date TIMESTAMP,
152 geometry_sector INTEGER,
153 rank_address SMALLINT,
154 rank_search SMALLINT,
156 indexed_status SMALLINT,
157 LIKE place INCLUDING CONSTRAINTS,
158 wikipedia TEXT, -- calculated wikipedia article name (language:title)
159 country_code varchar(2),
162 centroid GEOMETRY(Geometry, 4326)
164 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
165 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
166 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index} WHERE linked_place_id IS NOT NULL;
167 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
168 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
169 CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name'),rank_search) {ts:address-index} WHERE osm_type='N' and rank_search < 26;
171 DROP SEQUENCE IF EXISTS seq_place;
172 CREATE SEQUENCE seq_place start 1;
173 GRANT SELECT on placex to "{www-user}" ;
174 GRANT SELECT ON search_name to "{www-user}" ;
175 GRANT SELECT on place_addressline to "{www-user}" ;
176 GRANT SELECT ON seq_word to "{www-user}" ;
177 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
178 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
179 GRANT SELECT on location_area to "{www-user}" ;
181 -- insert creates the location tables, creates location indexes if indexed == true
182 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
183 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
184 CREATE TRIGGER osmline_before_insert BEFORE INSERT ON location_property_osmline
185 FOR EACH ROW EXECUTE PROCEDURE osmline_insert();
187 -- update insert creates the location tables
188 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
189 FOR EACH ROW EXECUTE PROCEDURE placex_update();
190 CREATE TRIGGER osmline_before_update BEFORE UPDATE ON location_property_osmline
191 FOR EACH ROW EXECUTE PROCEDURE osmline_update();
193 -- diff update triggers
194 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
195 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
196 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
197 FOR EACH ROW EXECUTE PROCEDURE place_delete();
198 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
199 FOR EACH ROW EXECUTE PROCEDURE place_insert();
201 -- Table for synthetic postcodes.
202 DROP TABLE IF EXISTS location_postcode;
203 CREATE TABLE location_postcode (
205 parent_place_id BIGINT,
206 rank_search SMALLINT,
207 rank_address SMALLINT,
208 indexed_status SMALLINT,
209 indexed_date TIMESTAMP,
210 country_code varchar(2),
212 geometry GEOMETRY(Geometry, 4326)
214 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {ts:address-index};
215 GRANT SELECT ON location_postcode TO "{www-user}" ;
217 CREATE TRIGGER location_postcode_before_update BEFORE UPDATE ON location_postcode
218 FOR EACH ROW EXECUTE PROCEDURE postcode_update();
220 DROP TABLE IF EXISTS import_polygon_error;
221 CREATE TABLE import_polygon_error (
227 country_code varchar(2),
230 prevgeometry GEOMETRY(Geometry, 4326),
231 newgeometry GEOMETRY(Geometry, 4326)
233 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
234 GRANT SELECT ON import_polygon_error TO "{www-user}";
236 DROP TABLE IF EXISTS import_polygon_delete;
237 CREATE TABLE import_polygon_delete (
243 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
244 GRANT SELECT ON import_polygon_delete TO "{www-user}";
246 DROP SEQUENCE IF EXISTS file;
247 CREATE SEQUENCE file start 1;
249 -- null table so it won't error
250 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
251 CREATE TABLE wikipedia_article (
252 language text NOT NULL,
257 lat double precision,
258 lon double precision,
259 importance double precision,
260 osm_type character(1),
263 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
264 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
266 CREATE TABLE wikipedia_redirect (
271 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);