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 drop table if exists import_npi_log;
17 CREATE TABLE import_npi_log (
26 --drop table IF EXISTS query_log;
27 CREATE TABLE query_log (
34 CREATE INDEX idx_query_log ON query_log USING BTREE (starttime);
35 GRANT SELECT ON query_log TO "{www-user}" ;
36 GRANT INSERT ON query_log TO "{www-user}" ;
37 GRANT UPDATE ON query_log TO "{www-user}" ;
39 CREATE TABLE new_query_log (
51 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
52 GRANT INSERT ON new_query_log TO "{www-user}" ;
53 GRANT UPDATE ON new_query_log TO "{www-user}" ;
54 GRANT SELECT ON new_query_log TO "{www-user}" ;
56 create view vw_search_query_log as SELECT substr(query, 1, 50) AS query, starttime, endtime - starttime AS duration, substr(useragent, 1, 20) as
57 useragent, language, results, ipaddress FROM new_query_log WHERE type = 'search' ORDER BY starttime DESC;
59 drop table IF EXISTS word;
66 country_code varchar(2),
67 search_name_count INTEGER,
70 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
71 GRANT SELECT ON word TO "{www-user}" ;
72 DROP SEQUENCE IF EXISTS seq_word;
73 CREATE SEQUENCE seq_word start 1;
75 drop table IF EXISTS location_area CASCADE;
76 CREATE TABLE location_area (
79 country_code VARCHAR(2),
81 rank_search INTEGER NOT NULL,
82 rank_address INTEGER NOT NULL,
85 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
86 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
88 CREATE TABLE location_area_large () INHERITS (location_area);
90 drop table IF EXISTS location_property CASCADE;
91 CREATE TABLE location_property (
94 parent_place_id BIGINT,
98 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
100 CREATE TABLE location_property_aux () INHERITS (location_property);
101 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
102 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
103 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
104 GRANT SELECT ON location_property_aux TO "{www-user}";
106 CREATE TABLE location_property_tiger () INHERITS (location_property) {ts:aux-data};
107 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id) {ts:aux-index};
108 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id) {ts:aux-index};
109 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber) {ts:aux-index};
110 GRANT SELECT ON location_property_tiger TO "{www-user}";
112 drop table IF EXISTS search_name;
113 CREATE TABLE search_name (
116 address_rank integer,
118 country_code varchar(2),
119 name_vector integer[],
120 nameaddress_vector integer[]
122 SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
123 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
125 drop table IF EXISTS place_addressline;
126 CREATE TABLE place_addressline (
128 address_place_id BIGINT,
132 cached_rank_address integer
134 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
136 drop table if exists placex;
137 CREATE TABLE placex (
138 place_id BIGINT NOT NULL,
140 LIKE place INCLUDING CONSTRAINTS,
141 parent_place_id BIGINT,
142 linked_place_id BIGINT,
143 rank_address INTEGER,
146 indexed_status INTEGER,
147 indexed_date TIMESTAMP,
148 wikipedia TEXT, -- calculated wikipedia article name (language:title)
149 geometry_sector INTEGER,
150 calculated_country_code varchar(2)
152 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
153 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
154 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
155 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index};
156 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
157 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
158 CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name'),rank_search) WHERE osm_type='N' and rank_search < 26 {ts:address-index};
160 DROP SEQUENCE IF EXISTS seq_place;
161 CREATE SEQUENCE seq_place start 1;
162 GRANT SELECT on placex to "{www-user}" ;
163 GRANT SELECT ON search_name to "{www-user}" ;
164 GRANT SELECT on place_addressline to "{www-user}" ;
165 GRANT SELECT ON seq_word to "{www-user}" ;
166 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
167 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
168 GRANT SELECT on location_area to "{www-user}" ;
170 -- insert creates the location tagbles, creates location indexes if indexed == true
171 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
172 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
174 -- update insert creates the location tables
175 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
176 FOR EACH ROW EXECUTE PROCEDURE placex_update();
178 -- diff update triggers
179 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
180 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
181 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
182 FOR EACH ROW EXECUTE PROCEDURE place_delete();
183 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
184 FOR EACH ROW EXECUTE PROCEDURE place_insert();
186 drop index idx_placex_sector;
187 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id) {ts:address-index};
189 DROP SEQUENCE seq_postcodes;
190 CREATE SEQUENCE seq_postcodes start 1;
192 drop table import_polygon_error;
193 CREATE TABLE import_polygon_error (
199 country_code varchar(2),
203 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
204 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
205 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
206 GRANT SELECT ON import_polygon_error TO "{www-user}";
208 drop table import_polygon_delete;
209 CREATE TABLE import_polygon_delete (
215 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
216 GRANT SELECT ON import_polygon_delete TO "{www-user}";
219 CREATE SEQUENCE file start 1;
221 -- null table so it won't error
222 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
223 CREATE TABLE wikipedia_article (
224 language text NOT NULL,
229 lat double precision,
230 lon double precision,
231 importance double precision,
232 osm_type character(1),
235 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
236 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
238 CREATE TABLE wikipedia_redirect (
243 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);