Re: Query taking seq scan on a table

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Shrikant Bhende <shrikantpostgresql(at)gmail(dot)com>
Cc: Jeff Janes <jeff(dot)janes(at)gmail(dot)com>, Avinash Kumar <avinash(dot)vallarapu(at)gmail(dot)com>, dbatoCloud Solution <dbatocloud17(at)gmail(dot)com>, pgsql-admin(at)lists(dot)postgresql(dot)org
Subject: Re: Query taking seq scan on a table
Date: 2020-09-22 14:07:26
Message-ID: 1176451.1600783646@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

Shrikant Bhende <shrikantpostgresql(at)gmail(dot)com> writes:
> *create index concurrently lname_test_btree_txt_pat_ops on wldbowner.member
> (lname text_pattern_ops) where fname like LOWER(unaccent_string(lname) ||
> '%')*
> Is this the correct way to create a b-tree index with text_pattern_ops for
> my requirement ?

No. What you're trying to optimize is

Filter: ((lower(unaccent_string((lname)::text))
~~ 'info%'::text) AND (lower(unaccent_string((fname)::text)) ~~
'travel%'::text))

so you need one or both of

create index on member (lower(unaccent_string(lname)) text_pattern_ops);
create index on member (lower(unaccent_string(fname)) text_pattern_ops);

If one of those two conditions is reliably more selective than the
other, perhaps just one index would do.

regards, tom lane

In response to

Responses

Browse pgsql-admin by date

  From Date Subject
Next Message MUKESH PRASAD 2020-09-22 14:07:40 Re: The default database account can be accessed without a password
Previous Message Geoff Winkless 2020-09-22 13:40:42 Re: The default database account can be accessed without a password