Thread: explicit JOIN faster than implicit?

explicit JOIN faster than implicit?

From
Eric Schwarzenbach
Date:
I'm in the process taking a large SELECT statement which had been
written using implicit join syntax (that is, just listing all the tables
in the FROM clause, and listing join conditions in the WHERE clause) and
rewriting it to use explicit JOIN syntax (they are all inner joins).
This has sped up the query by 50%.

This is using Postgres 8.3 on a database with GEQO turned off.

Is this what would be expected? Does the query planner / optimizer
generally do better with explicit JOIN syntax?

Cheers,

Eric

Re: explicit JOIN faster than implicit?

From
Martin Gainty
Date:
here is my best -> worst join scenario starting with best
1)low cardinality tables
2)where or join on indexed columns
3)function indexes
4)concatenated indexes
.........
5)cartesian join ..every row join specifically joins every other row from every other table

Martin Gainty
______________________________________________
Verzicht und Vertraulichkeitanmerkung/Note de déni et de confidentialité
 
Diese Nachricht ist vertraulich. Sollten Sie nicht der vorgesehene Empfaenger sein, so bitten wir hoeflich um eine Mitteilung. Jede unbefugte Weiterleitung oder Fertigung einer Kopie ist unzulaessig. Diese Nachricht dient lediglich dem Austausch von Informationen und entfaltet keine rechtliche Bindungswirkung. Aufgrund der leichten Manipulierbarkeit von E-Mails koennen wir keine Haftung fuer den Inhalt uebernehmen.
Ce message est confidentiel et peut être privilégié. Si vous n'êtes pas le destinataire prévu, nous te demandons avec bonté que pour satisfaire informez l'expéditeur. N'importe quelle diffusion non autorisée ou la copie de ceci est interdite. Ce message sert à l'information seulement et n'aura pas n'importe quel effet légalement obligatoire. Étant donné que les email peuvent facilement être sujets à la manipulation, nous ne pouvons accepter aucune responsabilité pour le contenu fourni.





> Date: Wed, 5 Aug 2009 17:43:20 -0400
> From: subscriber@blackbrook.org
> To: pgsql-general@postgresql.org
> Subject: [GENERAL] explicit JOIN faster than implicit?
>
> I'm in the process taking a large SELECT statement which had been
> written using implicit join syntax (that is, just listing all the tables
> in the FROM clause, and listing join conditions in the WHERE clause) and
> rewriting it to use explicit JOIN syntax (they are all inner joins).
> This has sped up the query by 50%.
>
> This is using Postgres 8.3 on a database with GEQO turned off.
>
> Is this what would be expected? Does the query planner / optimizer
> generally do better with explicit JOIN syntax?
>
> Cheers,
>
> Eric
>
> --
> Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-general


Get your vacation photos on your phone! Click here.

Re: explicit JOIN faster than implicit?

From
Eric Schwarzenbach
Date:
Um, ok. You've listed some conditions in order of how well they should
perform and these generally agree with my understanding. But how does
this relate to the relative performance of the semantically equivalent
explicit and implicit join syntaxes?

Eric

Martin Gainty wrote:
> here is my best -> worst join scenario starting with best
> 1)low cardinality tables
> 2)where or join on indexed columns
> 3)function indexes
> 4)concatenated indexes
> .........
> 5)cartesian join ..every row join specifically joins every other row
> from every other table
>
> Martin Gainty
> ______________________________________________
> Verzicht und Vertraulichkeitanmerkung/Note de déni et de confidentialité
>
> Diese Nachricht ist vertraulich. Sollten Sie nicht der vorgesehene
> Empfaenger sein, so bitten wir hoeflich um eine Mitteilung. Jede
> unbefugte Weiterleitung oder Fertigung einer Kopie ist unzulaessig.
> Diese Nachricht dient lediglich dem Austausch von Informationen und
> entfaltet keine rechtliche Bindungswirkung. Aufgrund der leichten
> Manipulierbarkeit von E-Mails koennen wir keine Haftung fuer den
> Inhalt uebernehmen.
> Ce message est confidentiel et peut être privilégié. Si vous n'êtes pas le destinataire prévu, nous te demandons avec
bontéque pour satisfaire informez l'expéditeur. N'importe quelle diffusion non autorisée ou la copie de ceci est
interdite.Ce message sert à l'information seulement et n'aura pas n'importe quel effet légalement obligatoire. Étant
donnéque les email peuvent facilement être sujets à la manipulation, nous ne pouvons accepter aucune responsabilité
pourle contenu fourni. 
>
>
>
>
>
> > Date: Wed, 5 Aug 2009 17:43:20 -0400
> > From: subscriber@blackbrook.org
> > To: pgsql-general@postgresql.org
> > Subject: [GENERAL] explicit JOIN faster than implicit?
> >
> > I'm in the process taking a large SELECT statement which had been
> > written using implicit join syntax (that is, just listing all the tables
> > in the FROM clause, and listing join conditions in the WHERE clause) and
> > rewriting it to use explicit JOIN syntax (they are all inner joins).
> > This has sped up the query by 50%.
> >
> > This is using Postgres 8.3 on a database with GEQO turned off.
> >
> > Is this what would be expected? Does the query planner / optimizer
> > generally do better with explicit JOIN syntax?
> >
> > Cheers,
> >
> > Eric
> >
> > --
> > Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
> > To make changes to your subscription:
> > http://www.postgresql.org/mailpref/pgsql-general
>
> ------------------------------------------------------------------------
> Get your vacation photos on your phone! Click here.
> <http://windowsliveformobile.com/en-us/photos/default.aspx?&OCID=0809TL-HM>


Re: explicit JOIN faster than implicit?

From
Eric Schwarzenbach
Date:
I tried playing with the join_collapse_limit setting. The implicit join
query was unaffected. The explicit join out-performed the implicit one
by 50% when the join_collapse_limit  was low enough, and took just as
long as the implicit one when the join_collapse_limit was high enough.

If I'm reading the documentation right, when the join_collapse_limit is
high enough, the planner is rewriting my explicit join syntax into the
implicit join syntax...with the effect of slowing it down!

I'm not especially concerned, as the performance is acceptable either
way, and I'll be getting the better performance anyway, but I'm just
wondering if this behavior is expected.


Eric

Eric Schwarzenbach wrote:
> I'm in the process taking a large SELECT statement which had been
> written using implicit join syntax (that is, just listing all the tables
> in the FROM clause, and listing join conditions in the WHERE clause) and
> rewriting it to use explicit JOIN syntax (they are all inner joins).
> This has sped up the query by 50%.
>
> This is using Postgres 8.3 on a database with GEQO turned off.
>
> Is this what would be expected? Does the query planner / optimizer
> generally do better with explicit JOIN syntax?
>
> Cheers,
>
> Eric
>
>


Re: explicit JOIN faster than implicit?

From
Tom Lane
Date:
Eric Schwarzenbach <subscriber@blackbrook.org> writes:
> I'm in the process taking a large SELECT statement which had been
> written using implicit join syntax (that is, just listing all the tables
> in the FROM clause, and listing join conditions in the WHERE clause) and
> rewriting it to use explicit JOIN syntax (they are all inner joins).
> This has sped up the query by 50%.

Are you getting the same plan both ways?  Have you distinguished between
planning time and execution time?  How many tables in the query, and how
does that relate to your join_collapse_limit setting?

            regards, tom lane

Re: explicit JOIN faster than implicit?

From
Filip Rembiałkowski
Date:
Hi,

2009/8/6 Eric Schwarzenbach <Eric.J.Schwarzenbach.C88@alumni.upenn.edu>
I tried playing with the join_collapse_limit setting. The implicit join
query was unaffected. The explicit join out-performed the implicit one
by 50% when the join_collapse_limit  was low enough, and took just as
long as the implicit one when the join_collapse_limit was high enough.

If I'm reading the documentation right, when the join_collapse_limit is
high enough, the planner is rewriting my explicit join syntax into the
implicit join syntax...with the effect of slowing it down!

I'm not especially concerned, as the performance is acceptable either
way, and I'll be getting the better performance anyway, but I'm just
wondering if this behavior is expected.


Probably it's not expected, and definitely it is not desired :)
It would be helpful if you post explain analyze of both queries, before and after VACUM ANALYZE of all used tables.
You can also try to increase statistics target for join columns. Indexes might help too.


--
Filip Rembiałkowski
JID,mailto:filip.rembialkowski@gmail.com
http://filip.rembialkowski.net/