1 drop table if exists import_status;
2 CREATE TABLE import_status (
3 lastimportdate timestamp with time zone NOT NULL,
7 GRANT SELECT ON import_status TO "{{config.DATABASE_WEBUSER}}" ;
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 "{{config.DATABASE_WEBUSER}}" ;
34 GRANT UPDATE ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
35 GRANT SELECT ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
37 GRANT SELECT ON TABLE country_name TO "{{config.DATABASE_WEBUSER}}";
39 DROP TABLE IF EXISTS nominatim_properties;
40 CREATE TABLE nominatim_properties (
44 GRANT SELECT ON TABLE nominatim_properties TO "{{config.DATABASE_WEBUSER}}";
46 drop table IF EXISTS location_area CASCADE;
47 CREATE TABLE location_area (
51 rank_search SMALLINT NOT NULL,
52 rank_address SMALLINT NOT NULL,
53 country_code VARCHAR(2),
56 centroid GEOMETRY(Point, 4326),
57 geometry GEOMETRY(Geometry, 4326)
60 CREATE TABLE location_area_large () INHERITS (location_area);
62 DROP TABLE IF EXISTS location_area_country;
63 CREATE TABLE location_area_country (
65 country_code varchar(2),
66 geometry GEOMETRY(Geometry, 4326)
67 ) {{db.tablespace.address_data}};
68 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {{db.tablespace.address_index}};
71 CREATE TABLE location_property_tiger (
73 parent_place_id BIGINT,
78 interpolationtype TEXT,
80 GRANT SELECT ON location_property_tiger TO "{{config.DATABASE_WEBUSER}}";
82 drop table if exists location_property_osmline;
83 CREATE TABLE location_property_osmline (
84 place_id BIGINT NOT NULL,
86 parent_place_id BIGINT,
87 geometry_sector INTEGER,
88 indexed_date TIMESTAMP,
92 indexed_status SMALLINT,
94 interpolationtype TEXT,
96 token_info JSONB, -- custom column for tokenizer use only
98 country_code VARCHAR(2)
99 ){{db.tablespace.search_data}};
100 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {{db.tablespace.search_index}};
101 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {{db.tablespace.address_index}};
102 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {{db.tablespace.search_index}};
103 GRANT SELECT ON location_property_osmline TO "{{config.DATABASE_WEBUSER}}";
105 drop table IF EXISTS search_name;
106 {% if not db.reverse_only %}
107 CREATE TABLE search_name (
110 search_rank SMALLINT,
111 address_rank SMALLINT,
112 name_vector integer[],
113 nameaddress_vector integer[],
114 country_code varchar(2),
115 centroid GEOMETRY(Geometry, 4326)
116 ) {{db.tablespace.search_data}};
117 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {{db.tablespace.search_index}};
118 GRANT SELECT ON search_name to "{{config.DATABASE_WEBUSER}}" ;
121 drop table IF EXISTS place_addressline;
122 CREATE TABLE place_addressline (
124 address_place_id BIGINT,
126 cached_rank_address SMALLINT,
129 ) {{db.tablespace.search_data}};
130 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {{db.tablespace.search_index}};
132 drop table if exists placex;
133 CREATE TABLE placex (
134 place_id BIGINT NOT NULL,
135 parent_place_id BIGINT,
136 linked_place_id BIGINT,
138 indexed_date TIMESTAMP,
139 geometry_sector INTEGER,
140 rank_address SMALLINT,
141 rank_search SMALLINT,
143 indexed_status SMALLINT,
144 LIKE place INCLUDING CONSTRAINTS,
145 wikipedia TEXT, -- calculated wikipedia article name (language:title)
146 token_info JSONB, -- custom column for tokenizer use only
147 country_code varchar(2),
150 centroid GEOMETRY(Geometry, 4326)
151 ) {{db.tablespace.search_data}};
152 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {{db.tablespace.search_index}};
153 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {{db.tablespace.search_index}};
154 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {{db.tablespace.address_index}} WHERE linked_place_id IS NOT NULL;
155 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {{db.tablespace.address_index}};
156 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {{db.tablespace.search_index}};
157 CREATE INDEX idx_placex_geometry_buildings ON placex
158 USING {{postgres.spgist_geom}} (geometry) {{db.tablespace.search_index}}
159 WHERE address is not null and rank_search = 30
160 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon');
161 CREATE INDEX idx_placex_geometry_placenode ON placex
162 USING {{postgres.spgist_geom}} (geometry) {{db.tablespace.search_index}}
163 WHERE osm_type = 'N' and rank_search < 26
164 and class = 'place' and type != 'postcode' and linked_place_id is null;
165 CREATE INDEX idx_placex_wikidata on placex USING BTREE ((extratags -> 'wikidata')) {{db.tablespace.address_index}} WHERE extratags ? 'wikidata' and class = 'place' and osm_type = 'N' and rank_search < 26;
167 DROP SEQUENCE IF EXISTS seq_place;
168 CREATE SEQUENCE seq_place start 1;
169 GRANT SELECT on placex to "{{config.DATABASE_WEBUSER}}" ;
170 GRANT SELECT on place_addressline to "{{config.DATABASE_WEBUSER}}" ;
171 GRANT SELECT ON planet_osm_ways to "{{config.DATABASE_WEBUSER}}" ;
172 GRANT SELECT ON planet_osm_rels to "{{config.DATABASE_WEBUSER}}" ;
173 GRANT SELECT on location_area to "{{config.DATABASE_WEBUSER}}" ;
175 -- Table for synthetic postcodes.
176 DROP TABLE IF EXISTS location_postcode;
177 CREATE TABLE location_postcode (
179 parent_place_id BIGINT,
180 rank_search SMALLINT,
181 rank_address SMALLINT,
182 indexed_status SMALLINT,
183 indexed_date TIMESTAMP,
184 country_code varchar(2),
186 geometry GEOMETRY(Geometry, 4326)
188 CREATE UNIQUE INDEX idx_postcode_id ON location_postcode USING BTREE (place_id) {{db.tablespace.search_index}};
189 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {{db.tablespace.address_index}};
190 GRANT SELECT ON location_postcode TO "{{config.DATABASE_WEBUSER}}" ;
192 DROP TABLE IF EXISTS import_polygon_error;
193 CREATE TABLE import_polygon_error (
199 country_code varchar(2),
202 prevgeometry GEOMETRY(Geometry, 4326),
203 newgeometry GEOMETRY(Geometry, 4326)
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 "{{config.DATABASE_WEBUSER}}";
208 DROP TABLE IF EXISTS 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 "{{config.DATABASE_WEBUSER}}";
218 DROP SEQUENCE IF EXISTS file;
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),
237 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
238 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
240 CREATE TABLE wikipedia_redirect (
245 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);
247 -- osm2pgsql does not create indexes on the middle tables for Nominatim
248 -- Add one for lookup of associated street relations.
249 CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];
251 GRANT SELECT ON table country_osm_grid to "{{config.DATABASE_WEBUSER}}";