Skip site navigation (1) Skip section navigation (2)

Re: Need indexes on inherited tables?

From: Franco Bruno Borghesi <franco(at)akyasociados(dot)com(dot)ar>
To: Phil Endecott <spam_from_postgresql_sql(at)chezphil(dot)org>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Need indexes on inherited tables?
Date: 2004-06-26 21:06:20
Message-ID: 1088283980.1215.19.camel@taz.oficina (view raw or flat)
Thread:
Lists: pgsql-sql
Table T is not inheriting any indexes, neither the primary key
constraint. That means that the search is going to use an index scan on
table B and a sequential scan on table T (unless of course you add a
primary key constraint or an index on table T).

You can check this things doing: 
->SET enable_seqscan TO off;
->EXPLAIN SELECT * FROM B WHERE id=5; 
you'll see an index scan on table B and sequential scans on the other
tables.

Doing:
->SELECT C.relname AS table_name, C2.relname AS index_name FROM pg_index
I LEFT JOIN pg_class C ON (I.indrelid=C.oid) LEFT JOIN pg_class C2 ON
(C2.oid=I.indexrelid) WHERE  C.relname ILIKE '<table_name>'

you can find out what indexes are available for table_name (or \d
<table_name> in psql).


On Sat, 2004-06-26 at 16:29, Phil Endecott wrote:

> Dear Postgresql experts,
> 
> I have a base table that declares a primary key spanning a couple of columns:
> 
> create table B (
>   id integer,
>   xx someothertype,
>   .....
>   primary key (id, xx)
> );
> 
> and a number of derived tables that inherit from B:
> 
> create table T (
>  ....
> ) inherits (B);
> 
> An index is automatically created for B because of the primary key.
> 
> If I search for something in T using the key columns, e.g. I do
> 
>   select * from T where id=1 and xx=something;
> 
> will the index be used?  Or must I explicity create an index on id and xx for T and each of the other derived tables?
> 
> Is it any different if I search in B and find rows that are actually in T?
> 
> (Slightly unrelated: does the index on (id,xx) help when I am searching only on id?)
> 
> Thanks for any insight anyone can offer.
> 
> --Phil.
> 
> ---------------------------(end of broadcast)---------------------------
> TIP 7: don't forget to increase your free space map settings
> 

In response to

Responses

pgsql-sql by date

Next:From: Phil EndecottDate: 2004-06-26 22:30:26
Subject: Re: Need indexes on inherited tables?
Previous:From: Phil EndecottDate: 2004-06-26 19:29:19
Subject: Need indexes on inherited tables?

Privacy Policy | About PostgreSQL
Copyright © 1996-2014 The PostgreSQL Global Development Group