Re: Planner does not use btree index for LIKE 'prefix%' on text column, but does for equivalent range query (PostgreSQL 17.4)

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Abdullah DURSUN <adursuns(at)gmail(dot)com>
Cc: pgsql-bugs(at)lists(dot)postgresql(dot)org
Subject: Re: Planner does not use btree index for LIKE 'prefix%' on text column, but does for equivalent range query (PostgreSQL 17.4)
Date: 2025-05-03 20:04:14
Message-ID: 2202693.1746302654@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-bugs

Abdullah DURSUN <adursuns(at)gmail(dot)com> writes:
> A btree index on a text column is not used for a query of the form WHERE
> col LIKE 'prefix%', even though the index is healthy, statistics are
> correct, and the query is highly selective.

LIKE with a prefix condition can only use an index if the index's
collation is "C", or if it uses the "pattern" opclass. This isn't
new in v17, it's been true for a very long time.

d1=# create table foo (t text);
CREATE TABLE
d1=# create index on foo (t);
CREATE INDEX
d1=# explain select * from foo where t like 'prefix%';
QUERY PLAN
-----------------------------------------------------
Seq Scan on foo (cost=0.00..27.00 rows=7 width=32)
Filter: (t ~~ 'prefix%'::text)
(2 rows)

d1=# create index on foo (t collate "C");
CREATE INDEX
d1=# explain select * from foo where t like 'prefix%';
QUERY PLAN
-------------------------------------------------------------------------
Bitmap Heap Scan on foo (cost=4.22..14.37 rows=7 width=32)
Filter: (t ~~ 'prefix%'::text)
-> Bitmap Index Scan on foo_t_idx1 (cost=0.00..4.22 rows=7 width=0)
Index Cond: ((t >= 'prefix'::text) AND (t < 'prefiy'::text))
(4 rows)

regards, tom lane

In response to

Browse pgsql-bugs by date

  From Date Subject
Next Message Sergey Koposov 2025-05-03 21:50:04 Re: BUG #18909: Query creates millions of temporary files and stalls
Previous Message Sergey Koposov 2025-05-03 19:20:59 Re: BUG #18909: Query creates millions of temporary files and stalls