Re: Question about Sql SELECT and optimizer

From: Michael Fuhr <mike(at)fuhr(dot)org>
To: "Chaz(dot)" <eprparadocs(at)gmail(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Question about Sql SELECT and optimizer
Date: 2006-03-02 17:04:14
Message-ID: 20060302170414.GA7634@winnie.fuhr.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Thu, Mar 02, 2006 at 11:19:32AM -0500, Chaz. wrote:
> I am trying to understand something I have seen happen. I had a select
> that looked like:
>
> select f(A) from A, B, C where g(A)
>
> Where f(A) is the select that only depends on table A;
> g(A) is the where part that only depends on table A.
>
> What I saw happen was the optimizer will waste a lot of time (seconds!)
> bringing in table B and C. I was wondering why doesn't the optimizer
> drop references to tables B and C since they aren't used any where?

The above query does a cross join. Even though you're not using
values from B and C they're still contributing rows to the result
set.

test=> SELECT * FROM a;
aid
-----
a1
a2
(2 rows)

test=> SELECT * FROM b;
bid
-----
b1
b2
(2 rows)

test=> SELECT * FROM c;
cid
-----
c1
c2
(2 rows)

test=> SELECT a.*, b.*, c.* FROM a, b, c WHERE a.aid = 'a1';
aid | bid | cid
-----+-----+-----
a1 | b1 | c1
a1 | b2 | c1
a1 | b1 | c2
a1 | b2 | c2
(4 rows)

test=> SELECT a.*, b.* FROM a, b, c WHERE a.aid = 'a1';
aid | bid
-----+-----
a1 | b1
a1 | b2
a1 | b1
a1 | b2
(4 rows)

test=> SELECT a.* FROM a, b, c WHERE a.aid = 'a1';
aid
-----
a1
a1
a1
a1
(4 rows)

--
Michael Fuhr

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Hannu Krosing 2006-03-02 17:50:11 Re: [SQL] Interval subtracting
Previous Message Maciej Piekielniak 2006-03-02 16:59:28 Re: dump with lo