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 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-user}" ;
41 GRANT UPDATE ON new_query_log TO "{www-user}" ;
42 GRANT SELECT ON new_query_log TO "{www-user}" ;
45 drop table IF EXISTS word;
52 country_code varchar(2),
53 search_name_count INTEGER,
56 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
57 GRANT SELECT ON word TO "{www-user}" ;
58 DROP SEQUENCE IF EXISTS seq_word;
59 CREATE SEQUENCE seq_word start 1;
61 drop table IF EXISTS location_area CASCADE;
62 CREATE TABLE location_area (
65 country_code VARCHAR(2),
67 rank_search INTEGER NOT NULL,
68 rank_address INTEGER NOT NULL,
71 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
72 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
74 CREATE TABLE location_area_large () INHERITS (location_area);
76 drop table IF EXISTS location_property CASCADE;
77 CREATE TABLE location_property (
80 parent_place_id BIGINT,
84 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
86 CREATE TABLE location_property_aux () INHERITS (location_property);
87 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
88 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
89 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
90 GRANT SELECT ON location_property_aux TO "{www-user}";
92 CREATE TABLE location_property_tiger () INHERITS (location_property) {ts:aux-data};
93 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id) {ts:aux-index};
94 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id) {ts:aux-index};
95 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber) {ts:aux-index};
96 GRANT SELECT ON location_property_tiger TO "{www-user}";
98 drop table IF EXISTS search_name;
99 CREATE TABLE search_name (
102 address_rank integer,
104 country_code varchar(2),
105 name_vector integer[],
106 nameaddress_vector integer[]
108 SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
109 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
111 drop table IF EXISTS place_addressline;
112 CREATE TABLE place_addressline (
114 address_place_id BIGINT,
118 cached_rank_address integer
120 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
122 drop table if exists placex;
123 CREATE TABLE placex (
124 place_id BIGINT NOT NULL,
126 LIKE place INCLUDING CONSTRAINTS,
127 parent_place_id BIGINT,
128 linked_place_id BIGINT,
129 rank_address INTEGER,
132 indexed_status INTEGER,
133 indexed_date TIMESTAMP,
134 wikipedia TEXT, -- calculated wikipedia article name (language:title)
135 geometry_sector INTEGER,
136 calculated_country_code varchar(2)
138 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
139 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
140 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
141 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index};
142 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
143 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
144 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;
146 DROP SEQUENCE IF EXISTS seq_place;
147 CREATE SEQUENCE seq_place start 1;
148 GRANT SELECT on placex to "{www-user}" ;
149 GRANT SELECT ON search_name to "{www-user}" ;
150 GRANT SELECT on place_addressline to "{www-user}" ;
151 GRANT SELECT ON seq_word to "{www-user}" ;
152 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
153 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
154 GRANT SELECT on location_area to "{www-user}" ;
156 -- insert creates the location tagbles, creates location indexes if indexed == true
157 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
158 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
160 -- update insert creates the location tables
161 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
162 FOR EACH ROW EXECUTE PROCEDURE placex_update();
164 -- diff update triggers
165 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
166 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
167 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
168 FOR EACH ROW EXECUTE PROCEDURE place_delete();
169 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
170 FOR EACH ROW EXECUTE PROCEDURE place_insert();
172 drop index idx_placex_sector;
173 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id) {ts:address-index};
175 DROP SEQUENCE seq_postcodes;
176 CREATE SEQUENCE seq_postcodes start 1;
178 drop table import_polygon_error;
179 CREATE TABLE import_polygon_error (
185 country_code varchar(2),
189 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
190 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
191 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
192 GRANT SELECT ON import_polygon_error TO "{www-user}";
194 drop table import_polygon_delete;
195 CREATE TABLE import_polygon_delete (
201 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
202 GRANT SELECT ON import_polygon_delete TO "{www-user}";
205 CREATE SEQUENCE file start 1;
207 -- null table so it won't error
208 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
209 CREATE TABLE wikipedia_article (
210 language text NOT NULL,
215 lat double precision,
216 lon double precision,
217 importance double precision,
218 osm_type character(1),
221 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
222 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
224 CREATE TABLE wikipedia_redirect (
229 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);