Edition Based Redefinition

This post is a simple example of the problem that can be solved by Oracle’s Edition Based Redefinition (EBR) feature. This example uses a table, a view, a stored procedure and an Oracle job. First up I’ll create the table and the view.

CREATE TABLE demo
( ts timestamp NOT NULL );
CREATE OR REPLACE VIEW demo_view AS
SELECT *
  FROM demo;

At this point the table and view have exactly the same columns.

Next I’ll create a procedure to insert records into the view (be careful to note that I use the view, not the table).

CREATE OR REPLACE PROCEDURE p AS
BEGIN
  INSERT INTO demo_view
  VALUES(systimestamp);
END;

Next I’ll submit an Oracle job to run the procedure over and over at 1 second intervals. This simply simulates application sessions that sign on and create data.

BEGIN
  DBMS_SCHEDULER.CREATE_JOB( job_name => 'J',
                             job_type => 'STORED_PROCEDURE',
                             job_action => 'P',
                             repeat_interval => 'FREQ=SECONDLY;INTERVAL=1',
                             enabled => TRUE );
END;

After a few seconds pass I’ll check the jobs status.

SELECT run_count,
       failure_count
  FROM user_scheduler_jobs;
RUN_COUNT FAILURE_COUNT
---------- -------------
        18             0

This shows the job has run 18 times without failing. At this point there will also be 18 records in the table. And speaking of the table…let’s add a column to it.

SQL> ALTER TABLE demo 2 ADD ( a number );

And check the job again.

RUN_COUNT FAILURE_COUNT
---------- -------------
        53             0

Still no failures because the procedure references the view which remains blissfully unaware of the new column.

Next we cause badness by redefining the view

SQL> CREATE OR REPLACE VIEW demo_view AS
2    SELECT *
3      FROM demo;

At this point the job starts failing. If this was an actual application that would equate to frustrated users.

RUN_COUNT FAILURE_COUNT
---------- -------------
        89            12

The job is fails because the change to the view has invalidated the procedure. The way to stop the badness is to recreate the procedure:

CREATE OR REPLACE PROCEDURE p AS
BEGIN
  INSERT INTO demo_view
  VALUES(systimestamp,
         1); -->> values for new column!
END;

Then we check the jobs a few times and see the failure count is no longer increasing.

RUN_COUNT FAILURE_COUNT
--------- -------------
      123            38
      124            38
      125            38

EBR could be used to avoid the period of badness in this example. In future posts I’ll explain how that is done.

At this point I’d like to show another important point about the data in the table after all of this processing.

SQL> SELECT a,
   2        COUNT(*)
   3  FROM demo
   4 GROUP BY a
   5 ORDER BY a;
         A    COUNT(*)
---------- ----------
         1         68
                   77
2 rows selected.

Records created prior to the change have NULL values for the new column (A). Records created during the period of badness also have NULL values. But the records created after that do have values (1).

I’ll also explain how EBR gets past that as well in future posts.

Thanks for reading.

When Views Are Forced To Care

In my last post regarding Edition Based Redefinition (EBR) I explained that Oracle views do not automatically take on changes to the structures underneath them. This makes them a very handy feature. But they do have limitations – such as when an new NOT NULL column is added. Here is an example:

-- create a table with just one lonely column
SQL> CREATE TABLE demo
 2   ( col1 NUMBER );
Table created.

-- create a view on top of the table
SQL> CREATE VIEW demo_view AS
 2   SELECT *
 3     FROM demo;
View created.

-- add a NOT NULL column to the table
SQL> ALTER TABLE demo
 2   ADD ( col2 NUMBER NOT NULL );
Table altered.

-- try to insert a record into the view
SQL> INSERT INTO demo_view
 2   VALUES(2);
INSERT INTO demo_view
*
ERROR at line 1:
ORA-01400: cannot insert NULL into ("DRH"."DEMO"."COL2")

The INSERT does not succeed because a value is not provided for COL2 in the DEMO table.

In the next few post’s I’ll explain how this failure might be worked around using a methodology that requires downtime.

Then I’ll segue into how EBR handles it with minimal downtime.

Thanks for reading!

Views Don’t Care Unless They Have To

Oracle’s Edition Based Redefinition (EBR) feature allows modifying database objects such as PLSQL code or database tables without interfering with a functioning application. In this series of articles I’ll introduce some of the underlying concepts of EBR and show some examples of its use. This first post describes a feature of Oracle views that helps enable EBR – the fact that views do not automatically change when their underlying tables do. Here is an example:

-- create demo table
SQL> CREATE TABLE demo
 2 ( col1 NUMBER );
Table created.

-- create a view on top of the table
SQL> CREATE VIEW demo_view AS
 2 SELECT *
 3 FROM demo;
View created.

-- insert a record into the view and only provdide value for col1
SQL> INSERT INTO demo_view
 2 VALUES(1);
1 row created.

-- add a second column to the table
SQL> ALTER TABLE demo
 2 ADD ( col2 NUMBER );
Table altered.

-- Does the view see the new column right away? No!
SQL> INSERT INTO demo_view
 2 VALUES(2);
1 row created.

-- The view remains blissfully unaware
SQL> SELECT *
 2 FROM demo_view;
COL1
----------
 1
 2

-- the table sure knows about the column though
SQL> INSERT INTO demo
 2 VALUES(3);
INSERT INTO demo
 *
ERROR at line 1:
ORA-00947: not enough values

Inserts directly into the table fail because of the new column. But not the view! The view does not see the columns until it is recreated.

SQL> CREATE OR REPLACE VIEW demo_view AS
 2   SELECT *
 3     FROM demo;
View created.

SQL> INSERT INTO demo_view
 2   VALUES(3);
INSERT INTO demo_view
 *
ERROR at line 1:
ORA-00947: not enough values

In future articles I’ll explain how this relates to EBR.

Thanks for reading!