1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2026 by the Nominatim developer community.
6 -- For a full list of authors see the git log.
8 -- placex - main table for searchable places
10 DROP TABLE IF EXISTS placex;
12 place_id BIGINT NOT NULL,
13 parent_place_id BIGINT,
14 linked_place_id BIGINT,
16 indexed_date TIMESTAMP,
17 geometry_sector INTEGER NOT NULL,
18 rank_address SMALLINT NOT NULL,
19 rank_search SMALLINT NOT NULL,
20 partition SMALLINT NOT NULL,
21 indexed_status SMALLINT NOT NULL,
22 LIKE place INCLUDING CONSTRAINTS,
23 wikipedia TEXT, -- calculated wikipedia article name (language:title)
24 token_info JSONB, -- custom column for tokenizer use only
25 country_code varchar(2),
28 centroid GEOMETRY(Geometry, 4326) NOT NULL
29 ) {{db.tablespace.search_data}};
31 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {{db.tablespace.search_index}};
32 {% for osm_type in ('N', 'W', 'R') %}
33 CREATE INDEX idx_placex_osmid_{{osm_type | lower}} ON placex
34 USING BTREE (osm_id) {{db.tablespace.search_index}}
35 WHERE osm_type = '{{osm_type}}';
38 -- Usage: - removing linkage status on update
39 -- - lookup linked places for /details
40 CREATE INDEX idx_placex_linked_place_id ON placex
41 USING BTREE (linked_place_id) {{db.tablespace.address_index}}
42 WHERE linked_place_id IS NOT NULL;
44 -- Usage: - check that admin boundaries do not overtake each other rank-wise
45 -- - check that place node in a admin boundary with the same address level
46 -- - boundary is not completely contained in a place area
47 -- - parenting of large-area or unparentable features
48 CREATE INDEX idx_placex_geometry_address_area_candidates ON placex
49 USING gist (geometry) {{db.tablespace.address_index}}
50 WHERE rank_address between 1 and 25
51 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon');
53 -- Usage: - POI is within building with housenumber
54 CREATE INDEX idx_placex_geometry_buildings ON placex
55 USING SPGIST (geometry) {{db.tablespace.address_index}}
56 WHERE address is not null and rank_search = 30
57 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon');
59 -- Usage: - linking of similar named places to boundaries
60 -- - linking of place nodes with same type to boundaries
61 CREATE INDEX idx_placex_geometry_placenode ON placex
62 USING SPGIST (geometry) {{db.tablespace.address_index}}
63 WHERE osm_type = 'N' and rank_search < 26 and class = 'place';
65 -- Usage: - is node part of a way?
66 -- - find parent of interpolation spatially
67 CREATE INDEX idx_placex_geometry_lower_rank_ways ON placex
68 USING SPGIST (geometry) {{db.tablespace.address_index}}
69 WHERE osm_type = 'W' and rank_search >= 26;
71 -- Usage: - linking place nodes by wikidata tag to boundaries
72 CREATE INDEX idx_placex_wikidata on placex
73 USING BTREE ((extratags -> 'wikidata')) {{db.tablespace.address_index}}
74 WHERE extratags ? 'wikidata' and class = 'place'
75 and osm_type = 'N' and rank_search < 26;
77 -- The following two indexes function as a todo list for indexing.
79 CREATE INDEX idx_placex_rank_address_sector ON placex
80 USING BTREE (rank_address, geometry_sector) {{db.tablespace.address_index}}
81 WHERE indexed_status > 0;
83 CREATE INDEX idx_placex_rank_boundaries_sector ON placex
84 USING BTREE (rank_search, geometry_sector) {{db.tablespace.address_index}}
85 WHERE class = 'boundary' and type = 'administrative'
86 and indexed_status > 0;