1 drop table if exists import_status;
2 CREATE TABLE import_status (
3 lastimportdate timestamp NOT NULL
5 GRANT SELECT ON import_status TO "{www-user}" ;
7 drop table if exists import_osmosis_log;
8 CREATE TABLE import_osmosis_log (
16 CREATE TABLE new_query_log (
29 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
30 GRANT INSERT ON new_query_log TO "{www-user}" ;
31 GRANT UPDATE ON new_query_log TO "{www-user}" ;
32 GRANT SELECT ON new_query_log TO "{www-user}" ;
34 GRANT SELECT ON TABLE country_name TO "{www-user}";
35 GRANT SELECT ON TABLE gb_postcode TO "{www-user}";
37 drop table IF EXISTS word;
44 country_code varchar(2),
45 search_name_count INTEGER,
48 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
49 GRANT SELECT ON word TO "{www-user}" ;
50 DROP SEQUENCE IF EXISTS seq_word;
51 CREATE SEQUENCE seq_word start 1;
53 drop table IF EXISTS location_area CASCADE;
54 CREATE TABLE location_area (
57 country_code VARCHAR(2),
59 rank_search INTEGER NOT NULL,
60 rank_address INTEGER NOT NULL,
63 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
64 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
66 CREATE TABLE location_area_large () INHERITS (location_area);
68 drop table IF EXISTS location_property CASCADE;
69 CREATE TABLE location_property (
72 parent_place_id BIGINT,
76 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
78 CREATE TABLE location_property_aux () INHERITS (location_property);
79 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
80 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
81 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
82 GRANT SELECT ON location_property_aux TO "{www-user}";
84 CREATE TABLE location_property_tiger (linegeo GEOMETRY, place_id BIGINT, partition INTEGER, parent_place_id BIGINT, startnumber INTEGER, endnumber INTEGER, interpolationtype TEXT, postcode TEXT);
85 GRANT SELECT ON location_property_tiger TO "{www-user}";
87 drop table if exists location_property_osmline;
88 CREATE TABLE location_property_osmline (
90 place_id BIGINT NOT NULL,
93 parent_place_id BIGINT,
96 interpolationtype TEXT,
101 country_code VARCHAR(2),
102 geometry_sector INTEGER,
103 indexed_status INTEGER,
104 indexed_date TIMESTAMP){ts:search-data};
105 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
106 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
107 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
108 GRANT SELECT ON location_property_osmline TO "{www-user}";
110 drop table IF EXISTS search_name;
111 CREATE TABLE search_name (
114 address_rank integer,
116 country_code varchar(2),
117 name_vector integer[],
118 nameaddress_vector integer[]
120 SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
121 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
123 drop table IF EXISTS place_addressline;
124 CREATE TABLE place_addressline (
126 address_place_id BIGINT,
130 cached_rank_address integer
132 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
134 drop table if exists placex;
135 CREATE TABLE placex (
136 place_id BIGINT NOT NULL,
138 LIKE place INCLUDING CONSTRAINTS,
139 parent_place_id BIGINT,
140 linked_place_id BIGINT,
141 rank_address INTEGER,
144 indexed_status INTEGER,
145 indexed_date TIMESTAMP,
146 wikipedia TEXT, -- calculated wikipedia article name (language:title)
147 geometry_sector INTEGER,
148 country_code varchar(2),
154 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
155 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
156 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
157 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index};
158 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
159 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
160 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;
162 DROP SEQUENCE IF EXISTS seq_place;
163 CREATE SEQUENCE seq_place start 1;
164 GRANT SELECT on placex to "{www-user}" ;
165 GRANT SELECT ON search_name to "{www-user}" ;
166 GRANT SELECT on place_addressline to "{www-user}" ;
167 GRANT SELECT ON seq_word to "{www-user}" ;
168 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
169 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
170 GRANT SELECT on location_area to "{www-user}" ;
172 -- insert creates the location tables, creates location indexes if indexed == true
173 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
174 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
175 CREATE TRIGGER osmline_before_insert BEFORE INSERT ON location_property_osmline
176 FOR EACH ROW EXECUTE PROCEDURE osmline_insert();
178 -- update insert creates the location tables
179 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
180 FOR EACH ROW EXECUTE PROCEDURE placex_update();
181 CREATE TRIGGER osmline_before_update BEFORE UPDATE ON location_property_osmline
182 FOR EACH ROW EXECUTE PROCEDURE osmline_update();
184 -- diff update triggers
185 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
186 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
187 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
188 FOR EACH ROW EXECUTE PROCEDURE place_delete();
189 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
190 FOR EACH ROW EXECUTE PROCEDURE place_insert();
192 DROP SEQUENCE IF EXISTS seq_postcodes;
193 CREATE SEQUENCE seq_postcodes start 1;
195 DROP TABLE IF EXISTS import_polygon_error;
196 CREATE TABLE import_polygon_error (
202 country_code varchar(2),
206 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
207 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
208 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
209 GRANT SELECT ON import_polygon_error TO "{www-user}";
211 DROP TABLE IF EXISTS import_polygon_delete;
212 CREATE TABLE import_polygon_delete (
218 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
219 GRANT SELECT ON import_polygon_delete TO "{www-user}";
221 DROP SEQUENCE IF EXISTS file;
222 CREATE SEQUENCE file start 1;
224 -- null table so it won't error
225 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
226 CREATE TABLE wikipedia_article (
227 language text NOT NULL,
232 lat double precision,
233 lon double precision,
234 importance double precision,
235 osm_type character(1),
238 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
239 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
241 CREATE TABLE wikipedia_redirect (
246 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);