Re: index not used?

Lists: pgsql-general
From: Dan Pelleg <daniel+pgsql(at)pelleg(dot)org>
To: pgsql-general(at)postgresql(dot)org
Subject: index not used?
Date: 2004-10-20 14:06:09
Message-ID: 16758.28881.684597.807409@lark.auton.cs.cmu.edu
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general


I'm trying to access a table with about 120M rows. It's a vertical version
of a table with 360 or so columns. The new columns are: original item col,
original item row, and the value.

I created an index:

CREATE INDEX idx on table (col, row)

however, selects are still very slow. It seems it still needs a sequential
scan:

EXPLAIN SELECT * FROM table WHERE col=1 AND row=10;
QUERY PLAN
------------------------------------------------------------------------------
Seq Scan on table (cost=100000000.00..102612533.00 rows=1 width=14)
Filter: ((col = 1) AND ("row" = 10))

What am I doing wrong?

--
Dan Pelleg


From: "Scott Marlowe" <smarlowe(at)qwest(dot)net>
To: "Dan Pelleg" <daniel+pgsql(at)pelleg(dot)org>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: index not used?
Date: 2004-10-20 15:44:06
Message-ID: 1098287046.21035.45.camel@localhost.localdomain
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

On Wed, 2004-10-20 at 08:06, Dan Pelleg wrote:
> I'm trying to access a table with about 120M rows. It's a vertical version
> of a table with 360 or so columns. The new columns are: original item col,
> original item row, and the value.
>
> I created an index:
>
> CREATE INDEX idx on table (col, row)
>
> however, selects are still very slow. It seems it still needs a sequential
> scan:
>
> EXPLAIN SELECT * FROM table WHERE col=1 AND row=10;
> QUERY PLAN
> ------------------------------------------------------------------------------
> Seq Scan on table (cost=100000000.00..102612533.00 rows=1 width=14)
> Filter: ((col = 1) AND ("row" = 10))
>
> What am I doing wrong?

What type are row and col? If they're bigint (i.e. not int / int4) then
you might need to quote the value to get the query to use an index:

SELECT * FROM table WHERE col='1' AND row='10';

also, have you vacuumed / analyzed the table? I'm assuming yes.


From: Dan Pelleg <daniel+pgsql(at)pelleg(dot)org>
To: Scott Marlowe <smarlowe(at)qwest(dot)net>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: index not used?
Date: 2004-10-20 15:45:26
Message-ID: 16758.34838.167915.510242@lark.auton.cs.cmu.edu
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Scott Marlowe writes:
> On Wed, 2004-10-20 at 08:06, Dan Pelleg wrote:
> > I'm trying to access a table with about 120M rows. It's a vertical version
> > of a table with 360 or so columns. The new columns are: original item col,
> > original item row, and the value.
> >
> > I created an index:
> >
> > CREATE INDEX idx on table (col, row)
> >
> > however, selects are still very slow. It seems it still needs a sequential
> > scan:
> >
> > EXPLAIN SELECT * FROM table WHERE col=1 AND row=10;
> > QUERY PLAN
> > ------------------------------------------------------------------------------
> > Seq Scan on table (cost=100000000.00..102612533.00 rows=1 width=14)
> > Filter: ((col = 1) AND ("row" = 10))
> >
> > What am I doing wrong?
>
> What type are row and col? If they're bigint (i.e. not int / int4) then
> you might need to quote the value to get the query to use an index:
>
> SELECT * FROM table WHERE col='1' AND row='10';
>
> also, have you vacuumed / analyzed the table? I'm assuming yes.

They're not bigints:

CREATE TABLE table (col int2, row integer, val double precision)

Yes, I vacuumed and analyzed, right after creating the index. Should I try
and issue a few queries beforehand?

--Dan


From: "Scott Marlowe" <smarlowe(at)qwest(dot)net>
To: "Dan Pelleg" <daniel+pgsql(at)pelleg(dot)org>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: index not used?
Date: 2004-10-20 15:55:27
Message-ID: 1098287727.21035.56.camel@localhost.localdomain
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

On Wed, 2004-10-20 at 09:45, Dan Pelleg wrote:
> Scott Marlowe writes:
> > On Wed, 2004-10-20 at 08:06, Dan Pelleg wrote:
> > > I'm trying to access a table with about 120M rows. It's a vertical version
> > > of a table with 360 or so columns. The new columns are: original item col,
> > > original item row, and the value.
> > >
> > > I created an index:
> > >
> > > CREATE INDEX idx on table (col, row)
> > >
> > > however, selects are still very slow. It seems it still needs a sequential
> > > scan:
> > >
> > > EXPLAIN SELECT * FROM table WHERE col=1 AND row=10;
> > > QUERY PLAN
> > > ------------------------------------------------------------------------------
> > > Seq Scan on table (cost=100000000.00..102612533.00 rows=1 width=14)
> > > Filter: ((col = 1) AND ("row" = 10))
> > >
> > > What am I doing wrong?
> >
> > What type are row and col? If they're bigint (i.e. not int / int4) then
> > you might need to quote the value to get the query to use an index:
> >
> > SELECT * FROM table WHERE col='1' AND row='10';
> >
> > also, have you vacuumed / analyzed the table? I'm assuming yes.
>
> They're not bigints:
>
> CREATE TABLE table (col int2, row integer, val double precision)
>
> Yes, I vacuumed and analyzed, right after creating the index. Should I try
> and issue a few queries beforehand?

but one is an int2 (i.e. not int / int4) so you'll need to quote that
value to get an index to work. Note this is fixed in 8.0 I understand.


From: Dan Pelleg <daniel+pgsql(at)pelleg(dot)org>
To: Scott Marlowe <smarlowe(at)qwest(dot)net>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: index not used?
Date: 2004-10-20 16:14:54
Message-ID: 16758.36606.170619.839086@lark.auton.cs.cmu.edu
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Scott Marlowe writes:
> On Wed, 2004-10-20 at 09:45, Dan Pelleg wrote:
> > Scott Marlowe writes:
> > > On Wed, 2004-10-20 at 08:06, Dan Pelleg wrote:
> > > > I'm trying to access a table with about 120M rows. It's a vertical version
> > > > of a table with 360 or so columns. The new columns are: original item col,
> > > > original item row, and the value.
> > > >
> > > > I created an index:
> > > >
> > > > CREATE INDEX idx on table (col, row)
> > > >
> > > > however, selects are still very slow. It seems it still needs a sequential
> > > > scan:
> > > >
> > > > EXPLAIN SELECT * FROM table WHERE col=1 AND row=10;
> > > > QUERY PLAN
> > > > ------------------------------------------------------------------------------
> > > > Seq Scan on table (cost=100000000.00..102612533.00 rows=1 width=14)
> > > > Filter: ((col = 1) AND ("row" = 10))
> > > >
> > > > What am I doing wrong?
> > >
> > > What type are row and col? If they're bigint (i.e. not int / int4) then
> > > you might need to quote the value to get the query to use an index:
> > >
> > > SELECT * FROM table WHERE col='1' AND row='10';
> > >
> > > also, have you vacuumed / analyzed the table? I'm assuming yes.
> >
> > They're not bigints:
> >
> > CREATE TABLE table (col int2, row integer, val double precision)
> >
> > Yes, I vacuumed and analyzed, right after creating the index. Should I try
> > and issue a few queries beforehand?
>
> but one is an int2 (i.e. not int / int4) so you'll need to quote that
> value to get an index to work. Note this is fixed in 8.0 I understand.

Bingo.

=> explain select * from table where col='302' and row =100600400;
QUERY PLAN
---------------------------------------------------------------------
Index Scan using idx2 on table (cost=0.00..5.27 rows=1 width=14)
Index Cond: ((col = 302::smallint) AND ("row" = 100600400))
(2 rows)

=> explain select * from table where col=302 and row =100600400;
QUERY PLAN
------------------------------------------------------------------------
Seq Scan on table (cost=100000000.00..102612533.00 rows=1 width=14)
Filter: ((col = 302) AND ("row" = 100600400))
(2 rows)

Wow, that sure is a big difference for such a small "change" in the
query. Thank you very much!


From: Gaetano Mendola <mendola(at)bigfoot(dot)com>
To: Scott Marlowe <smarlowe(at)qwest(dot)net>
Subject: Re: index not used?
Date: 2004-10-22 23:11:38
Message-ID: 417993AA.6050605@bigfoot.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Scott Marlowe wrote:
> On Wed, 2004-10-20 at 08:06, Dan Pelleg wrote:
>
>>I'm trying to access a table with about 120M rows. It's a vertical version
>>of a table with 360 or so columns. The new columns are: original item col,
>>original item row, and the value.
>>
>>I created an index:
>>
>>CREATE INDEX idx on table (col, row)
>>
>>however, selects are still very slow. It seems it still needs a sequential
>>scan:
>>
>>EXPLAIN SELECT * FROM table WHERE col=1 AND row=10;
>> QUERY PLAN
>>------------------------------------------------------------------------------
>> Seq Scan on table (cost=100000000.00..102612533.00 rows=1 width=14)
>> Filter: ((col = 1) AND ("row" = 10))
>>
>>What am I doing wrong?
>
>
> What type are row and col? If they're bigint (i.e. not int / int4) then
> you might need to quote the value to get the query to use an index:
>
> SELECT * FROM table WHERE col='1' AND row='10';
>
> also, have you vacuumed / analyzed the table? I'm assuming yes.

I assume not, seen that cost...

Regards
Gaetano Mendola


From: Gaetano Mendola <mendola(at)bigfoot(dot)com>
To: Scott Marlowe <smarlowe(at)qwest(dot)net>, pgsql-general <pgsql-general(at)postgresql(dot)org>
Subject: Re: index not used?
Date: 2004-10-23 09:04:08
Message-ID: 417A1E88.7080800@bigfoot.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

-----BEGIN PGP SIGNED MESSAGE-----
Hash: SHA1

Scott Marlowe wrote:
| On Fri, 2004-10-22 at 17:11, Gaetano Mendola wrote:
|
|>Scott Marlowe wrote:
|>
|>>On Wed, 2004-10-20 at 08:06, Dan Pelleg wrote:
|>>
|>>
|>>>I'm trying to access a table with about 120M rows. It's a vertical version
|>>>of a table with 360 or so columns. The new columns are: original item col,
|>>>original item row, and the value.
|>>>
|>>>I created an index:
|>>>
|>>>CREATE INDEX idx on table (col, row)
|>>>
|>>>however, selects are still very slow. It seems it still needs a sequential
|>>>scan:
|>>>
|>>>EXPLAIN SELECT * FROM table WHERE col=1 AND row=10;
|>>> QUERY PLAN
|>>>------------------------------------------------------------------------------
|>>>Seq Scan on table (cost=100000000.00..102612533.00 rows=1 width=14)
|>>> Filter: ((col = 1) AND ("row" = 10))
|>>>
|>>>What am I doing wrong?
|>>
|>>
|>>What type are row and col? If they're bigint (i.e. not int / int4) then
|>>you might need to quote the value to get the query to use an index:
|>>
|>>SELECT * FROM table WHERE col='1' AND row='10';
|>>
|>>also, have you vacuumed / analyzed the table? I'm assuming yes.
|>
|>I assume not, seen that cost...
|>
|
|
| Actually, that cost would likely be caused by set enable_seqscan = off
| wouldn't it?

That's true. This is the second time in these last days that I see someone "tune"
postgres setting enable_seqscan = off.

G.

-----BEGIN PGP SIGNATURE-----
Version: GnuPG v1.2.5 (MingW32)
Comment: Using GnuPG with Thunderbird - http://enigmail.mozdev.org

iD8DBQFBeh6H7UpzwH2SGd4RAvEDAKDdBI6g484jxv4dzdMwXSRwQpJUhgCfU2W7
4hghwH7rJhsC8mRk+Uo/OsU=
=WCBg
-----END PGP SIGNATURE-----