Re: is it normal behavior of index? - Mailing list pgsql-novice
From | Jean-Yves F. Barbier |
---|---|
Subject | Re: is it normal behavior of index? |
Date | |
Msg-id | 20120101134437.705a98cb@anubis.defcon1 Whole thread Raw |
In response to | Re: is it normal behavior of index? (Andreas Kretschmer <akretschmer@spamfence.net>) |
Responses |
Re: is it normal behavior of index?
|
List | pgsql-novice |
On Sun, 1 Jan 2012 12:52:04 +0100 Andreas Kretschmer <akretschmer@spamfence.net> wrote: > > Simple test table w/ a varchar(32): if I create an index with > > 'varchar_pattern_ops' explain says it is NOT used in my query; > > if I create it without it is used (?!) > > Please show more details and/or an example. I have one for you: > > test=# create table words ( w text); > CREATE TABLE > Time: 5,829 ms > test=*# copy words from '/usr/share/dict/ngerman'; > COPY 320577 > Time: 458,902 ms > test=*# create index idx_words on words (w varchar_pattern_ops); > CREATE INDEX > Time: 1270,534 ms > test=*# explain select * from words where w = 'foo'; > QUERY PLAN > ---------------------------------------------------------------------------- > Bitmap Heap Scan on words (cost=36.72..1781.30 rows=1603 width=32) > Recheck Cond: (w = 'foo'::text) > -> Bitmap Index Scan on idx_words (cost=0.00..36.32 rows=1603 width=0) > Index Cond: (w = 'foo'::text) > (4 rows) > > Time: 0,467 ms > > > > As you can see, there is an index WITH varchar_pattern_ops, and the > index used for the query. Yep, I HAD this behavior with my prior test version (nothing has changed: I just droped/recreated it) but not anymore: Table "public.tst1m" Column | Type | Modifiers | Storage | Description --------+-----------------------+----------------------------------------------------+----------+------------- id | integer | not null default nextval('tst1m_id_seq'::regclass) | plain | name | character varying(32) | not null | extended | note | character varying(64) | not null | extended | Indexes: "tst1m_pkey" PRIMARY KEY, btree (id) "tst1m_name_ix" UNIQUE, btree (name) "tst1m_name_lmetaphone_ix" btree (lower(metaphone(name::text, 16)) varchar_pattern_ops) "tst1m_name_lu_ix" btree (lower(jyunaccent(name)::text) text_pattern_ops) "tst1m_note_ix" btree (note varchar_pattern_ops) "tst1m_note_lu_ix" btree (note) Has OIDs: no CREATE INDEX tst1m_name_regular_ix ON tst1m(name varchar_pattern_ops); EXPLAIN SELECT * FROM tst1m ORDER BY name; QUERY PLAN --------------------------------------------------------------------- Sort (cost=25402.82..25652.82 rows=100000 width=138) Sort Key: name -> Seq Scan on tst1m (cost=0.00..3084.00 rows=100000 width=138) (3 rows) JY -- Kiss me, Kate, we will be married o' Sunday. -- William Shakespeare, "The Taming of the Shrew"
pgsql-novice by date: