Обсуждение: Why index used/not used

Поиск
Список
Период
Сортировка

Why index used/not used

От
Anton Maksimenkov
Дата:
Hello.

Explain.
  I have table "traf_raw" contains field "sip_id" (integer). This field
indexed with "CREATE INDEX traf_raw_sip ON traf_raw (sip_id)".

Question.
  When I try to get different rows postgres use index with one "sip_id"
and not use index with another "sip_id". I don't understand why it is
happen, but with more complex queries Seq Scan is so slowly.

Example.
  With "sip_id='19'" there many rows in table, with "sip_id='29'" there
is no rows.

cnupm=> ANALYZE traf_raw;
ANALYZE
cnupm=> EXPLAIN ANALYZE SELECT * FROM traf_raw WHERE sip_id='19' LIMIT
10 OFFSET 100000;
                                                      QUERY PLAN

---------------------------------------------------------------------------------------------------------------------
  Limit  (cost=5230.95..5230.99 rows=1 width=56) (actual
time=2505.89..2505.89 rows=0 loops=1)
    ->  Seq Scan on traf_raw  (cost=0.00..5230.99 rows=10808 width=56)
(actual time=0.04..2490.02 rows=10977 loops=1)
          Filter: (sip_id = 19)
  Total runtime: 2505.95 msec
(4 rows)

cnupm=> EXPLAIN ANALYZE SELECT * FROM traf_raw WHERE sip_id='29' LIMIT
10 OFFSET 100000;
                                                            QUERY PLAN


---------------------------------------------------------------------------------------------------------------------------------
  Limit  (cost=391.39..392.70 rows=1 width=56) (actual time=43.08..43.08
rows=0 loops=1)
    ->  Index Scan using traf_raw_sip on traf_raw  (cost=0.00..392.70
rows=99 width=56) (actual time=43.07..43.07 rows=0 loops=1)
          Index Cond: (sip_id = 29)
  Total runtime: 43.16 msec
(4 rows)

--
engineer

Re: Why index used/not used

От
Mike G
Дата:
hello,

Try reading through the pgsql-performance mailing list.  Generally the database needs to be vacuumed and analyzed to
updatethe stats usually for the planner to make the correct choices. 

Mike

On Wed, Jul 21, 2004 at 11:00:06AM +0600, Anton Maksimenkov wrote:
>  Hello.
>
> Explain.
>  I have table "traf_raw" contains field "sip_id" (integer). This field
> indexed with "CREATE INDEX traf_raw_sip ON traf_raw (sip_id)".
>
> Question.
>  When I try to get different rows postgres use index with one "sip_id"
> and not use index with another "sip_id". I don't understand why it is
> happen, but with more complex queries Seq Scan is so slowly.
>
> Example.
>  With "sip_id='19'" there many rows in table, with "sip_id='29'" there
> is no rows.
>
> cnupm=> ANALYZE traf_raw;
> ANALYZE
> cnupm=> EXPLAIN ANALYZE SELECT * FROM traf_raw WHERE sip_id='19' LIMIT
> 10 OFFSET 100000;
>                                                      QUERY PLAN
>
> ---------------------------------------------------------------------------------------------------------------------
>  Limit  (cost=5230.95..5230.99 rows=1 width=56) (actual
> time=2505.89..2505.89 rows=0 loops=1)
>    ->  Seq Scan on traf_raw  (cost=0.00..5230.99 rows=10808 width=56)
> (actual time=0.04..2490.02 rows=10977 loops=1)
>          Filter: (sip_id = 19)
>  Total runtime: 2505.95 msec
> (4 rows)
>
> cnupm=> EXPLAIN ANALYZE SELECT * FROM traf_raw WHERE sip_id='29' LIMIT
> 10 OFFSET 100000;
>                                                            QUERY PLAN
>
>
---------------------------------------------------------------------------------------------------------------------------------
>  Limit  (cost=391.39..392.70 rows=1 width=56) (actual time=43.08..43.08
> rows=0 loops=1)
>    ->  Index Scan using traf_raw_sip on traf_raw  (cost=0.00..392.70
> rows=99 width=56) (actual time=43.07..43.07 rows=0 loops=1)
>          Index Cond: (sip_id = 29)
>  Total runtime: 43.16 msec
> (4 rows)
>
> --
> engineer
>
> ---------------------------(end of broadcast)---------------------------
> TIP 9: the planner will ignore your desire to choose an index scan if your
>      joining column's datatypes do not match

Re: Why index used/not used

От
Anton Maksimenkov
Дата:
Mike G wrote:

> Try reading through the pgsql-performance mailing list.  Generally the database needs to be vacuumed and analyzed to
updatethe stats usually for the planner to make the correct choices. 

  Of course, I do VACUUM FULL ANALYZE some times, VACUUM ANALYZE
periodicaly.
  But I don't change "traf_raw" some hours, and imagine that ANALYZE may
be enough for this examle.

>>cnupm=> ANALYZE traf_raw;
>>ANALYZE
--
engineer


Re: Why index used/not used

От
"Scott Marlowe"
Дата:
On Tue, 2004-07-20 at 23:00, Anton Maksimenkov wrote:
>   Hello.
>
> Explain.
>   I have table "traf_raw" contains field "sip_id" (integer). This field
> indexed with "CREATE INDEX traf_raw_sip ON traf_raw (sip_id)".
>
> Question.
>   When I try to get different rows postgres use index with one "sip_id"
> and not use index with another "sip_id". I don't understand why it is
> happen, but with more complex queries Seq Scan is so slowly.
>
> Example.
>   With "sip_id='19'" there many rows in table, with "sip_id='29'" there
> is no rows.
>
> cnupm=> ANALYZE traf_raw;
> ANALYZE
> cnupm=> EXPLAIN ANALYZE SELECT * FROM traf_raw WHERE sip_id='19' LIMIT
> 10 OFFSET 100000;
>                                                       QUERY PLAN
>
> ---------------------------------------------------------------------------------------------------------------------
>   Limit  (cost=5230.95..5230.99 rows=1 width=56) (actual
> time=2505.89..2505.89 rows=0 loops=1)
>     ->  Seq Scan on traf_raw  (cost=0.00..5230.99 rows=10808 width=56)
> (actual time=0.04..2490.02 rows=10977 loops=1)
>           Filter: (sip_id = 19)
>   Total runtime: 2505.95 msec
> (4 rows)

Note that in this instance, your query is returning >10k rows.
While in this example:

> cnupm=> EXPLAIN ANALYZE SELECT * FROM traf_raw WHERE sip_id='29' LIMIT
> 10 OFFSET 100000;
>                                                             QUERY PLAN
>
>
---------------------------------------------------------------------------------------------------------------------------------
>   Limit  (cost=391.39..392.70 rows=1 width=56) (actual time=43.08..43.08
> rows=0 loops=1)
>     ->  Index Scan using traf_raw_sip on traf_raw  (cost=0.00..392.70
> rows=99 width=56) (actual time=43.07..43.07 rows=0 loops=1)
>           Index Cond: (sip_id = 29)
>   Total runtime: 43.16 msec
> (4 rows)

you are only returning 0 rows.

PostgreSQL uses a cost based planner.  So, in the first instance, it
thought it was returning enough rows to justify grabbing all the rows
first.

There are several settings that tune the planner to tell it when to
switch from an index scan to a seq scan.  random_page_cost is the most
commonly adusted one.  Try dropping it from the default of 4 to
something around 1.4 to 2.0 or so.

Also, you can force the planner to not use seq scans unless it has to by
setting enable_seqscan to off:

set enable_seqscan = off;

and run the query again.  Test several of your queries and find out
where the turning point is, and then adjust the random_page_cost to
cause it to switch at about the right time.


Re: Why index used/not used

От
Anton Maksimenkov
Дата:
Scott Marlowe wrote:

> There are several settings that tune the planner to tell it when to
> switch from an index scan to a seq scan.  random_page_cost is the most
> commonly adusted one.  Try dropping it from the default of 4 to
> something around 1.4 to 2.0 or so.
...
> and run the query again.  Test several of your queries and find out
> where the turning point is, and then adjust the random_page_cost to
> cause it to switch at about the right time.

  Thank's for explain. With "random_page_cost = 2.0" situation is much
better. I will follow you tips.

EXPLAIN ANALYZE SELECT * FROM traf_raw WHERE sip_id='19' LIMIT 10 OFFSET
100000;
...
  Limit  (cost=5042.22..5042.56 rows=1 width=56) (actual
time=110.32..110.32 rows=0 loops=1)
    ->  Index Scan using traf_raw_sip on traf_raw  (cost=0.00..5042.56
rows=11020 width=56) (actual time=0.30..95.95 rows=10977 loops=1)
          Index Cond: (sip_id = 19)
  Total runtime: 110.52 msec

--
engineer