Beiträge getaggt mit 11g New Features

Parameter to prevent license violation with Active Data Guard

Disclaimer: I got informed that the mentioned underscore parameter is not reliable on every database version and that it never was intended for customer use. That is also why the quoted MOS note has been removed. I leave the article in spite, because I know it got referenced by many sites. And don’t mess with Larry Carpenter 😉

Although Real-Time Query is a great feature, it requires the Active Data Guard option to be licensed AND it is very easy to turn it on. That has been a concern for some customers I encountered. Now I realized that we have an undocumented parameter to prevent exactly that. Thanks to Marc, who mentioned the MOS Note 1436313.1 in a recent comment!

I am here connected to a Physical Standby database, running on 11.2.0.1 and don’t want to use Real-Time Query. The startup command would normally trigger the database to open READ ONLY, together with a Data Guard Broker configuration, Real-Time Query would be started. Not any more:

SQL> alter system set "_query_on_physical"=false scope=spfile;                             

System altered.

SQL> shutdown immediate
ORA-01109: database not open

Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.

Total System Global Area  521936896 bytes
Fixed Size		    2214936 bytes
Variable Size		  314573800 bytes
Database Buffers	  201326592 bytes
Redo Buffers		    3821568 bytes
Database mounted.
ORA-16669: instance cannot be opened because the Active Data Guard option is
disabled

SQL> host oerr ora 16669
16669, 00000, "instance cannot be opened because the Active Data Guard option is disabled"
// *Cause:  The attempt to open the instance failed because the Active Data
//          Guard option was not enabled and Redo Apply was either running
//          or was about to be started by the Data Guard broker. 
// *Action: Stop Redo Apply or set the database state to APPLY-OFF and then 
//          open the database.

It is still possible to open the Physical Standby READ ONLY when the MRP background process is stopped:

DGMGRL> edit database physt set state=apply-off;
Succeeded.
SQL> alter database open;

Database altered.

SQL> select open_mode from v$database;

OPEN_MODE
--------------------
READ ONLY

Only drawback is that it is an undocumented parameter, so you should confirm with Oracle Support that it is okay to use it in your case.
Conclusion: There is an easy way to prevent license violation by accident with Real-Time Query. Don’t believe it, ask Oracle Support 🙂

,

19 Kommentare

Fine Grained Access Control with DBMS_RLS using UPDATE_CHECK=>true

Fine Grained Access Control aka Virtual Private Database (VPD) has been there since Oracle 8 and got enhanced in each subsequent version. One minor New Feature of 11.2 was the addition of the parameter UPDATE_CHECK to the DBMS_RLS.ADD_POLICY procedure. During the OCM Preparation Workshop that I deliver presently, one of the attendees asked me what this parameter is actually doing – the doc is not so clear about it – which is why I came up with this simplified example. Hope you find it useful also 🙂

SQL> grant dba to adam identified by adam;

Grant succeeded.

SQL> connect adam/adam
Connected.
SQL> create table emp (ename varchar2(5),salary number);

Table created.

SQL> insert into emp values ('SCOTT',3000);

1 row created.

SQL> insert into emp values ('KING',9000);

1 row created.

SQL> commit;

Commit complete.

SQL> grant create session to scott identified by tiger;

Grant succeeded.

SQL> grant select,update on adam.emp to scott;

Grant succeeded.

The user SCOTT is not supposed to see the salary of the other employees and VPD is an elegant way to achieve that. The following technique will silently attach a WHERE-condition to statements hitting the table emp:

SQL> connect adam/adam
Connected.
SQL> create or replace function whoisit(schema varchar2, tab varchar2) return varchar2 
as
begin 
return '''' || sys_context('userenv','session_user') || ''' = ename ';     
end; 
/    

Function created.

SQL> begin
 dbms_rls.add_policy
  (object_schema=>'ADAM',
   object_name=>'EMP',
   policy_name=>'EMP_POLICY',
   function_schema=>'ADAM',
   policy_function=>'WHOISIT',
   update_check=>true);
end;
/    

PL/SQL procedure successfully completed.

SQL> connect scott/tiger
Connected.
SQL> select * from adam.emp;

ENAME	  SALARY
----- ----------
SCOTT	    3000

Although there are two rows in the table, SCOTT sees only his own salary! So far, this has been the same in earlier versions already. Now to the effect of update_check:

SQL> update adam.emp set ename='KING';
update adam.emp set ename='KING'
            *
ERROR at line 1:
ORA-28115: policy with check option violation

Without that parameter setting, the update would succeed – and the row would vanish for the user SCOTT as if the update would have deleted the row. Imagine the confusion of the user about that weird behavior 🙂

Talking about weird, by the way:

SQL> connect adam/adam
Connected.
SQL> select * from adam.emp;

no rows selected

SQL> connect / as sysdba
Connected.
SQL> select * from adam.emp;

ENAME	  SALARY
----- ----------
SCOTT	    3000
KING	    9000

SQL> grant exempt access policy to adam;

Grant succeeded.

SQL> connect adam/adam
Connected.
SQL> select * from adam.emp;

ENAME	  SALARY
----- ----------
SCOTT	    3000
KING	    9000

That was funny, wasn’t it?

Conclusion: The new parameter UPDATE_CHECK in the DBMS_RLS.ADD_POLICY procedure restricts updates that would else lead to the updated rows to fall out of the allowed visibility for that user. Check out the old behavior by just omitting that parameter. Because: Don’t believe it, test it 🙂

, , , ,

4 Kommentare

Backup & Restore one Datafile in Parallel

multisection

A lesser known 11g New Feature is the option to backup and restore single large datafiles with multiple channels in parallel, which can speed up these processes dramatically. This posting is supposed to give an example for it.

SQL> select * from v$version;
BANNER
 --------------------------------------------------------------------------------
 Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
 PL/SQL Release 11.2.0.3.0 - Production
 CORE    11.2.0.3.0    Production
 TNS for Linux: Version 11.2.0.3.0 - Production
 NLSRTL Version 11.2.0.3.0 - Production
SQL> select file#,bytes/1024/1024 as mb from v$datafile;
FILE#       MB
 ---------- ----------
 1                300
 2                200
 3                179
 4               2136

My demo system is on 11gR2, but the feature was there in 11gR1 already – it is easy to miss and just keep the old backup scripts in place like with 10g, though, where one channel could only read one datafile. bk is the same service that we have seen in a previous posting. I will now just backup & restore datafile 4 to show this can be done with two channels:

[oracle@uhesse1 ~]$ time rman target sys/oracle@uhesse1/bk cmdfile=backup_par.rmn
Recovery Manager: Release 11.2.0.3.0 - Production on Wed Dec 12 21:20:49 2012
Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.
connected to target database: PRIMA (DBID=2003897072)
RMAN> configure device type disk parallelism 2;
 2> backup datafile 4 section size 1100m;
 3>
 using target database control file instead of recovery catalog
 old RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 1 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters are successfully stored
Starting backup at 2012-12-12:21:20:50
 allocated channel: ORA_DISK_1
 channel ORA_DISK_1: SID=24 device type=DISK
 allocated channel: ORA_DISK_2
 channel ORA_DISK_2: SID=9 device type=DISK
 channel ORA_DISK_1: starting full datafile backup set
 channel ORA_DISK_1: specifying datafile(s) in backup set
 input datafile file number=00004 name=/home/oracle/prima/users01.dbf
 backing up blocks 1 through 140800
 channel ORA_DISK_1: starting piece 1 at 2012-12-12:21:20:51
 channel ORA_DISK_2: starting full datafile backup set
 channel ORA_DISK_2: specifying datafile(s) in backup set
 input datafile file number=00004 name=/home/oracle/prima/users01.dbf
 backing up blocks 140801 through 273408
 channel ORA_DISK_2: starting piece 2 at 2012-12-12:21:20:51
 channel ORA_DISK_2: finished piece 2 at 2012-12-12:21:21:46
 piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3kr_.bkp tag=TAG20121212T212051 comment=NONE
 channel ORA_DISK_2: backup set complete, elapsed time: 00:00:55
 channel ORA_DISK_1: finished piece 1 at 2012-12-12:21:22:06
 piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3bm_.bkp tag=TAG20121212T212051 comment=NONE
 channel ORA_DISK_1: backup set complete, elapsed time: 00:01:15
 Finished backup at 2012-12-12:21:22:06
Recovery Manager complete.
real    1m17.681s
 user    0m1.356s
 sys    0m0.129s

The script backup_par.rmn contains these lines:

[oracle@uhesse1 ~]$ cat backup_par.rmn
 configure device type disk parallelism 2;
 backup datafile 4 section size 1100m;

As you can see, the two channels were running in parallel, each taking about 1 minute to backup its section into a separate backupset. Also the restore can now be done in parallel for a single datafile:

[oracle@uhesse1 ~]$ time rman target sys/oracle@uhesse1/bk cmdfile=restore_par.rmn
Recovery Manager: Release 11.2.0.3.0 - Production on Wed Dec 12 21:23:28 2012
Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.
 connected to target database: PRIMA (DBID=2003897072)
RMAN> configure device type disk parallelism 2;
 2> sql "alter database datafile 4 offline";
 3> restore datafile 4;
 4> recover datafile 4;
 5> sql "alter database datafile 4 online";
 6>
 7>
 using target database control file instead of recovery catalog
 old RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters are successfully stored
sql statement: alter database datafile 4 offline
Starting restore at 2012-12-12:21:23:30
 allocated channel: ORA_DISK_1
 channel ORA_DISK_1: SID=9 device type=DISK
 allocated channel: ORA_DISK_2
 channel ORA_DISK_2: SID=24 device type=DISK
channel ORA_DISK_1: starting datafile backup set restore
 channel ORA_DISK_1: specifying datafile(s) to restore from backup set
 channel ORA_DISK_1: restoring datafile 00004 to /home/oracle/prima/users01.dbf
 channel ORA_DISK_1: restoring section 1 of 2
 channel ORA_DISK_1: reading from backup piece /home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3bm_.bkp
 channel ORA_DISK_2: starting datafile backup set restore
 channel ORA_DISK_2: specifying datafile(s) to restore from backup set
 channel ORA_DISK_2: restoring datafile 00004 to /home/oracle/prima/users01.dbf
 channel ORA_DISK_2: restoring section 2 of 2
 channel ORA_DISK_2: reading from backup piece /home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3kr_.bkp
 channel ORA_DISK_2: piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3kr_.bkp tag=TAG20121212T212051
 channel ORA_DISK_2: restored backup piece 2
 channel ORA_DISK_2: restore complete, elapsed time: 00:02:05
 channel ORA_DISK_1: piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3bm_.bkp tag=TAG20121212T212051
 channel ORA_DISK_1: restored backup piece 1
 channel ORA_DISK_1: restore complete, elapsed time: 00:02:16
 Finished restore at 2012-12-12:21:25:46
Starting recover at 2012-12-12:21:25:46
 using channel ORA_DISK_1
 using channel ORA_DISK_2
starting media recovery
 media recovery complete, elapsed time: 00:00:01
Finished recover at 2012-12-12:21:25:48
sql statement: alter database datafile 4 online
Recovery Manager complete.
real    2m20.137s
 user    0m1.229s
 sys    0m0.187s

This is the script I have used for the restore:

[oracle@uhesse1 ~]$ cat restore_par.rmn
 configure device type disk parallelism 2;
 sql "alter database datafile 4 offline";
 restore datafile 4;
 recover datafile 4;
 sql "alter database datafile 4 online";

Conclusion: Multisection backup & restore can be very useful for the processing of large (bigfile) datafiles with multiple channels in parallel. If you have not done it yet, you should definitely give it a try! As always: Don’t believe it, test it 🙂

Addendum: With 12c, this feature got enhanced to support also image copies.

, , ,

8 Kommentare