Compiling views: when the FORCE fails you
The order in which your deployment scripts create views is important. This is a fact that I was reminded of when I had to fix a minor issue in the deployment of version #2 of my application recently.
Normally, you can just generate a create or replace force view
script for all your views and just run it in each environment, then recompile your schema after they’re finished – and everything’s fine. However, if views depend on other views, you can run into a logical problem if you don’t create them in the order of dependency.
Software Release 1.0
create table t (id number, name varchar2(100)); create or replace force view tv_base as select t.*, 'hello' as stat from t; create or replace force view tv_alpha as select t.* from tv_base t; desc tv_alpha; Name Null Type ---- ---- ------------- ID NUMBER NAME VARCHAR2(100) STAT CHAR(5)
Here we have our first version of the schema, with a table and two views based on it. Let’s say that the tv_base
includes some derived expressions, and tv_alpha
is intended to do some joins on other tables for more detailed reporting.
Software Release 1.1
alter table t add (phone varchar2(10)); create or replace force view tv_alpha as select t.* from tv_base t; create or replace force view tv_base as select t.*, 'hello' as stat from t;
Now, in the second release of the software, we added a new column to the table, and duly recompiled the views. In the development environment the view recompilation may happen multiple times (because other changes are being made to the views as well) – and nothing’s wrong. Everything works as expected.
However, when we run the deployment scripts in the Test environment, the “run all views” script has been run just once; and due to the way it was generated, the views are created in alphabetical order – so tv_alpha
was recreated first, followed by tv_base
. Now, when we describe the view, we see that it’s missing the new column:
desc tv_alpha; Name Null Type ---- ---- ------------- ID NUMBER NAME VARCHAR2(100) STAT CHAR(5)
Whoops. What’s happened, of course, is that when tv_alpha
was recompiled, tv_base
still hadn’t been recompiled and so it didn’t have the new column in it yet. Oracle internally defines views with SELECT *
expanded to list all the columns. The view won’t gain the new column until we REPLACE
the view with a new one using SELECT *
. By that time, it’s too late for tv_alpha
– it had already been compiled, successfully, so it doesn’t see the new column.
Lesson Learnt
What should we learn from this? Be wary of SELECT *
in your views. Don’t get me wrong: they are very handy, especially during initial development of your application; but they can surprise you if not handled carefully and I would suggest it’s good practice to expand those SELECT *
‘s into a discrete list of columns.
Some people would go so far as to completely outlaw SELECT *
, and even views-on-views, for reasons such as the above. I’m not so dogmatic, because in my view there are some good reasons to use them in some situations.