Shrikant Bhende <shrikantpostgresql@xxxxxxxxx> 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