Re: Alternative to INTERSECT

From: Andreas Joseph Krogh <andreak(at)officenet(dot)no>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: Alternative to INTERSECT
Date: 2007-07-31 19:45:10
Message-ID: 200707311945.16573.andreak@officenet.no
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Tuesday 31 July 2007 18:52:22 Josh Trutwin wrote:
> On Tue, 31 Jul 2007 17:30:51 +0000
>
> Andreas Joseph Krogh <andreak(at)officenet(dot)no> wrote:
> > Hi all. I have the following schema:
> >
> > CREATE TABLE test (
> > id integer NOT NULL,
> > field character varying NOT NULL,
> > value character varying NOT NULL
> > );
> >
> > ALTER TABLE ONLY test
> > ADD CONSTRAINT test_id_key UNIQUE (id, field, value);
> >
> > CREATE INDEX test_like_idx ON test USING btree (id, field, value
> > varchar_pattern_ops);
> >
> > Using INTERSECT I want to retrieve the rows matching (pseudo-code)
> > "firstname LIKE ('andrea%' OR 'jose%') AND lastname LIKE 'kro%'"
>
> Why not:
>
> WHERE (t.field = lastname AND t.value LIKE 'kro%')
> OR (t.field = firsname AND (
> t.value LIKE 'jose%' OR t.value LIKE 'andrea%')
> )
>
> Not tested. If you're having performance problems is probably less
> like that the INTERSECT is the problem with all those LIKE's in
> there? Is t.value indexed?

Yes, as I wrote:

CREATE INDEX test_like_idx ON test USING btree
(id, field, value varchar_pattern_ops);

And I'm observing that it uses that index.

Your query doesn't cut it, let me try to explain what I'm trying to achieve:

Suppose I have the following data:
INSERT INTO test VALUES (1, 'firstname', 'andreas');
INSERT INTO test VALUES (1, 'firstname', 'joseph');
INSERT INTO test VALUES (1, 'lastname', 'krogh');
INSERT INTO test VALUES (2, 'firstname', 'andreas');
INSERT INTO test VALUES (2, 'lastname', 'noname');

The reason for why I use INTERSECT is that I want:

SELECT t.id from test t WHERE t.field = 'firstname' AND t.value
LIKE 'andrea%'
INTERSECT SELECT t.id FROM test t WHERE t.field = 'firstname' AND t.value
LIKE 'jose%'
INTERSECT SELECT t.id FROM test t WHERE t.field = 'lastname'  AND t.value
LIKE 'kro%';

To return only id 1, and the query:

SELECT t.id from test t WHERE t.field = 'firstname' AND t.value
LIKE 'andrea%'
INTERSECT SELECT t.id FROM test t WHERE t.field = 'firstname' AND t.value
LIKE 'jose%'
INTERSECT SELECT t.id FROM test t WHERE t.field = 'lastname'  AND t.value
LIKE 'non%';

To return no rows at all (cause nobydy's name is "andreas joseph noname").

Your suggestion doesn't cover this case.

--
AJK

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Rodrigo De León 2007-07-31 20:30:17 Re: Alternative to INTERSECT
Previous Message Jon Horsman 2007-07-31 19:06:10 Re: Connection Limit