[PostGIS] #5984: PostGIS selectivity is screwing up queries and forcing it to choose a spatial index when it's inappropriate
PostGIS
trac at osgeo.org
Wed Sep 10 16:34:16 PDT 2025
#5984: PostGIS selectivity is screwing up queries and forcing it to choose a
spatial index when it's inappropriate
-----------------------+---------------------------
Reporter: robe | Owner: pramsey
Type: defect | Status: new
Priority: critical | Milestone: PostGIS 3.4.5
Component: postgis | Version: 3.5.x
Resolution: | Keywords:
-----------------------+---------------------------
Comment (by robe):
Here is a better query to use, one that uses an id in the data set
There you can see 42 rows had to be removed by a filter call
{{{
EXPLAIN ANALYZE SELECT wn.way_id FROM test_way_nodes AS wn INNER JOIN
test_nodes AS n ON wn.node_id = n.id WHERE wn.node_id = 12862767139
AND ST_Contains(ST_GeomFromEWKT('SRID=4326;POLYGON((6.1198199
52.612195500000006,6.1198199 53.2038323,7.09
27397 53.2038323,7.0927397 52.612195500000006,6.1198199
52.612195500000006))'), n.geom);
QUERY PLAN
--------------------
Nested Loop (cost=0.70..29.25 rows=1 width=8) (actual time=0.349..0.350
rows=0 loops=1)
-> Index Scan using idx_test_way_nodes_node_id on test_way_nodes wn
(cost=0.42..8.44 rows=1 width=16) (actual time=0.075..0.076 rows=1
loops=1)
Index Cond: (node_id = '12862767139'::bigint)
-> Index Scan using idx_test_nodes_geom on test_nodes n
(cost=0.28..20.80 rows=1 width=8) (actual time=0.271..0.271 rows=0
loops=1)
Index Cond: (geom @
'0103000020E61000000100000005000000D5A35F11B27A184013A1116C5C4E4A40D5A35F11B27A18402A2F432D179A4A40D529EA27F75E1C402A2F432D179A4A40D529EA27F75E1C4013A1116C5C4E4A40D5A35F11B27A184013A1116C5C4E4A40'::geometry)
Filter: ((id = '12862767139'::bigint) AND
st_contains('0103000020E61000000100000005000000D5A35F11B27A184013A1116C5C4E4A40D5A35F11B27A18402A2F432D179A4A40D529EA27F75E1C402A2F432D179A4A40D529EA27F75E1C4013A1116C5C4E4A40D5A35F11B27A184013A1116C5C4E4A4
0'::geometry, geom))
Rows Removed by Filter: 43
Planning Time: 2.873 ms
Execution Time: 0.472 ms
(9 rows)
}}}
Verses query that prevents spatial index usage
{{{
EXPLAIN ANALYZE SELECT wn.way_id FROM test_way_nodes AS wn INNER JOIN
test_nodes AS n ON wn.node_id = n.id WHERE wn.node_id = 12862767139
AND _ST_Contains(ST_GeomFromEWKT('SRID=4326;POLYGON((6.1198199
52.612195500000006,6.1198199 53.2038323,7.0
927397 53.2038323,7.0927397 52.612195500000006,6.1198199
52.612195500000006))'), n.geom);
QUERY PLAN
-------------------------------------------------
Nested Loop (cost=0.84..29.38 rows=1 width=8) (actual time=0.132..0.133
rows=0 loops=1)
-> Index Scan using idx_test_way_nodes_node_id on test_way_nodes wn
(cost=0.42..8.44 rows=1 width=16) (actual time=0.017..0.018 rows=1
loops=1)
Index Cond: (node_id = '12862767139'::bigint)
-> Index Scan using test_nodes_pkey on test_nodes n (cost=0.42..20.94
rows=1 width=8) (actual time=0.111..0.111 rows=0 loops=1)
Index Cond: (id = '12862767139'::bigint)
Filter:
_st_contains('0103000020E61000000100000005000000D5A35F11B27A184013A1116C5C4E4A40D5A35F11B27A18402A2F432D179A4A40D529EA27F75E1C402A2F432D179A4A40D529EA27F75E1C4013A1116C5C4E4A40D5A35F11B27A184013A1116C5C4E4A40'::geometry,
geom)
Planning Time: 0.232 ms
Execution Time: 0.208 ms
(8 rows)
}}}
--
Ticket URL: <https://trac.osgeo.org/postgis/ticket/5984#comment:2>
PostGIS <http://trac.osgeo.org/postgis/>
The PostGIS Trac is used for bug, enhancement & task tracking, a user and developer wiki, and a view into the subversion code repository of PostGIS project.
More information about the postgis-tickets
mailing list