Re: GiST index performance

From: Matthew Wakeling <matthew(at)flymine(dot)org>
To: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: Kevin Grittner <Kevin(dot)Grittner(at)wicourts(dot)gov>, pgsql-performance(at)postgresql(dot)org
Subject: Re: GiST index performance
Date: 2009-04-16 17:54:05
Message-ID: alpine.DEB.2.00.0904161843330.22330@aragorn.flymine.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

On Thu, 16 Apr 2009, Tom Lane wrote:
> Matthew, can you put together a self-contained test case with a similar
> slowdown?

It isn't the smoking gun I thought it would be, but:

CREATE TABLE a AS SELECT a FROM generate_series(1,1000000) AS a(a);
CREATE TABLE b AS SELECT b FROM generate_series(1,1000000) AS b(b);

ANALYSE;

CREATE INDEX a_a ON a (a);

EXPLAIN ANALYSE SELECT * FROM a, b WHERE a.a BETWEEN b.b AND b.b + 2;

DROP INDEX a_a;
CREATE INDEX a_a ON a USING gist (a);

EXPLAIN ANALYSE SELECT * FROM a, b WHERE a.a BETWEEN b.b AND b.b + 2;

I see four seconds versus thirty seconds. The difference was much greater
on my non-test-case - I wonder if multi-column indexing has something to
do with it.

> Also, what are the physical sizes of the two indexes?

relname | pg_size_pretty
----------------------------+----------------
location_object_start_gist | 193 MB
location_object_start | 75 MB
(2 rows)

> I notice that the inner nestloop join gets slower too, when it's not
> changed at all --- that suggests that the overall I/O load is a lot
> worse, so maybe the reason the query is falling off a performance cliff
> is that the GIST index fails to fit in cache.

Memory in the machine is 16GB.

Matthew

--
[About NP-completeness] These are the problems that make efficient use of
the Fairy Godmother. -- Computer Science Lecturer

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message Tom Lane 2009-04-16 17:59:32 Re: GiST index performance
Previous Message Tom Lane 2009-04-16 17:52:35 Re: GiST index performance