Re: optimize self-join query

From: Harald Fuchs <hari(dot)fuchs(at)gmail(dot)com>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: optimize self-join query
Date: 2011-10-28 09:31:58
Message-ID: 86sjmdlawh.fsf@protecting.net
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

In article <BFC71945-8821-4BC9-8430-A8CACF8F3794(at)gmail(dot)com>,
Ty Busby <tybusby(at)gmail(dot)com> writes:

> I have a table that stores a very large starting number called
> epc_start_numeric and a quantity. I've apparently built the most
> inefficient query possible for doing the job I need: find out if any
> records overlap. Imagine the epc_start_numeric + quantity
> representing a block of numbers. I need to find out if any of these
> blocks overlap.

If I understand you correctly, you want to compare numeric intervals.
On PgFoundry you can find an interval type like that called bioseg.
This type is GiST-indexable and thus may speed up your query.

Example:

CREATE TABLE test2 (
id serial NOT NULL,
seg bioseg NOT NULL,
PRIMARY KEY (id)
);

-- Fill test2 with a gazillion of rows

CREATE INDEX test2_seg_ix ON test2 USING gist (seg);

SELECT t1.id, t1.seg, t2.id, t2.seg
FROM test2 t1
JOIN test2 t2 ON t2.id != t1.id AND t2.seg && t1.seg;

You'll still need a seqscan for t1, but t2 will use an index scan.

You can even define a table constraint to prevent overlaps:

ALTER TABLE test2
ADD CONSTRAINT test2_seg_ex
EXCLUDE USING gist (seg WITH &&);

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Phil Couling 2011-10-28 10:25:20 Re: Different order by behaviour depending on where clause?
Previous Message Pavel Stehule 2011-10-28 05:13:26 Re: Different order by behaviour depending on where clause?