From 60cea6c8bfe36156a625b7e9da41749060f22acb Mon Sep 17 00:00:00 2001 From: Sarah Hoffmann Date: Wed, 8 Aug 2018 22:04:39 +0200 Subject: [PATCH] fixup use of indexes for latest reverse changes --- lib/ReverseGeocode.php | 10 ++++------ sql/indices.src.sql | 26 ++++++++++++++++++-------- 2 files changed, 22 insertions(+), 14 deletions(-) diff --git a/lib/ReverseGeocode.php b/lib/ReverseGeocode.php index 5648fedf..60f35449 100644 --- a/lib/ReverseGeocode.php +++ b/lib/ReverseGeocode.php @@ -113,9 +113,8 @@ class ReverseGeocode $sSQL .= ' FROM placex'; $sSQL .= ' WHERE osm_type = \'N\''; $sSQL .= ' AND country_code = \''.$sCountryCode.'\''; - $sSQL .= ' AND rank_search > 4'; - $sSQL .= ' AND rank_search <= ' .min(25, $iMaxRank); - $sSQL .= ' AND type != \'postcode\''; + $sSQL .= ' AND rank_search between 5 and ' .min(25, $iMaxRank); + $sSQL .= ' AND class = \'place\' AND type != \'postcode\''; $sSQL .= ' AND name IS NOT NULL '; $sSQL .= ' and indexed_status = 0 and linked_place_id is null'; $sSQL .= ' AND ST_DWithin('.$sPointSQL.', geometry, 5.0)) p '; @@ -194,13 +193,12 @@ class ReverseGeocode // using rank_search because of a better differentiation // for place nodes at rank_address 16 $sSQL .= ' AND rank_search > '.$iRankSearch; - $sSQL .= ' AND rank_search <= ' .$iMaxRank; + $sSQL .= ' AND rank_search <= '.$iMaxRank; $sSQL .= ' AND class = \'place\''; $sSQL .= ' AND type != \'postcode\''; $sSQL .= ' AND name IS NOT NULL '; $sSQL .= ' AND indexed_status = 0 AND linked_place_id is null'; - // preselection through bbox - $sSQL .= ' AND (SELECT geometry FROM placex WHERE place_id = '.$iPlaceID.') && geometry'; + $sSQL .= ' AND ST_DWithin('.$sPointSQL.', geometry, reverse_place_diameter('.$iRankSearch.'::smallint))'; $sSQL .= ' ORDER BY distance ASC,'; $sSQL .= ' rank_address DESC'; $sSQL .= ' limit 500) as a'; diff --git a/sql/indices.src.sql b/sql/indices.src.sql index 0bdebffb..32ac8a3d 100644 --- a/sql/indices.src.sql +++ b/sql/indices.src.sql @@ -14,14 +14,24 @@ CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search) {ts:sear CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address) {ts:search-index}; CREATE INDEX idx_placex_pendingsector ON placex USING BTREE (rank_search,geometry_sector) {ts:address-index} where indexed_status > 0; CREATE INDEX idx_placex_parent_place_id ON placex USING BTREE (parent_place_id) {ts:search-index} where parent_place_id IS NOT NULL; -CREATE INDEX idx_placex_geometry_reverse_lookupPoint ON placex USING gist (geometry) {ts:search-index} -where (name is not null or housenumber is not null or rank_address between 26 and 27) and class not in ('railway','tunnel','bridge','man_made') and rank_address >= 26 and indexed_status = 0 and linked_place_id is null; -CREATE INDEX idx_placex_geometry_reverse_lookupPolygon ON placex USING gist (geometry) {ts:search-index} where St_GeometryType(geometry) in ('ST_Polygon', 'ST_MultiPolygon') and rank_address between 4 and 25 and type != 'postcode' and name is not null and indexed_status = 0 and linked_place_id is null; -CREATE INDEX idx_placex_geometry_reverse_placeNode_rank_search ON placex USING gist (geometry) {ts:search-index} where -osm_type = 'N' and rank_search > 0 and rank_search <= 25 and class = 'place' and type != 'postcode' and name is not null and indexed_status = 0 and linked_place_id is null; -CREATE INDEX idx_placex_geometry_reverse_placeNode_rank_address ON placex USING gist (geometry) {ts:search-index} where -osm_type = 'N' and rank_address > 0 and rank_address <= 25 and type != 'postcode' and name is not null and indexed_status = 0 and linked_place_id is null; -GRANT SELECT ON Table country_osm_grid to "{www-user}"; + +CREATE INDEX idx_placex_geometry_reverse_lookupPoint + ON placex USING gist (geometry) {ts:search-index} + WHERE (name is not null or housenumber is not null or rank_address between 26 and 27) + AND class not in ('railway','tunnel','bridge','man_made') + AND rank_address >= 26 AND indexed_status = 0 AND linked_place_id is null; +CREATE INDEX idx_placex_geometry_reverse_lookupPolygon + ON placex USING gist (geometry) {ts:search-index} + WHERE St_GeometryType(geometry) in ('ST_Polygon', 'ST_MultiPolygon') + AND rank_address between 4 and 25 AND type != 'postcode' + AND name is not null AND indexed_status = 0 AND linked_place_id is null; +CREATE INDEX idx_placex_geometry_reverse_placeNode + ON placex USING gist (geometry) {ts:search-index} + WHERE osm_type = 'N' AND rank_search between 5 and 25 + AND class = 'place' AND type != 'postcode' + AND name is not null AND indexed_status = 0 AND linked_place_id is null; + +GRANT SELECT ON table country_osm_grid to "{www-user}"; CREATE INDEX idx_location_area_country_place_id ON location_area_country USING BTREE (place_id) {ts:address-index}; -- 2.39.5