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 -- Used to find postcode areas after a search in location_postcode.
25 CREATE INDEX IF NOT EXISTS idx_placex_postcode_areas
26 ON placex USING BTREE (country_code, postcode) {{db.tablespace.search_index}}
27 WHERE osm_type = 'R' AND class = 'boundary' AND type = 'postal_code';
29 CREATE INDEX IF NOT EXISTS idx_placex_geometry ON placex
30 USING GIST (geometry) {{db.tablespace.search_index}};
31 -- Index is needed during import but can be dropped as soon as a full
32 -- geometry index is in place. The partial index is almost as big as the full
35 DROP INDEX IF EXISTS idx_placex_geometry_lower_rank_ways;
37 CREATE INDEX IF NOT EXISTS idx_placex_geometry_reverse_lookupPolygon
38 ON placex USING gist (geometry) {{db.tablespace.search_index}}
39 WHERE St_GeometryType(geometry) in ('ST_Polygon', 'ST_MultiPolygon')
40 AND rank_address between 4 and 25 AND type != 'postcode'
41 AND name is not null AND indexed_status = 0 AND linked_place_id is null;
43 -- used in reverse large area lookup
44 CREATE INDEX IF NOT EXISTS idx_placex_geometry_reverse_lookupPlaceNode
45 ON placex USING gist (ST_Buffer(geometry, reverse_place_diameter(rank_search)))
46 {{db.tablespace.search_index}}
47 WHERE rank_address between 4 and 25 AND type != 'postcode'
48 AND name is not null AND linked_place_id is null AND osm_type = 'N';
50 CREATE INDEX IF NOT EXISTS idx_osmline_parent_place_id
51 ON location_property_osmline USING BTREE (parent_place_id) {{db.tablespace.search_index}}
52 WHERE parent_place_id is not null;
54 CREATE INDEX IF NOT EXISTS idx_osmline_parent_osm_id
55 ON location_property_osmline USING BTREE (osm_id) {{db.tablespace.search_index}};
57 CREATE INDEX IF NOT EXISTS idx_postcode_postcode
58 ON location_postcode USING BTREE (postcode) {{db.tablespace.search_index}};
62 DROP INDEX IF EXISTS idx_placex_geometry_address_area_candidates;
63 DROP INDEX IF EXISTS idx_placex_geometry_buildings;
64 DROP INDEX IF EXISTS idx_placex_wikidata;
65 DROP INDEX IF EXISTS idx_placex_rank_address_sector;
66 DROP INDEX IF EXISTS idx_placex_rank_boundaries_sector;
68 -- Indices only needed for updating.
70 CREATE INDEX IF NOT EXISTS idx_location_area_country_place_id
71 ON location_area_country USING BTREE (place_id) {{db.tablespace.address_index}};
73 CREATE UNIQUE INDEX IF NOT EXISTS idx_place_osm_unique
74 ON place USING btree(osm_id, osm_type, class, type) {{db.tablespace.address_index}};
76 -- Table needed for running updates with osm2pgsql on place.
77 CREATE TABLE IF NOT EXISTS place_to_be_deleted (
85 CREATE INDEX IF NOT EXISTS idx_location_postcode_parent_place_id
86 ON location_postcode USING BTREE (parent_place_id) {{db.tablespace.address_index}};
89 -- Indices only needed for search.
90 {% if 'search_name' in db.tables %}
92 CREATE INDEX IF NOT EXISTS idx_search_name_nameaddress_vector
93 ON search_name USING GIN (nameaddress_vector) WITH (fastupdate = off) {{db.tablespace.search_index}};
95 CREATE INDEX IF NOT EXISTS idx_search_name_name_vector
96 ON search_name USING GIN (name_vector) WITH (fastupdate = off) {{db.tablespace.search_index}};
98 CREATE INDEX IF NOT EXISTS idx_search_name_centroid
99 ON search_name USING GIST (centroid) {{db.tablespace.search_index}};
101 {% if postgres.has_index_non_key_column %}
103 CREATE INDEX IF NOT EXISTS idx_placex_housenumber
104 ON placex USING btree (parent_place_id)
105 INCLUDE (housenumber) {{db.tablespace.search_index}}
106 WHERE housenumber is not null;
108 CREATE INDEX IF NOT EXISTS idx_osmline_parent_osm_id_with_hnr
109 ON location_property_osmline USING btree(parent_place_id)
110 INCLUDE (startnumber, endnumber) {{db.tablespace.search_index}}
111 WHERE startnumber is not null;