Have you ever run into the following error when trying to create a materialized view?
Calm yourself. While it is true that you will need to "rewrite the statement" that you provide in your
All you have to do is create a view with the subqueries, and then create your materialized view based on the view:
By taking this approach, you can change the contents of the materialized view with the next refresh by doing nothing more than changing the query (instead of dropping and re-creating the materialized view).
ORA-22818: subquery expressions not allowed here
Yes, it is true: you cannot have a scalar subquery in the SQL statement used to create your materialized view. Here's an example of what won't work (note: I am not claiming this query makes any sense):CREATE MATERIALIZED VIEW hr_demo_mv
AS
SELECT employee_id,
(SELECT MAX (hire_date)
FROM employees ce) maxhd
FROM employees t
/
ORA-22818: subquery expressions not allowed here
22818. 00000 - "subquery expressions not allowed here"
*Cause: An attempt was made to use a subquery expression where these
are not supported.
*Action: Rewrite the statement without the subquery expression.
Rewrite my query without the subquery expression? But I just spent an hour putting it all together. Works great. Gives me exactly the results I want and need. Rewrite it? ARGH.Calm yourself. While it is true that you will need to "rewrite the statement" that you provide in your
CREATE MATERIALIZED VIEW
statement, you will not have to abandon your subqueries and all your hard work.All you have to do is create a view with the subqueries, and then create your materialized view based on the view:
CREATE VIEW hr_demo_v
AS
SELECT employee_id,
(SELECT MAX (hire_date)
FROM employees ce) maxhd
FROM employees t
/
View HR_DEMO_V created.
CREATE MATERIALIZED VIEW hr_demo_mv
AS
SELECT * FROM hr_demo_v
/
Materialized view HR_DEMO_MV created.
I recommend this approach (the materialized view is "nothing more" than a select from a view), even if your materialized view query does not contain a subquery or anything else that would preclude the materialized view from being created.By taking this approach, you can change the contents of the materialized view with the next refresh by doing nothing more than changing the query (instead of dropping and re-creating the materialized view).
That is pretty cool. Thanks!
ReplyDeleteAnd it's so simple it makes me feel stupid for not thinking of this myself. Thanks for that too ;-)
I am definitely going to use this, starting tomorrow morning.
Hello Steven, All,
ReplyDeleteWhen using the approach of basing a naterialized view on a view instead of directly on the base tables,
you should be aware that this automatically makes the materialized view to be considered COMPLEX,
and thus NOT fast refreshable.
This is true even for very simple views, like for example a view that selects all the columns of a single table.
That is, if the table has a materialized view log defined, then a materialized view based directly on the table
will be fast-refreshable, while a materialized view based on a view that selects from the table will NOT be fast-refreshable.
This behavior may be relevant or not, based, of course, on the specifics and performance requirements of your application.
Thanks a lot & Best Regards,
Iudith
Thanks for pointing that out, Iudith.
DeleteHi everyone, following-up on this thread:
DeleteI just learned about Materialized View today and encountered the same issue in this post. As Steven suggested, I built the MV above a View. But @iudith mentioned that this won't enable the fast-refresh. My questions are:
1. By default, how is MV refreshed by the system? Is it by period of time or something else?
2. Since the fast-refresh is not possible, is there a way to regularly update the MV? I will appreciate it if someone can refer me to a good tutorial for beginner about this. The Oracle Docs is a bit overwhelming ...
Danny
Danny, check out Tim Hall's article on materialized views.
Deletehttps://oracle-base.com/articles/misc/materialized-views
On the Oracle Dev Gym (devgym.oracle.com) we use DBMS_SCHEDULER to run jobs daily and weekly to refresh materialized views.
ok, this query doesn't make any sense, however, the "GROUP BY"-part of it doesn't even make any sense at all.
ReplyDeleteIt should be left away because it might be confusing
Ha! Excellent point. That was left over from an earlier iteration of the query. I will remove it.
DeleteI just wonder how annoying it might get later on, when you figure out, that changing of query actually does not work in changing of your MV_ contents, and it also stops to refresh.
ReplyDeleteOr that when you add column into view query, this will not automatically add column into MV_ ...
This comment has been removed by a blog administrator.
ReplyDeleteThat's exactly what I needed. It works perfectly!
ReplyDeleteThis just pushed the error farther down - I'm working in peoplesoft and got the same error when I tried to build the materialized view from the view with subqueries as suggested above - "Warning: named view in FROM list not supported for this type MV" and "Warning: named view in FROM list not supported for this type MV"
ReplyDeleteWhat version of the database are you using?
DeleteThank you Steven this workaround was a great help.
ReplyDeleteHi Steven - Just wanted to say many thanks for this!! I spent a few days toiling with a materialized view trying to re-write it. Then I also got this idea to make part of the materialized view simply into a view.
ReplyDeleteI didnt have any proof, or a comfort level doing it but after reading your blog I'm more confident that this is the best that can be done :)
Glad to hear it, Rodney! Thanks for sharing your experience.
Delete