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!

 

Transaction Backout Is Not Picky

All of the examples I’ve shown so far on this blog rely on transaction names to specify what to backout. This is simpler than specifying transaction ID’s. But it does have potential drawback. It backs out ALL discovered. Here is an example that executes single INSERTs in 3 separate transactions – notice the transaction names used.

SQL> SET TRANSACTION NAME 'INSERT';
Transaction set.

SQL> BEGIN
 2     INSERT INTO demo
 3     VALUES(1,'Demo 1');
 4     COMMIT;
 5   END;
 6 /
PL/SQL procedure successfully completed.

SQL> COMMIT;
Commit complete.

SQL> SET TRANSACTION NAME 'BOB';
Transaction set.

SQL> BEGIN
 2     INSERT INTO demo
 3     VALUES(2,'Demo 2');
 4     COMMIT;
 5   END;
 6 /
PL/SQL procedure successfully completed.

SQL> COMMIT;
Commit complete.

SQL> SET TRANSACTION NAME 'INSERT';
Transaction set.

SQL> BEGIN
 2     INSERT INTO demo
 3     VALUES(3,'Demo 3');
 4     COMMIT;
 5   END;
 6 /
PL/SQL procedure successfully completed.

SQL> COMMIT;

What will happen when I backout the transaction (or transactionS) named INSERT?

SQL> DECLARE
 2     v_names SYS.TXNAME_ARRAY := SYS.TXNAME_ARRAY('INSERT');
 3   BEGIN
 4     DBMS_FLASHBACK.TRANSACTION_BACKOUT( numtxns => 1,
 5                                         names => v_names,
 6                                         scnhint => hold_stuff.v_scn,
 7                                         options => DBMS_FLASHBACK.CASCADE );
 8   END;

What records are left in the DEMO table?

SQL> SELECT *
 2     FROM demo;

DEMO_ID    DEMO_NAME
---------- ---------
         2 Demo 2

Both of the INSERT transactions were backed out. Here is the SQL used for the backout.

delete from DRH.DEMO where DEMO_ID = '3' and DEMO_NAME = 'Demo 3'
delete from DRH.DEMO where DEMO_ID = '1' and DEMO_NAME = 'Demo 1'

Beware of this behavior! Or. conversely; embrace it in your applications. I’ll discuss more about that in future entries.

Thanks for reading!