From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | "Jim 'Decibel!' Nasby" <jnasby(at)cashnetusa(dot)com> |
Cc: | Richard Huxton <dev(at)archonet(dot)com>, postgresql performance list <pgsql-performance(at)postgresql(dot)org> |
Subject: | Re: Oddity with view (now with test case) |
Date: | 2008-11-10 19:31:39 |
Message-ID: | 12776.1226345499@sss.pgh.pa.us |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-performance |
"Jim 'Decibel!' Nasby" <jnasby(at)cashnetusa(dot)com> writes:
> Here's the commands to generate the test case:
> create table a(a int, b text default 'test text');
> create table c(c_id serial primary key, c_text text);
> insert into c(c_text) values('a'),('b'),('c');
> create table b(a int, c_id int references c(c_id));
> create view v as select a, b, null as c_id, null as c_text from a
> union all select a, null, b.c_id, c_text from b join c on (b.c_id=
> c.c_id);
> \timing
> insert into a(a) select generate_series(1,9999999);
> select count(*) from a;
> select count(*) from v;
> explain analyze select count(*) from a;
> explain analyze select count(*) from v;
I think what you're looking at is projection overhead and per-plan-node
overhead (the EXPLAIN ANALYZE in itself contributes quite a lot of the
latter). One thing you could do is be more careful about making the
union input types match up so that no subquery scan nodes are required:
create view v2 as select a, b, null::int as c_id, null::text as c_text from a
union all select a, null::text, b.c_id, c_text from b join c on (b.c_id=c.c_id);
On my machine this runs about twice as fast as the original view.
regards, tom lane
From | Date | Subject | |
---|---|---|---|
Next Message | Jim 'Decibel!' Nasby | 2008-11-10 21:06:36 | Re: Oddity with view (now with test case) |
Previous Message | Jim 'Decibel!' Nasby | 2008-11-10 18:36:12 | Re: Oddity with view (now with test case) |