1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2022 by the Nominatim developer community.
6 -- For a full list of authors see the git log.
8 -- Indices used only during search and update.
9 -- These indices are created only after the indexing process is done.
11 CREATE INDEX IF NOT EXISTS idx_place_addressline_address_place_id
12 ON place_addressline USING BTREE (address_place_id) {{db.tablespace.search_index}};
14 CREATE INDEX IF NOT EXISTS idx_placex_rank_search
15 ON placex USING BTREE (rank_search) {{db.tablespace.search_index}};
17 CREATE INDEX IF NOT EXISTS idx_placex_rank_address
18 ON placex USING BTREE (rank_address) {{db.tablespace.search_index}};
20 CREATE INDEX IF NOT EXISTS idx_placex_parent_place_id
21 ON placex USING BTREE (parent_place_id) {{db.tablespace.search_index}}
22 WHERE parent_place_id IS NOT NULL;
24 CREATE INDEX IF NOT EXISTS idx_placex_geometry ON placex
25 USING GIST (geometry) {{db.tablespace.search_index}};
27 CREATE INDEX IF NOT EXISTS idx_placex_geometry_reverse_lookupPolygon
28 ON placex USING gist (geometry) {{db.tablespace.search_index}}
29 WHERE St_GeometryType(geometry) in ('ST_Polygon', 'ST_MultiPolygon')
30 AND rank_address between 4 and 25 AND type != 'postcode'
31 AND name is not null AND indexed_status = 0 AND linked_place_id is null;
33 -- used in reverse large area lookup
34 CREATE INDEX IF NOT EXISTS idx_placex_geometry_reverse_lookupPlaceNode
35 ON placex USING gist (ST_Buffer(geometry, reverse_place_diameter(rank_search)))
36 {{db.tablespace.search_index}}
37 WHERE rank_address between 4 and 25 AND type != 'postcode'
38 AND name is not null AND linked_place_id is null AND osm_type = 'N';
40 CREATE INDEX IF NOT EXISTS idx_osmline_parent_place_id
41 ON location_property_osmline USING BTREE (parent_place_id) {{db.tablespace.search_index}}
42 WHERE parent_place_id is not null;
44 CREATE INDEX IF NOT EXISTS idx_osmline_parent_osm_id
45 ON location_property_osmline USING BTREE (osm_id) {{db.tablespace.search_index}};
47 CREATE INDEX IF NOT EXISTS idx_postcode_postcode
48 ON location_postcode USING BTREE (postcode) {{db.tablespace.search_index}};
52 DROP INDEX IF EXISTS idx_placex_geometry_address_area_candidates;
53 DROP INDEX IF EXISTS idx_placex_geometry_buildings;
54 DROP INDEX IF EXISTS idx_placex_geometry_lower_rank_ways;
55 DROP INDEX IF EXISTS idx_placex_wikidata;
56 DROP INDEX IF EXISTS idx_placex_rank_address_sector;
57 DROP INDEX IF EXISTS idx_placex_rank_boundaries_sector;
59 -- Indices only needed for updating.
61 CREATE INDEX IF NOT EXISTS idx_location_area_country_place_id
62 ON location_area_country USING BTREE (place_id) {{db.tablespace.address_index}};
64 CREATE UNIQUE INDEX IF NOT EXISTS idx_place_osm_unique
65 ON place USING btree(osm_id, osm_type, class, type) {{db.tablespace.address_index}};
67 -- Table needed for running updates with osm2pgsql on place.
68 CREATE TABLE IF NOT EXISTS place_to_be_deleted (
77 -- Indices only needed for search.
78 {% if 'search_name' in db.tables %}
80 CREATE INDEX IF NOT EXISTS idx_search_name_nameaddress_vector
81 ON search_name USING GIN (nameaddress_vector) WITH (fastupdate = off) {{db.tablespace.search_index}};
83 CREATE INDEX IF NOT EXISTS idx_search_name_name_vector
84 ON search_name USING GIN (name_vector) WITH (fastupdate = off) {{db.tablespace.search_index}};
86 CREATE INDEX IF NOT EXISTS idx_search_name_centroid
87 ON search_name USING GIST (centroid) {{db.tablespace.search_index}};
89 {% if postgres.has_index_non_key_column %}
91 CREATE INDEX IF NOT EXISTS idx_placex_housenumber
92 ON placex USING btree (parent_place_id)
93 INCLUDE (housenumber) {{db.tablespace.search_index}}
94 WHERE housenumber is not null;
96 CREATE INDEX IF NOT EXISTS idx_osmline_parent_osm_id_with_hnr
97 ON location_property_osmline USING btree(parent_place_id)
98 INCLUDE (startnumber, endnumber) {{db.tablespace.search_index}}
99 WHERE startnumber is not null;