Re: To use a VIEW or not to use a View..... - Mailing list pgsql-sql

From Stephan Szabo
Subject Re: To use a VIEW or not to use a View.....
Date
Msg-id 20030122130604.C1159-100000@megazone23.bigpanda.com
Whole thread Raw
In response to Re: To use a VIEW or not to use a View.....  (Tomasz Myrta <jasiek@klaster.net>)
Responses Re: To use a VIEW or not to use a View.....  (Tomasz Myrta <jasiek@klaster.net>)
List pgsql-sql
On Wed, 22 Jan 2003, Tomasz Myrta wrote:

> Let's make some test:
>
> First, let's create some simple view with 2 tables join:
> drop view pm;
> create view pm as
>  select
>    id_przystanku,
>    m.nazwa
>  from
>    przystanki p
>    join miasta m using (id_miasta);
>
> explain select * from pm where id_przystanku=1230;
> Nested Loop  (cost=0.00..6.26 rows=1 width=23)
>   ->  Index Scan using przystanki_pkey on przystanki p  (cost=0.00..3.14 rows=1 width=8)
>   ->  Index Scan using miasta_pkey on miasta m  (cost=0.00..3.10 rows=1 width=15)
>
>
> Next, let's try query using this view 2 times with explicit join:
> explain select * from pm a join pm b using(id_przystanku) where id_przystanku=1230;
> Hash Join  (cost=13.00..30.10 rows=1 width=46)
>   ->  Hash Join  (cost=6.74..21.02 rows=374 width=23)
>         ->  Seq Scan on przystanki p  (cost=0.00..7.74 rows=374 width=8)
>         ->  Hash  (cost=5.99..5.99 rows=299 width=15)
>               ->  Seq Scan on miasta m  (cost=0.00..5.99 rows=299 width=15)
>   ->  Hash  (cost=6.26..6.26 rows=1 width=23)
>         ->  Nested Loop  (cost=0.00..6.26 rows=1 width=23)
>               ->  Index Scan using przystanki_pkey on przystanki p  (cost=0.00..3.14 rows=1 width=8)
>               ->  Index Scan using miasta_pkey on miasta m  (cost=0.00..3.10 rows=1 width=15)
>
> And now similiar view, but without nesting views:


> drop view pm2;
> create view pm2 as
>  select
>    id_przystanku,
>    m1.nazwa as nazwa1,
>    m2.nazwa as nazwa2
>  from
>    przystanki p1
>    join miasta m1 using (id_miasta)
>    join przystanki p2 using (id_przystanku)
>    join miasta m2 on (m2.id_miasta=p2.id_miasta);

That's not the same join for optimization purposes
since postgresql treats explicit join syntax as a
constraint on the ordering of joins.

The same join would be something like:

przystanki p1 join miasta m1 using (id_miasta)
join (przystanki p2 join miasta m2 using (id_miasta))using (id_przystanku)

minus the fact I think you'd need some explicit naming in
there.




pgsql-sql by date:

Previous
From: Tom Lane
Date:
Subject: Re: Speed depending of Join Order.
Next
From: Tom Lane
Date:
Subject: Re: To use a VIEW or not to use a View.....