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),
65 centroid GEOMETRY(Point, 4326),
66 geometry GEOMETRY(Geometry, 4326)
69 CREATE TABLE location_area_large () INHERITS (location_area);
71 drop table IF EXISTS location_property CASCADE;
72 CREATE TABLE location_property (
74 parent_place_id BIGINT,
78 centroid GEOMETRY(Point, 4326)
81 CREATE TABLE location_property_aux () INHERITS (location_property);
82 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
83 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
84 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
85 GRANT SELECT ON location_property_aux TO "{www-user}";
87 CREATE TABLE location_property_tiger (
89 parent_place_id BIGINT,
94 interpolationtype TEXT,
96 GRANT SELECT ON location_property_tiger TO "{www-user}";
98 drop table if exists location_property_osmline;
99 CREATE TABLE location_property_osmline (
100 place_id BIGINT NOT NULL,
102 parent_place_id BIGINT,
103 geometry_sector INTEGER,
104 indexed_date TIMESTAMP,
108 indexed_status SMALLINT,
110 interpolationtype TEXT,
113 country_code VARCHAR(2)
115 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
116 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
117 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
118 GRANT SELECT ON location_property_osmline TO "{www-user}";
120 drop table IF EXISTS search_name;
121 CREATE TABLE search_name (
124 search_rank SMALLINT,
125 address_rank SMALLINT,
126 name_vector integer[],
127 nameaddress_vector integer[],
128 country_code varchar(2),
129 centroid GEOMETRY(Geometry, 4326)
131 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
133 drop table IF EXISTS place_addressline;
134 CREATE TABLE place_addressline (
136 address_place_id BIGINT,
138 cached_rank_address SMALLINT,
142 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
144 drop table if exists placex;
145 CREATE TABLE placex (
146 place_id BIGINT NOT NULL,
147 parent_place_id BIGINT,
148 linked_place_id BIGINT,
150 indexed_date TIMESTAMP,
151 geometry_sector INTEGER,
152 rank_address SMALLINT,
153 rank_search SMALLINT,
155 indexed_status SMALLINT,
156 LIKE place INCLUDING CONSTRAINTS,
157 wikipedia TEXT, -- calculated wikipedia article name (language:title)
158 country_code varchar(2),
161 centroid GEOMETRY(Geometry, 4326)
163 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
164 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
165 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index} WHERE linked_place_id IS NOT NULL;
166 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
167 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
168 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;
170 DROP SEQUENCE IF EXISTS seq_place;
171 CREATE SEQUENCE seq_place start 1;
172 GRANT SELECT on placex to "{www-user}" ;
173 GRANT SELECT ON search_name to "{www-user}" ;
174 GRANT SELECT on place_addressline to "{www-user}" ;
175 GRANT SELECT ON seq_word to "{www-user}" ;
176 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
177 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
178 GRANT SELECT on location_area to "{www-user}" ;
180 -- insert creates the location tables, creates location indexes if indexed == true
181 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
182 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
183 CREATE TRIGGER osmline_before_insert BEFORE INSERT ON location_property_osmline
184 FOR EACH ROW EXECUTE PROCEDURE osmline_insert();
186 -- update insert creates the location tables
187 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
188 FOR EACH ROW EXECUTE PROCEDURE placex_update();
189 CREATE TRIGGER osmline_before_update BEFORE UPDATE ON location_property_osmline
190 FOR EACH ROW EXECUTE PROCEDURE osmline_update();
192 -- diff update triggers
193 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
194 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
195 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
196 FOR EACH ROW EXECUTE PROCEDURE place_delete();
197 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
198 FOR EACH ROW EXECUTE PROCEDURE place_insert();
200 -- Table for synthetic postcodes.
201 DROP TABLE IF EXISTS location_postcode;
202 CREATE TABLE location_postcode (
204 parent_place_id BIGINT,
205 rank_search SMALLINT,
206 rank_address SMALLINT,
207 indexed_status SMALLINT,
208 indexed_date TIMESTAMP,
209 country_code varchar(2),
211 geometry GEOMETRY(Geometry, 4326)
213 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {ts:address-index};
215 CREATE TRIGGER location_postcode_before_update BEFORE UPDATE ON location_postcode
216 FOR EACH ROW EXECUTE PROCEDURE postcode_update();
218 DROP TABLE IF EXISTS import_polygon_error;
219 CREATE TABLE import_polygon_error (
225 country_code varchar(2),
228 prevgeometry GEOMTRY(Geometry, 4326),
229 newgeometry GEOMTRY(Geometry, 4326)
231 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
232 GRANT SELECT ON import_polygon_error TO "{www-user}";
234 DROP TABLE IF EXISTS import_polygon_delete;
235 CREATE TABLE import_polygon_delete (
241 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
242 GRANT SELECT ON import_polygon_delete TO "{www-user}";
244 DROP SEQUENCE IF EXISTS file;
245 CREATE SEQUENCE file start 1;
247 -- null table so it won't error
248 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
249 CREATE TABLE wikipedia_article (
250 language text NOT NULL,
255 lat double precision,
256 lon double precision,
257 importance double precision,
258 osm_type character(1),
261 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
262 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
264 CREATE TABLE wikipedia_redirect (
269 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);