 |
|
11g Enhanced Read-Only Tables
Oracle 11g New Features Tips by Burleson
Consulting
June 27, 2008 |
Oracle 11g SQL New Features Tips
Oracle 11g has introduced a much simpler method
for enabling read-only tables that even protect the table from
unintentional DML by the table’s owner. Prior to 11g, a
read-only table was achieved by creating a table under a restricted
account and granting select privileges to the appropriate users.
However, using this method, it is possible for the owner of the
table to unintentionally modify the table.
Oracle Database 11g introduces new ALTER TABLE
syntax. For example, a table can be set to read-only by issuing the
following:
ALTER TABLE
<name> READ ONLY;
A table can be returned to read and write using
the following:
ALTER TABLE
<name> READ WRITE;
In read-only mode, the following operations are
permitted on the table:
-
Select
-
Management indexes, constraints, supplemental
log
-
Dropping and deallocation of unused columns
-
Renaming and moving of the table
-
Altering the table for physical property
changes, row movement, and shrinking the segment
-
Drop table
The following operations are disabled on a table
in read-only mode:
-
DML on table or any table partitions
-
Truncation of table
-
Select for update
-
Adding, removing, renaming, dropping, or
setting a column to unused
-
Dropping a partition or sub partition belonging
to the table
-
Online redefinition
-
Flashback on the table
For example, consider a transactional table that
stores a customer’s account, sales amount, and transaction date:
SQL>
desc account_sales
Name
Null?
Type
--------------------------------------------------------
ACCOUNT_ID
NUMBER
SALES_AMOUNT
NUMBER
TRX_DATE
DATE
The business might request that this table be
used to keep a historical record of accounts that were active during
each month. If it is November 1st, 2007, the Remote DBA
might run the following command to meet this requirement and then
make the table read-only since the table is only for a historical
record:
SQL>
create table
2 account_sales_october2007
3 as
4 select
5 *
6 from
7 account_sales
8 where
9 trx_date between ('01-OCT-07') and
('31-OCT-07');
Table created.
SQL> alter table
account_sales_october2007 read only;
Table altered.
A table’s read-only status is available from the
read_only column of the
dictionary views for [user|all|Remote DBA]_tables.
For example:
SQL>
select
2 table_name,
3 read_only
4 from
5 user_tables
6 where
7 table_name = 'ACCOUNT_SALES_OCTOBER2007';
TABLE_NAME
READ_ONLY
------------------------------ ----------
ACCOUNT_SALES_OCTOBER2007 YES
Any attempts to insert, delete, or update the
data from this table while it is in read-only status results in the
following error:
SQL>
insert into
2 account_sales_october2007
3 values (3, 100, '31-OCT-2007');
account_sales_october2007
*
ERROR at line 2:
ORA-12081: update operation not allowed on table
"VJ"."ACCOUNT_SALES_OCTOBER2007"
SQL> delete from
2 account_sales_october2007
3 where
4 account_id = 3;
account_sales_october2007
*
ERROR at line 2:
ORA-12081: update operation not allowed on table
"VJ"."ACCOUNT_SALES_OCTOBER2007"
SQL> update
2 account_sales_october2007
3 set
4 sales_amount = 2*sales_amount
5 where
6 customer_id = 3;
account_sales_october2007
*
ERROR at line 2:
ORA-12081: update operation not allowed on table
"VJ"."ACCOUNT_SALES_OCTOBER2007"
While the example above has been simplified to focus
on the new feature, there are many business cases where a read-only
table is appropriate. Most of these business cases share the
fact that the data is being stored for historical record or
reference, and there is no reason that the table should need to be
updated. In many cases, protecting the integrity of the data
is a main priority. An example is an OLTP table with
transactional data and sales compensation based on the table’s
monthly activity. It would be desirable to have each month’s
data stored in a read-only table that is protected from
modification.
The need for read-only data has existed long
before the new release of Oracle. However, this new feature
greatly simplifies the process of enabling and disabling read-only
status from a table with its simple syntax.
 |
This is an
excerpt from the new book
Oracle 11g New Features: Expert Guide to the Important
New Features by John Garmany, Steve Karam, Lutz Hartmann, V. J.
Jain, Brian Carr.
You can buy it direct from the publisher
for 30% off. |