| From: | Andreas Kretschmer <akretschmer(at)spamfence(dot)net> | 
|---|---|
| To: | pgsql-performance(at)postgresql(dot)org | 
| Subject: | Re: Using index for IS NULL query | 
| Date: | 2008-11-11 20:47:03 | 
| Message-ID: | 20081111204703.GA15745@tux | 
| Views: | Whole Thread | Raw Message | Download mbox | Resend email | 
| Thread: | |
| Lists: | pgsql-performance | 
Andrus <kobruleht2(at)hot(dot)ee> schrieb:
> Index is not used for
>
> is null
>
> condition:
>
> create index  makse_dokumnr_idx on makse(dokumnr);
> explain select
>     sum( summa)
>   from MAKSE
>   where  dokumnr is null
>
> "Aggregate  (cost=131927.95..131927.96 rows=1 width=10)"
> "  ->  Seq Scan on makse  (cost=0.00..131927.94 rows=1 width=10)"
> "        Filter: (dokumnr IS NULL)"
>
>
>
> Table makse contains 1200000 rows and about 800 rows with dokumnr is null 
> so using index is much faster that seq scan.
> How to fix ?
Create a partial index like below:
test=# create table foo ( i float);
CREATE TABLE
Zeit: 1,138 ms
test=*# insert into foo select random() from generate_series(1,1000000);
INSERT 0 1000000
test=*# insert into foo values (NULL);
INSERT 0 1
test=*# create index idx_foo on foo(i) where i is null;
CREATE INDEX
test=*# explain analyse select * from foo where i is null;
                                                    QUERY PLAN
-------------------------------------------------------------------------------------------------------------------
 Bitmap Heap Scan on foo  (cost=5.51..4690.89 rows=5000 width=8) (actual
time=0.037..0.038 rows=1 loops=1)
   Recheck Cond: (i IS NULL)
   ->  Bitmap Index Scan on idx_foo  (cost=0.00..4.26 rows=5000 width=0)
(actual time=0.033..0.033 rows=1 loops=1)
         Index Cond: (i IS NULL)
 Total runtime: 0.068 ms
(5 Zeilen)
Maybe there are other solutions...
Andreas
-- 
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect.                              (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly."   (unknown)
Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°
| From | Date | Subject | |
|---|---|---|---|
| Next Message | Andreas Kretschmer | 2008-11-11 20:50:49 | Re: Using index for IS NULL query | 
| Previous Message | Tom Lane | 2008-11-11 20:45:15 | Re: Using index for IS NULL query |