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.

Transaction Backout Does Not Do JSON Part 2

I did some digging on this issue and found the problem was caused when Transaction Backout executed the following statement which failed:

SQL> INSERT INTO json
 2   VALUES(EMPTY_CLOB());
INSERT INTO json
*
ERROR at line 1:
ORA-02290: check constraint (DRH.KEEP_IT_REAL) violated

At this point I wondered where the EMPTY_CLOB insert was coming from so I added an INSERT trigger to catch the values:

CREATE OR REPLACE TRIGGER check
BEFORE INSERT ON json
FOR EACH ROW
DECLARE
  PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
 INSERT INTO log
 VALUES(:new.always_json);
 COMMIT;
END;

And sure enough a NULL value (EMPTY_CLOB) wound up in the LOG table.

I was now curious if this was a bug or an actual unsupported feature. I got my answer when I tried to backout this INSERT statement.

INSERT INTO json
VALUES(
'
{
"plch_id" : "1",
"plch_desc" : "One"
}'
);

It raised this error:

ORA-55506: Transaction performed unsupported change

And a quick check of Oracle’s Error Message Guide revealed this:

ORA-55506: Transaction performed unsupported change
Cause: A transaction in the dependency DAG performed some
Action: The specified transaction cannot be backed out.

No, that is not a cut and paste error – the Cause is truncated. I assume it was intended to say “…some unsupported DML.”

The Action makes it official though – Transaction Backout does NOT JSON.

Thanks for reading!

PS: DAG is something called a Directed Acyclic Graph. I may blog about that later.