Re: Composite Index Structure

Lists: pgsql-hackers
From: Nick Raj <nickrajjain(at)gmail(dot)com>
To: pgsql-hackers(at)postgresql(dot)org
Subject: Composite Index Structure
Date: 2011-03-07 06:07:02
Message-ID: AANLkTimR7JWGAbfSiD+u_M1iDSo=O3reAyGD_0QsnNPC@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers

Hi all,

I want to construct an "Composite Index Structure" i.e. a combination of
gist and btree.
What i am thinking is that first creating a Rtree structure that is pointing
to another Btree structure.
For example, Suppose i want to find vehicles between 2 to 4 pm on 14/2/2011
on X road.

I am thinking of creating rtree structure for road network and then btree
for time. For reaching X road i use Rtree, and from there btree begin i.e.
leaf node of rtree contains the pointer to root node of btree ( in this way
i have all time belonging to X road)

My question is that how to implement this composite index structure in
postgres?

Let us suppose, if i create mygist index, then i have to write my own
operator class?
or
can i use gist index as it is and btree tree as it is. I mean their operator
class and their gist methods but how to establish linkage between them?

Any idea ??

Thanks
Raj


From: Heikki Linnakangas <heikki(dot)linnakangas(at)enterprisedb(dot)com>
To: Nick Raj <nickrajjain(at)gmail(dot)com>
Cc: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Composite Index Structure
Date: 2011-03-07 07:03:19
Message-ID: 4D748337.6030700@enterprisedb.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers

On 07.03.2011 08:07, Nick Raj wrote:
> I want to construct an "Composite Index Structure" i.e. a combination of
> gist and btree.
> What i am thinking is that first creating a Rtree structure that is pointing
> to another Btree structure.
> For example, Suppose i want to find vehicles between 2 to 4 pm on 14/2/2011
> on X road.
>
> I am thinking of creating rtree structure for road network and then btree
> for time. For reaching X road i use Rtree, and from there btree begin i.e.
> leaf node of rtree contains the pointer to root node of btree ( in this way
> i have all time belonging to X road)
>
> My question is that how to implement this composite index structure in
> postgres?
>
> Let us suppose, if i create mygist index, then i have to write my own
> operator class?
> or
> can i use gist index as it is and btree tree as it is. I mean their operator
> class and their gist methods but how to establish linkage between them?

It sounds like a use case for a multi-column gist index. See btree_gist
contrib module. You'll want something like:

CREATE INDEX ... USING gist (coordinates, time)

--
Heikki Linnakangas
EnterpriseDB http://www.enterprisedb.com


From: Nick Raj <nickrajjain(at)gmail(dot)com>
To: Heikki Linnakangas <heikki(dot)linnakangas(at)enterprisedb(dot)com>
Cc: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Composite Index Structure
Date: 2011-03-07 09:11:25
Message-ID: AANLkTik6dEAtugc0SO3JvssZSFrfmo9+gHkhy52aK7B=@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers

Hi,

Thanks for your suggestion, Heikki. Btree_gist module provides Gist
implementation for various different data types, equivalent to btree.
Correct me if i wrong?
create index ..... using gist (coordinates,time). It will create index on
both but i think there would be no linkage between them.
But i want linkage between location and time tree. I want for each location
i have Btree like

Rtree root
/ \
non-leaf .......
/ \ \
leaf ...... leaf
| |
Btree root Btree root
/ \ / \
non-leaf
/
leaf

How to create this kind of structure?
What are the modification is required for this?

Thanks
Raj
On Mon, Mar 7, 2011 at 12:33 PM, Heikki Linnakangas <
heikki(dot)linnakangas(at)enterprisedb(dot)com> wrote:

> On 07.03.2011 08:07, Nick Raj wrote:
>
>> I want to construct an "Composite Index Structure" i.e. a combination of
>> gist and btree.
>> What i am thinking is that first creating a Rtree structure that is
>> pointing
>> to another Btree structure.
>> For example, Suppose i want to find vehicles between 2 to 4 pm on
>> 14/2/2011
>> on X road.
>>
>> I am thinking of creating rtree structure for road network and then btree
>> for time. For reaching X road i use Rtree, and from there btree begin i.e.
>> leaf node of rtree contains the pointer to root node of btree ( in this
>> way
>> i have all time belonging to X road)
>>
>> My question is that how to implement this composite index structure in
>> postgres?
>>
>> Let us suppose, if i create mygist index, then i have to write my own
>> operator class?
>> or
>> can i use gist index as it is and btree tree as it is. I mean their
>> operator
>> class and their gist methods but how to establish linkage between them?
>>
>
> It sounds like a use case for a multi-column gist index. See btree_gist
> contrib module. You'll want something like:
>
> CREATE INDEX ... USING gist (coordinates, time)
>
> --
> Heikki Linnakangas
> EnterpriseDB http://www.enterprisedb.com
>


From: Heikki Linnakangas <heikki(dot)linnakangas(at)enterprisedb(dot)com>
To: Nick Raj <nickrajjain(at)gmail(dot)com>
Cc: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Composite Index Structure
Date: 2011-03-07 09:31:22
Message-ID: 4D74A5EA.7090204@enterprisedb.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers

On 07.03.2011 11:11, Nick Raj wrote:
> create index ..... using gist (coordinates,time). It will create index on
> both but i think there would be no linkage between them.
> But i want linkage between location and time tree. I want for each location
> i have Btree like
>
> Rtree root
> / \
> non-leaf .......
> / \ \
> leaf ...... leaf
> | |
> Btree root Btree root
> / \ / \
> non-leaf
> /
> leaf
>
> How to create this kind of structure?

A multi-column index is quite similar to that, you should get the same
performance characteristics. The leading column will determine the
primary order of the tree, and for rows that have the same value in the
leading column, the second column will determine the order among them.

--
Heikki Linnakangas
EnterpriseDB http://www.enterprisedb.com