Thread: Materializing a view by hand

Materializing a view by hand

From
Robert James
Date:
I have a view which is very slow to computer, but doesn't change often.

I'd like to materialize it. I thought I'd do a simple poor man's materialize by:

1) ALTER VIEW myview RENAME to _myview
2) SELECT * INTO myview FROM _myview

The only problem is that all my other views, which are dependent on
myview, automatically rename to _myview.  That would normally be very
helpful but is exactly the opposite of what I want!

Is there a work around?

 I'm running Postgres 8.3 - upgrading is a possibility but difficult.


Re: Materializing a view by hand

From
Kevin Grittner
Date:
Robert James <srobertjames@gmail.com> wrote:

> I have a view which is very slow to computer, but doesn't change often.
>
> I'd like to materialize it. I thought I'd do a simple poor man's
> materialize by:
>
> 1) ALTER VIEW myview RENAME to _myview
> 2) SELECT * INTO myview FROM _myview
>
> The only problem is that all my other views, which are dependent on
> myview, automatically rename to _myview.  That would normally be very
> helpful but is exactly the opposite of what I want!
>
> Is there a work around?

The best I can think of would be to use pg_dump to do a of that one
view (-t myview), and run the GRANT and REVOKE statements from that
after the rename and materialization.

> I'm running Postgres 8.3 - upgrading is a possibility but difficult.

The upcoming 9.3 release will have minimal support for materialized
views, but there is no feature to transform a view into a
materialized view in that release, or on the roadmap.  I wonder
whether this comes up often enough to consider adding such a
feature to a future release.

--
Kevin Grittner
EDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company


Re: Materializing a view by hand

From
Merlin Moncure
Date:
All your view and function creation statements should be in scripts that you maintain as a kind of best practice.  If you've done that, then you can simply drop/cascade the view you're replacing after you renamed it and then rebuild the rest of them.

I actually go one step further and put the view creation scripts into a function: then I can just do 'SELECT RebuildViews();' at appropriate moments.  This typically happens at the very end of the materialization process switcheroo I have to do if my view has to be available while the materialization is happening.  Postgres 9.4 will make this technique basically obsolete with the lock-free refresh (Thanks Kevin!).

merlin


On Tue, Aug 13, 2013 at 5:02 PM, Robert James <srobertjames@gmail.com> wrote:
I have a view which is very slow to computer, but doesn't change often.

I'd like to materialize it. I thought I'd do a simple poor man's materialize by:

1) ALTER VIEW myview RENAME to _myview
2) SELECT * INTO myview FROM _myview

The only problem is that all my other views, which are dependent on
myview, automatically rename to _myview.  That would normally be very
helpful but is exactly the opposite of what I want!

Is there a work around?

 I'm running Postgres 8.3 - upgrading is a possibility but difficult.


--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general