Обсуждение: Bidirectional index traversal

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

Bidirectional index traversal

От
Alanoly Andrews
Дата:

Hello,

 

I’d like to know whether Postgres (8.4) supports bidirectional traversal of indexes.

 

Thanks.

 

Alanoly.



This e-mail may be privileged and/or confidential, and the sender does not waive any related rights and obligations. Any distribution, use or copying of this e-mail or the information it contains by other than an intended recipient is unauthorized. If you received this e-mail in error, please advise me (by return e-mail or otherwise) immediately.

Ce courriel est confidentiel et prot�g�. L'exp�diteur ne renonce pas aux droits et obligations qui s'y rapportent. Toute diffusion, utilisation ou copie de ce message ou des renseignements qu'il contient par une personne autre que le (les) destinataire(s) d�sign�(s) est interdite. Si vous recevez ce courriel par erreur, veuillez m'en aviser imm�diatement, par retour de courriel ou par un autre moyen.

Mail sent via the Abaca EPG


Re: Bidirectional index traversal

От
Tom Lane
Дата:
Alanoly Andrews <alanolya@invera.com> writes:
> I'd like to know whether Postgres (8.4) supports bidirectional traversal of indexes.

If you defined exactly what you meant by that, you might get useful
answers.  There are some features in there that might be what you mean,
or then again maybe not.

            regards, tom lane

Re: Bidirectional index traversal

От
Alanoly Andrews
Дата:
To expand on that question:

Suppose I have a table with the following schema:
     tab1(col1 decimal(3,0), col2 char(3)).
There is an index defined on it as : create index tab1ind1 on tab1(col1)

Now, if I have a query as: "select * from tab1 order by col1", I expect the Optimizer to use the index tab1ind1. But if
Ihave a query like: "select * from tab1 order by col1 desc", does the Postgres Optimizer use the same index as above
(butin the reverse direction) or does it need to a full table scan and then sort values in col1 in the descending
order?If the former, then there is bidirectional index traversal. That example was for a numeric field. What about
character,date and timestamp fields? Does bidirectional index traversal exist, or do we need to create a second index
tohandle such cases? 

Alanoly.

-----Original Message-----
From: Tom Lane [mailto:tgl@sss.pgh.pa.us]
Sent: Thursday, September 16, 2010 10:57 AM
To: Alanoly Andrews
Cc: 'pgsql-admin@postgresql.org'
Subject: Re: [ADMIN] Bidirectional index traversal

Alanoly Andrews <alanolya@invera.com> writes:
> I'd like to know whether Postgres (8.4) supports bidirectional traversal of indexes.

If you defined exactly what you meant by that, you might get useful
answers.  There are some features in there that might be what you mean,
or then again maybe not.

            regards, tom lane
****************************************************
This e-mail may be privileged and/or confidential, and the sender does not waive any related rights and obligations.
Anydistribution, use or copying of this e-mail or the information it contains by other than an intended recipient is
unauthorized.If you received this e-mail in error, please advise me (by return e-mail or otherwise) immediately. 

Ce courriel est confidentiel et prot�g�. L'exp�diteur ne renonce pas aux droits et obligations qui s'y rapportent.
Toutediffusion, utilisation ou copie de ce message ou des renseignements qu'il contient par une personne autre que le
(les)destinataire(s) d�sign�(s) est interdite. Si vous recevez ce courriel par erreur, veuillez m'en aviser
imm�diatement,par retour de courriel ou par un autre moyen. 
****************************************************


Re: Bidirectional index traversal

От
Tom Lane
Дата:
Alanoly Andrews <alanolya@invera.com> writes:
> To expand on that question:
> Suppose I have a table with the following schema:
>      tab1(col1 decimal(3,0), col2 char(3)).
> There is an index defined on it as : create index tab1ind1 on tab1(col1)

> Now, if I have a query as: "select * from tab1 order by col1", I
> expect the Optimizer to use the index tab1ind1. But if I have a query
> like: "select * from tab1 order by col1 desc", does the Postgres
> Optimizer use the same index as above (but in the reverse direction)

Yes, it will, as you could easily find by reading the manual:
http://www.postgresql.org/docs/8.4/static/indexes-ordering.html
or by experimentation:

regression=# create table tab1(col1 decimal(3,0), col2 char(3));
CREATE TABLE
regression=# create index tab1ind1 on tab1(col1);
CREATE INDEX
regression=# explain select * from tab1 order by col1;
                                QUERY PLAN
--------------------------------------------------------------------------
 Index Scan using tab1ind1 on tab1  (cost=0.00..70.20 rows=1730 width=17)
(1 row)

regression=# explain select * from tab1 order by col1 desc;
                                    QUERY PLAN
-----------------------------------------------------------------------------------
 Index Scan Backward using tab1ind1 on tab1  (cost=0.00..70.20 rows=1730 width=17)
(1 row)

(Now, whether the optimizer will prefer an index over seqscan-and-sort
depends on a lot of factors.  But backwards scan isn't a problem.)

            regards, tom lane

issue pgsql_tmp keeps increasing

От
donghe@caltech.edu
Дата:
Hi,

I use psql (PostgreSQL) 8.1.10 on my box, there is a postmater process
running automatically to make temp files in pgsql_tmp folder, I don't do
any query on my database. Anybody knows what's wrong with it? and how to
find what the postmater process is for

Thanks

Dong He




Re: issue pgsql_tmp keeps increasing

От
Tom Lane
Дата:
donghe@caltech.edu writes:
> I use psql (PostgreSQL) 8.1.10 on my box, there is a postmater process
> running automatically to make temp files in pgsql_tmp folder, I don't do
> any query on my database. Anybody knows what's wrong with it? and how to
> find what the postmater process is for

Look in pg_stat_activity, perhaps.  In 8.1 that won't show you the
actual command unless you changed some default settings, but it should
at least tell you when the command was started and by whom.

            regards, tom lane