Thread: Created Index is not used

Created Index is not used

From
Kjeld Peters
Date:
Select and update statements are quite slow on a large table with more
than 600,000 rows. The table consists of 11 columns (nothing special).
The column "id" (int8) is primary key and has a btree index on it.

The following select statement takes nearly 500ms:

SELECT * FROM table WHERE id = 600000;

A prepending "EXPLAIN" to the statement reveals a seq scan:

EXPLAIN SELECT * FROM table WHERE id = 600000;

"Seq Scan on table  (cost=0.00..15946.48 rows=2 width=74)"
"  Filter: (id = 600000)"

I tried a full vacuum and a reindex, but had no effect. Why is
PostgreSQL not using the created index?

Or is there any other way to improve performance on this query?

The PostgreSQL installation is an out of the box installation with no
further optimization. The server is running SUSE Linux 9.1, kernel
2.6.4-52-smp. (Quad Xeon 2.8GHz, 1GB RAM)

SELECT version();
"PostgreSQL 7.4.2 on i686-pc-linux-gnu, compiled by GCC gcc (GCC) 3.3.3
(SuSE Linux)"


Thanks for any hints,
Kjeld

Re: Created Index is not used

From
Ragnar
Date:
On fim, 2006-02-23 at 13:35 +0100, Kjeld Peters wrote:
> Select and update statements are quite slow on a large table with more
> than 600,000 rows. The table consists of 11 columns (nothing special).
> The column "id" (int8) is primary key and has a btree index on it.
>
> The following select statement takes nearly 500ms:
>
> SELECT * FROM table WHERE id = 600000;
>
> A prepending "EXPLAIN" to the statement reveals a seq scan:
>
> EXPLAIN SELECT * FROM table WHERE id = 600000;
>
> "Seq Scan on table  (cost=0.00..15946.48 rows=2 width=74)"
> "  Filter: (id = 600000)"

> I tried a full vacuum and a reindex, but had no effect. Why is
> PostgreSQL not using the created index?

try one of:

SELECT * FROM table WHERE id = '600000';
SELECT * FROM table WHERE id = 600000::int8;
PostgreSQL 8+

gnari




Re: Created Index is not used

From
Markus Schaber
Date:
Hi, Kjeld,

Kjeld Peters wrote:
> Select and update statements are quite slow on a large table with more
> than 600,000 rows. The table consists of 11 columns (nothing special).
> The column "id" (int8) is primary key and has a btree index on it.
>
> The following select statement takes nearly 500ms:
>
> SELECT * FROM table WHERE id = 600000;

Known issue which is fixed in 8.X servers, postgreSQL sees your 600000
as int4 literal and does not grasp that the int8 index works for it.

SELECT * FROM table WHERE id = 600000::int8;

should do it.

> SELECT version();
> "PostgreSQL 7.4.2 on i686-pc-linux-gnu, compiled by GCC gcc (GCC) 3.3.3
> (SuSE Linux)"

Btw, you should update to 7.4.12, there are importand bug fixes and it
is upgradable "in place", without dumping and reloading the database.

HTH,
Markus

--
Markus Schaber | Logical Tracking&Tracing International AG
Dipl. Inf.     | Software Development GIS

Fight against software patents in EU! www.ffii.org www.nosoftwarepatents.org

Re: Created Index is not used

From
Kjeld Peters
Date:
Hi Markus,

first of all thanks for your quick reply!

Markus Schaber wrote:
> Kjeld Peters wrote:
>>Select and update statements are quite slow on a large table with more
>>than 600,000 rows. The table consists of 11 columns (nothing special).
>>The column "id" (int8) is primary key and has a btree index on it.
>>
>>The following select statement takes nearly 500ms:
>>
>>SELECT * FROM table WHERE id = 600000;
>
>
> Known issue which is fixed in 8.X servers, postgreSQL sees your 600000
> as int4 literal and does not grasp that the int8 index works for it.
>
> SELECT * FROM table WHERE id = 600000::int8;
>
> should do it.

After I appended "::int8" to the query, selecting the table takes only
40-50ms. That's a great performance boost!

> Btw, you should update to 7.4.12, there are importand bug fixes and it
> is upgradable "in place", without dumping and reloading the database.

I guess I'll test an upgrade to version 8.1.

Thanks again for your and Ragnar's help!

Kjeld