Oracle Database

No more cleartext-passwords in Scripts – Oracle Secure External Password Store (SEPS)

Gone are the day when cleartext passwords had to be stored in scripts for Oracle database access. The solution to this requirement is “Oracle Secure External Password Store (SEPS)”. This article will give a short introduction and a practical example of the solution.

Key facts:

  • no Advanced Security Option (License) necessary
  • every unix-account, who has access to the wallet can use it to log on to the contained databases without a password! Therefore prevent other unix-accounts from accessing your wallet! (chmod, chown)

Installation

  • Oracle Client: Unix-Account, who wishes to connect to the database without providing a password needs to have an Oracle Client installed. Actually it can be an Instant Client, however the Instant Client does not have the Oracle Wallet Manager (owm).
  • TNS_ADMIN: If the installed Oracle-Client is also used by other unix-accounts, you have to set Environment-Variable TNS_ADMIN to point to a dedicated destination for sqlnet.ora
echo "export TNS_ADMIN=/home/techuser/oracle/network/admin" >> ~/.bash_profile

  • sqlnet.ora in $TNS_ADMIN: In this file, the path to your personal wallet is defined:
WALLET_LOCATION =
(
   SOURCE =
      (METHOD = FILE)
      (METHOD_DATA =
         (DIRECTORY = /home/techuser/oracle/network/wallet)
      )
)
SQLNET.WALLET_OVERRIDE = TRUE
SSL_CLIENT_AUTHENTICATION = FALSE

Be aware that sqlnet.ora has very sensitive formatting! Blank at the beginning of the line means that previous line is continued. If the first character of a line is not a blank, then it is supposed to be new directive. Therefore note the identation of wallet_location parameter.

  • tnsnames.ora in $TNS_ADMIN: This file contains TNS Aliases, which are used to connect to database. If the unix-account needs to  connect to one database but with 2 different database accounts, then it needs to use 2 distinct tns aliases!
  • Creation of Wallet: When the wallet is created, a wallet password is requested. This password is needed when viewing, adding, modifying and deleting wallet entries.
mkstore –wrl /home/techuser/oracle/network/wallet –create

Management of Credentials in Wallet:

  • Adding Credentials to Wallet:
mkstore -wrl /home/techuser/oracle/network/wallet \
-createCredential
  • Removal of Credentials from wallet:

mkstore -wrl /home/techuser/oracle/network/wallet \
-deleteCredential TNSAlias

  • Modification of Credential in wallet

mkstore -wrl /home/techuser/oracle/network/wallet \
-modifyCredential N102 scott newpassword
Enter password:
Modify credential Modify 1
 
mkstore -wrl /home/techuser/oracle/network/wallet \
-modifyEntry oracle.security.client.password1 newpass
Enter password:

  • Viewing of Credentials in Wallet
mkstore -wrl /home/techuser/oracle/network/wallet -list
 
Oracle Secret Store entries:
oracle.security.client.connect_string1
oracle.security.client.password1
oracle.security.client.username
 
mkstore -wrl /home/techuser/oracle/network/wallet \
-viewEntry oracle.security.client.connect_string1
Enter password: 
 
oracle.security.client.connect_string1 = N102
 
mkstore -wrl /home/techuser/oracle/network/wallet -viewEntry oracle.security.client.username1
Enter password:
oracle.security.client.username1 = scott
 
mkstore -wrl /home/techuser/oracle/network/wallet -viewEntry oracle.security.client.password1
Enter password:
oracle.security.client.password1 = tiger

  • Changing Wallet Password
orapki wallet change_pwd -wallet /home/techuser/oracle/network/wallet \
-oldpwd welcome1 -newpwd welcome2

Example:

DBs:
 
TESTDB1 (11.2.0.3)
TESTDB2 (11.2.0.3)
 
Techuser:
techuser1 - uses RDBMS Server Home als Client
techuser2 - uses Oracle Instant Client
 
Requirements:
techuser1 should be able TO CONNECT TO ro_user@TESTDB2 AND rw_user@TESTDB2
techuser2 should be able TO CONNECT TO ro_user@TESTDB2 AND rw_user@TESTDB1 
 
Preparations:
 
AS oracle:
. TESTDB2.env
 
sqlplus "/as sysdba"
 
SQL> GRANT CREATE SESSION TO ro_user IDENTIFIED BY ro_password;
 
GRANT succeeded.
 
SQL> GRANT CREATE SESSION TO rw_user IDENTIFIED BY rw_password;
 
GRANT succeeded.
 
. TESTDB1.env
 
sqlplus "/as sysdba"
 
SQL> GRANT CREATE SESSION TO rw_user IDENTIFIED BY rw_password;
 
GRANT succeeded.
 
AS root:
useradd techuser1
useradd techuser2
 
su - techuser1
export ORACLE_HOME=/u01/app/oracle/product/11.2.0/dbhome_1
export PATH=$ORACLE_HOME/bin:$PATH
export TNS_ADMIN=/home/techuser1/oracle/network/admin
mkdir -p oracle/network/admin oracle/network/wallet
 
vi $TNS_ADMIN/sqlnet.ora:
WALLET_LOCATION =
   (SOURCE =
      (METHOD = FILE)
         (METHOD_DATA=
           (DIRECTORY=/home/techuser1/oracle/network/wallet)
         )
    )
 
SQLNET.WALLET_OVERRIDE=TRUE
SSL_CLIENT_AUTHENTICATION=FALSE
 
vi $TNS_ADMIN/tnsnames.ora:
 
TESTDB2_ro =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = oravm1.intra)(PORT = 1522))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = TESTDB2_SITE1)
    )
  )
 
TESTDB2_rw =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = oravm1.intra)(PORT = 1522))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = TESTDB2_SITE1)
    )
  )
 
[techuser1@oravm1 admin]$ tnsping TESTDB2_ro
 
TNS Ping Utility FOR Linux: Version 11.2.0.3.0 - Production ON 01-MAR-2012 11:13:34
 
Copyright (c) 1997, 2011, Oracle.  ALL rights reserved.
 
Used parameter files:
/home/techuser1/oracle/network/admin/sqlnet.ora
 
Used TNSNAMES adapter TO resolve the alias
Attempting TO contact (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = oravm1.intra)
(PORT = 1522)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = TESTDB2_SITE1)))
OK (0 msec)
[techuser1@oravm1 admin]$ tnsping TESTDB2_rw
 
TNS Ping Utility FOR Linux: Version 11.2.0.3.0 - Production ON 01-MAR-2012 11:13:36
 
Copyright (c) 1997, 2011, Oracle.  ALL rights reserved.
 
Used parameter files:
/home/techuser1/oracle/network/admin/sqlnet.ora
 
Used TNSNAMES adapter TO resolve the alias
Attempting TO contact (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = oravm1.intra)
(PORT = 1522)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = TESTDB2_SITE1)))
OK (10 msec)
 
[techuser1@oravm1 admin]$ mkstore -wrl /home/techuser1/oracle/network/wallet -CREATE
Oracle Secret Store Tool : Version 11.2.0.3.0 - Production
Copyright (c) 2004, 2011, Oracle AND/OR its affiliates. ALL rights reserved.
 
Enter password:
Enter password again:
 
mkstore -wrl /home/techuser1/oracle/network/wallet \
 -createCredential TESTDB2_rw rw_user rw_password
 
mkstore -wrl /home/techuser1/oracle/network/wallet \
-createCredential TESTDB2_ro ro_user ro_password
 
[techuser1@oravm1 admin]$ mkstore -wrl /home/techuser1/oracle/network/wallet \
-createCredential TESTDB2_rw rw_user rw_password
Oracle Secret Store Tool : Version 11.2.0.3.0 - Production
Copyright (c) 2004, 2011, Oracle AND/OR its affiliates. ALL rights reserved.
 
Enter wallet password:
CREATE credential oracle.security.client.connect_string1
 
[techuser1@oravm1 admin]$ mkstore -wrl /home/techuser1/oracle/network/wallet \
 -createCredential TESTDB2_ro ro_user ro_password
Oracle Secret Store Tool : Version 11.2.0.3.0 - Production
Copyright (c) 2004, 2011, Oracle AND/OR its affiliates. ALL rights reserved.
 
Enter wallet password:
CREATE credential oracle.security.client.connect_string2
 
[techuser1@oravm1 admin]$ sqlplus /@TESTDB2_rw
SQL*Plus: Release 11.2.0.3.0 Production ON Thu Mar 1 11:19:40 2012
 
Copyright (c) 1982, 2011, Oracle.  ALL rights reserved.
 
Connected TO:
Oracle DATABASE 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
WITH the Partitioning, OLAP, DATA Mining AND REAL Application Testing options
 
SQL> SHOW USER
USER IS "RW_USER"
SQL> quit
Disconnected FROM Oracle DATABASE 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
WITH the Partitioning, OLAP, DATA Mining AND REAL Application Testing options
[techuser1@oravm1 admin]$ sqlplus /@TESTDB2_ro
 
SQL*Plus: Release 11.2.0.3.0 Production ON Thu Mar 1 11:19:45 2012
 
Copyright (c) 1982, 2011, Oracle.  ALL rights reserved.
 
Connected TO:
Oracle DATABASE 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
WITH the Partitioning, OLAP, DATA Mining AND REAL Application Testing options
 
SQL> SHOW USER
USER IS "RO_USER"
 
[techuser1@oravm1 wallet]$ ls -la /home/techuser1/oracle/network/wallet/
total 24
drwxrwxr-x 2 techuser1 techuser1 4096 Mar  1 11:15 .
drwxrwxr-x 4 techuser1 techuser1 4096 Mar  1 11:01 ..
-rw------- 1 techuser1 techuser1 4341 Mar  1 11:17 cwallet.sso
-rw------- 1 techuser1 techuser1 4264 Mar  1 11:17 ewallet.p12
[techuser1@oravm1 wallet]$
 
techuser2 WITH instant client:
 
unzip instantclient-basic-linux.x64-11.2.0.3.0.zip
unzip instantclient-sqlplus-linux.x64-11.2.0.3.0.zip
 
export ORACLE_HOME=/home/techuser2/instantclient_11_2
export PATH=$ORACLE_HOME:$PATH
export TNS_ADMIN=/home/techuser2/oracle/network/admin
export LD_LIBRARY_PATH=$ORACLE_HOME:$LD_LIBRARY_PATH
 
[techuser2@oravm1 ~]$ mkdir -p /home/techuser2/oracle/network/admin
[techuser2@oravm1 ~]$ mkdir -p /home/techuser2/oracle/network/wallet
 
vi $TNS_ADMIN/sqlnet.ora
 
WALLET_LOCATION =
   (SOURCE =
      (METHOD = FILE)
         (METHOD_DATA=
           (DIRECTORY=/home/techuser2/oracle/network/wallet)
         )
    )
 
SQLNET.WALLET_OVERRIDE=TRUE
SSL_CLIENT_AUTHENTICATION=FALSE
 
vi $TNS_ADMIN/tnsnames.ora
 
TESTDB2_ro =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = oravm1.intra)(PORT = 1522))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = TESTDB2_SITE1)
    )
  )
 
TESTDB1 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = oravm1.intra)(PORT = 1522))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = TESTDB1)
    )
  )
 
Test interactive Password:
 
[techuser2@oravm1 instantclient_11_2]$ sqlplus ro_user@TESTDB2_ro
 
SQL*Plus: Release 11.2.0.3.0 Production ON Thu Mar 1 11:28:53 2012
 
Copyright (c) 1982, 2011, Oracle.  ALL rights reserved.
 
Enter password:
 
Connected TO:
Oracle DATABASE 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
WITH the Partitioning, OLAP, DATA Mining AND REAL Application Testing options
 
SQL> quit
 
Problem: no mkstore Tool IN Instantclient
Workaround: CREATE wallet WITH oracle  binaries owner AND copy afterwards
 
[oracle@oravm1 ~]$ mkdir /tmp/wallet
[oracle@oravm1 ~]$  /u01/app/oracle/product/11.2.0/dbhome_1/bin/mkstore \
-wrl /tmp/wallet -CREATE
Oracle Secret Store Tool : Version 11.2.0.3.0 - Production
Copyright (c) 2004, 2011, Oracle AND/OR its affiliates. ALL rights reserved.
 
Enter password:
Enter password again:
[oracle@oravm1 ~]$
[oracle@oravm1 ~]$
[oracle@oravm1 ~]$
[oracle@oravm1 ~]$
[oracle@oravm1 ~]$ /u01/app/oracle/product/11.2.0/dbhome_1/bin/mkstore \
-wrl /tmp/wallet -createCredential TESTDB2_ro ro_user ro_password
Oracle Secret Store Tool : Version 11.2.0.3.0 - Production
Copyright (c) 2004, 2011, Oracle AND/OR its affiliates. ALL rights reserved.
 
Enter wallet password:
 
CREATE credential oracle.security.client.connect_string1
[oracle@oravm1 ~]$ /u01/app/oracle/product/11.2.0/dbhome_1/bin/mkstore \
-wrl /tmp/wallet -createCredential TESTDB1 rw_user rw_password
Oracle Secret Store Tool : Version 11.2.0.3.0 - Production
Copyright (c) 2004, 2011, Oracle AND/OR its affiliates. ALL rights reserved.
 
Enter wallet password:
CREATE credential oracle.security.client.connect_string2
 
[techuser2@oravm1 wallet]$ ls -al
total 28
drwxr-xr-x  2 oracle oinstall 4096 Mar  1 11:32 .
drwxrwxrwt 31 root   root     4096 Mar  1 11:32 ..
-rw-------  1 oracle oinstall 4333 Mar  1 11:33 cwallet.sso
-rw-------  1 oracle oinstall 4256 Mar  1 11:33 ewallet.p12
 
[root@oravm1 techuser2]# chown -R techuser2:techuser2 /tmp/wallet
 
[root@oravm1 techuser2]# ls -la /tmp/wallet/
total 28
drwxr-xr-x  2 techuser2 techuser2 4096 Mar  1 11:32 .
drwxrwxrwt 31 root      root      4096 Mar  1 11:35 ..
-rw-------  1 techuser2 techuser2 4333 Mar  1 11:33 cwallet.sso
-rw-------  1 techuser2 techuser2 4256 Mar  1 11:33 ewallet.p12
 
[techuser2@oravm1 wallet]$ pwd
/home/techuser2/oracle/network/wallet
[techuser2@oravm1 wallet]$ mv /tmp/wallet/* .
[techuser2@oravm1 wallet]$ ls -la
total 24
drwxrwxr-x 2 techuser2 techuser2 4096 Mar  1 11:36 .
drwxrwxr-x 4 techuser2 techuser2 4096 Mar  1 11:25 ..
-rw------- 1 techuser2 techuser2 4333 Mar  1 11:33 cwallet.sso
-rw------- 1 techuser2 techuser2 4256 Mar  1 11:33 ewallet.p12
 
[techuser2@oravm1 wallet]$ sqlplus /@TESTDB2_ro
 
SQL*Plus: Release 11.2.0.3.0 Production on Thu Mar 1 11:36:58 2012
 
Copyright (c) 1982, 2011, Oracle.  All rights reserved.
 
Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
 
SQL> show user
USER is "RO_USER"
SQL> quit
 
[techuser2@oravm1 wallet]$ sqlplus /@TESTDB1
 
SQL*Plus: Release 11.2.0.3.0 Production on Thu Mar 1 11:38:06 2012
 
Copyright (c) 1982, 2011, Oracle.  All rights reserved.
 
Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
 
SQL> show user
USER is "RW_USER"

Referenz:



Bug: ORA-4031 for subheap “KTC latch subh” in 11.2.0.3

I just saw MOS Note

ORA-4031 After Upgrade From 11.2.0.1 To 11.2.0.3 With Leak in ‘KTC latch subh’ Subheaps [ID 1398984.1]

giving very little information about this bug. At the time of this writing, there is no patch available but I expect it to be in a few days. I have checked some 11.2.0.3 instances and found only one with > 60 MB for this subheap.



Oracle SCN Problem

In case you have not heard all the buzz about the Oracle SCN flaw, which was published by Infoworld after the release of January CPU, I summarize the essentials.

  • There is a risk that the SCN reaches it´s maximum value and this could lead to an outage of the database.
  • There is a bug in “ALTER DATABASE BEGIN BACKUP”, which increases the SCN dramatically. (Bug 12371955 – fixed in 11.2.0.2.4 and others)
  • When you query a remote database via database link from a database with elevated SCN, the remote SCN gets increased to the higher value as well. This has the dramatic effect, that a database will infect the other database.
  • Imagine an unpatched environment with user-managed online backups (e.g. for SAN split mirror technology) and dozens of interconnected databases with database links.
  • Now imagine an evil employee with this little innocent database account with only “create session” privilege  … you get the picture.
  • The January 2012 CPU/PSU contains a patch that should restrict the ways to increase the SCN. However, I am not sure that the issue with db links is solved. I could bump up the SCN to 12562779343042 by a remote select even after patching with CPU January 2012.

Additionally, there are already quite a few articles showing how a potential attacker could use this flaw, e.g. this one.

References:

  • Information on the System Change Number (SCN) and how it is used in the Oracle Database [ID 1376995.1]
  • Installing, Executing and Interpreting output from the “scnhealthcheck.sql” script [ID 1393363.1]
  • Bug 12371955 – Backup task can cause increased SCN growth rate leading to ORA-600 [2252] errors [ID 12371955.8]


RDBMS 11.2.0.2: unrecoverable operations of Compression Advisor running daily

At one of my customers, we wondered about some entries in v$datafile.unrecoverable_change# for the most critical tablespace of the application. Certainly no application components were allowed to perform nologging operations for segments inside this tablespace and yet there was evidence that “something” was done with nologging.

  • The unrecoverable_time was shortly after 10 pm
  • The ASH data covering this time period showed activity by DBMS_SCHEDULER and Autotask Jobs.
  • An internal DDL log table showed the following operations:
CREATE TABLE "MYOWNER".DBMS_TABCOMP_TEMP_UNCMP
tablespace "DAT_MYOWNER" nologging
AS
SELECT /*+ FULL("MYOWNER"."MYTAB") */ *  FROM "MYOWNER"."MYTAB"  sample block( 3.55) mytab ;   
 
CREATE TABLE "MYOWNER".DBMS_TABCOMP_TEMP_CMP ORGANIZATION HEAP
TABLESPACE "DAT_MYOWNER"
COMPRESS FOR ALL OPERATIONS
NOLOGGING
AS
SELECT  * FROM "MYOWNER".DBMS_TABCOMP_TEMP_UNCMP MYTAB;
 
DROP TABLE "MYOWNER".DBMS_TABCOMP_TEMP_UNCMP PURGE;
DROP TABLE "MYOWNER".DBMS_TABCOMP_TEMP_CMP purge;

Summary:

I find it suboptimal that Compression Advisor is executed on a daily basis during the maintenance window and that the Compression Advisor can not be seperately disabled without also disabling the Segment Advisor. (Although there is supposed to be an enhancement request open for this.)

In addition to that, it is more than problematic that the is using the user tablespace, which could lead to tablespace pressure and that the operations are performed as unrecoverable and therefore logged in v$datafile.unrecoverable_time, overwriting potential important information of real “user” operations performing with NOLOGGING.

More information about Compression Advisor can be found in MOS Note: How Does Compression Advisor Work? [ID 1284972.1]



Workaround for ORA-600/ORA-7445 with SQL Repair Advisor

From time to time we hit Errors like ORA-600 or ORA-7445, which are triggered by specific SQL statements. For these cases, Oracle developed the SQL Repair Advisor. This is a short demonstration of utilizing the SQL Repair Advisor to avoid ORA-7445 caused by a SQL statement.

SQL and Error:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
SELECT
EXTRACT(YEAR FROM date_new) jahr,
EXTRACT(MONTH FROM date_new) monat,
COUNT(DISTINCT TRUNC(date_new)) arbeitstage,
SUM(CASE WHEN STRING1 IN (SELECT STRING1
FROM MD.MD1
WHERE STRING1_GROUP = 'CUST')
THEN
DECODE(FLAG, 'J', 1, 0)
ELSE
0
END) cust_flag
FROM
SCHEMA.TAB1
WHERE
date_new BETWEEN TO_DATE(201101, 'yyyymm')
AND ADD_MONTHS(TO_DATE(201107, 'yyyymm'), 1)
GROUP BY
EXTRACT(YEAR FROM date_new),
EXTRACT(MONTH FROM date_new)
ORDER BY 1,2;
 
ERROR at line 6:
ORA-03113: end-of-file ON communication channel
Process ID: 7746
SESSION ID: 737 Serial NUMBER: 9823
 
Tue Jul 26 15:19:41 2011
Exception [TYPE: SIGSEGV, Address NOT mapped TO object] [ADDR:0xA] [PC:0x888A3C9, xtyqbcb()+413] ...
ORA-07445: exception encountered: core dump [xtyqbcb()+413] [SIGSEGV] [ADDR:0xA] [PC:0x888A3C9]...

Execution of SQL Repair Advisor:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
DECLARE
  rep_out CLOB;
  t_id VARCHAR2(50);
BEGIN
  T_ID := DBMS_SQLDIAG.CREATE_DIAGNOSIS_TASK( 
  sql_text => q'#SELECT
EXTRACT(YEAR FROM date_new) jahr,
EXTRACT(MONTH FROM date_new) monat,
COUNT(DISTINCT TRUNC(date_new)) arbeitstage,
SUM(CASE WHEN STRING1 IN (SELECT STRING1
FROM MD.MD1
WHERE STRING1_GROUP = 'CUST')
THEN
DECODE(FLAG, 'J', 1, 0)
ELSE
0
END) cust_flag
FROM
SCHEMA.TAB1
WHERE
date_new BETWEEN TO_DATE(201101, 'yyyymm')
AND ADD_MONTHS(TO_DATE(201107, 'yyyymm'), 1)
GROUP BY
EXTRACT(YEAR FROM date_new),
EXTRACT(MONTH FROM date_new)
ORDER BY 1,2#', 
  task_name => 'ORA7445-xtyqbcb', 
  problem_type =>DBMS_SQLDIAG.PROBLEM_TYPE_COMPILATION_ERROR
  );
  DBMS_SQLDIAG.EXECUTE_DIAGNOSIS_TASK (t_id);
  rep_out := DBMS_SQLDIAG.REPORT_DIAGNOSIS_TASK (t_id, DBMS_SQLDIAG.TYPE_TEXT);
  DBMS_OUTPUT.PUT_LINE ('Report : ' || rep_out);
END;
/
 
<strong>Output:</strong>
 
Report : GENERAL INFORMATION SECTION
-------------------------------------------------------------------------------
Tuning Task Name   : ORA7445-xtyqbcb
Tuning Task Owner  : SYS
Workload TYPE      : Single SQL Statement
Scope              : COMPREHENSIVE
TIME LIMIT(seconds):
1800
Completion STATUS  : COMPLETED
Started at         : 07/26/2011 15:46:38
Completed at       : 07/26/2011 15:46:38
 
-------------------------------------------------------------------------------
Schema Name: SYS
SQL ID     : 39ac71hjcn0rt
...
 
-------------------------------------------------------------------------------
FINDINGS SECTION (1
finding)
-------------------------------------------------------------------------------
 
1- SQL Patch Finding (see EXPLAIN plans SECTION below)
------------------------------------------------------
  A potentially better execution plan was found FOR this statement.
 
  Recommendation
 
 
--------------
  - Consider accepting the recommended SQL patch.
    EXECUTE dbms_sqldiag.accept_sql_patch(task_name =>
            'ORA7445-xtyqbcb', task_owner => 'SYS', REPLACE => TRUE);
 
  Rationale
  ---------
    Recommended plan WITH hash VALUE 1503213169 has NUMBER OF ROWS 7, CHECK
 
SUM 13925076401, execution TIME 264 AND 1972 buffer gets
 
-------------------------------------------------------------------------------
 
 
 
PL/SQL PROCEDURE successfully completed.

Activation:

1
2
3
4
5
6
 BEGIN dbms_sqldiag.accept_sql_patch(
      task_name =>'ORA7445-xtyqbcb', 
      task_owner => 'SYS', 
      REPLACE => TRUE);
END;
/

Test:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
SELECT
EXTRACT(YEAR FROM date_new) jahr,
EXTRACT(MONTH FROM date_new) monat,
COUNT(DISTINCT TRUNC(date_new)) arbeitstage,
SUM(CASE WHEN STRING1 IN (SELECT STRING1
FROM MD.MD1
WHERE STRING1_GROUP = 'CUST')
THEN
DECODE(FLAG, 'J', 1, 0)
ELSE
0
END) cust_flag
FROM
SCHEMA.TAB1
WHERE
date_new BETWEEN TO_DATE(201101, 'yyyymm')
AND ADD_MONTHS(TO_DATE(201107, 'yyyymm'), 1)
GROUP BY
EXTRACT(YEAR FROM date_new),
EXTRACT(MONTH FROM date_new)
ORDER BY 1,2;
 
      JAHR      MONAT ARBEITSTAGE CUST_FLAG
---------- ---------- ----------- ----------------
      2011          1          20                0
 
 
7 ROWS selected.
 
SQL> SELECT * FROM TABLE(dbms_xplan.display_cursor(NULL,NULL,'ADVANCED'));
 
PLAN_TABLE_OUTPUT
---------------------
SQL_ID  5wdztx81x0r8f, child NUMBER 0
-------------------------------------
 
 
Plan hash VALUE: 1503213169
 
-----------------------------------------------------------------------------------------------
| Id  | Operation          | Name             | ROWS  | Bytes |TempSpc| Cost (%CPU)| TIME     |
-----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |                  |       |       |       |   591 (100)|          |
|*  1 |  TABLE ACCESS FULL | MD1              |     1 |    12 |       |     3   (0)| 00:00:01 |
|   2 |  SORT GROUP BY     |                  | 27402 |   294K|  2776K|   591  (12)| 00:00:02 |
|*  3 |   TABLE ACCESS FULL| TAB1             |   117K|  1260K|       |   369  (10)| 00:00:01 |
-----------------------------------------------------------------------------------------------
 
 
...
 
 
Note
-----
   - SQL patch "SYS_SQLPTCH_013166b4fb2a0001" used FOR this statement
 
 
66 ROWS selected.

Removal of SQL Patch:

1
EXEC DBMS_SQLDIAG.DROP_SQL_PATCH ('SYS_SQLPTCH_013166b4fb2a0001');

Deletion of SQL Diag Task:

1
 EXEC DBMS_SQLDIAG.DROP_DIAGNOSIS_TASK ('ORA7445-xtyqbcb');


Performance Degradation for Query on DBA_SEGMENTS.BYTES in 11gR2

I have been troubleshooting a performance issue in a DWH environment, which is quite interesting. It was a query on DBA_SEGMENTS in 11gR2 with lots of partitions and it was taking almost 10 minutes versus only a few seconds in 10gR2. The problem could be stripped downt to this SQL query:

select bytes from dba_segments

The dba_segment view can be seen in DBA_VIEWS:

SELECT ...
       decode(bitand(segment_flags, 131072), 131072, blocks,
           (decode(bitand(segment_flags,1),1,
            <strong>dbms_space_admin.segment_number_blocks</strong>(tablespace_id, relative_fno,
            header_block, segment_type_id, buffer_pool_id, segment_flags,
            segment_objd, blocks), blocks)))*blocksize,
      ...
FROM sys_dba_segs

The response time was dominated by Waits for “db file sequential reads” taking almost all of the response time.

11gR2:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch    12563     23.17     546.74     157447     580414          1      188421
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total    12565     23.17     546.74     157447     580414          1      188421

10gR2:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.06       0.06          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch     5104      1.77       2.54          0      96688          0       76542
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total     5106      1.83       2.61          0      96688          0       76542

The 10046 Trace File contains more data regarding those waits:

WAIT #4: nam='db file sequential read' ela= 134 file#=21 block#=2313482 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 120 file#=15 block#=2128019 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 128 file#=21 block#=2313490 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 372 file#=21 block#=2313498 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 108 file#=21 block#=2313506 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 130 file#=21 block#=2313514 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 132 file#=21 block#=2313522 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 121 file#=21 block#=2313530 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 158 file#=15 block#=2128003 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 146 file#=21 block#=2313538 blocks=1 obj#=-1 
WAIT #4: nam='db file sequential read' ela= 116 file#=21 block#=2313546 blocks=1 obj#=-1 
(Output modified for formatting)

Strange thing that obj# is -1. I made some block dumps of those blocks and found out that all those blocks (file#/block#) have something in common: They were all segment header blocks. Another strange thing was that when the query was executed a second time, all those I/O requests were performed again – so no caching.

At that point, I opened a Support service request. After a couple of weeks, Support suggested running this for each tablespace of the user segments:

EXEC  dbms_space_admin.TABLESPACE_FIX_SEGMENT_EXTBLKS('<tablespace_name>');

Finally this fixed the problem. Now, we are trying to find out why this was necessary for a database, that was freshly created with dbca 11.2.0.2 from the seeded template and filled with data pump import.



Data Guard 11.2.0.2 – update

In March, Oracle MAA has published a white paper for implementing Data Guard on Exadata platforms. (http://www.oracle.com/technetwork/database/features/availability/maa-wp-dr-dbm-130065.pdf)

Although the paper is focused on Exadata, some information can be applied to non-Exadata systems as well:

  • Corruption Protection:
    • Primary:
      • DB_BLOCK_CHECKSUM=FULL,
      • DB_BLOCK_CHECKING=FULL,
      • DB_LOST_WRITE_PROTECT=TYPICAL
    • (Physical) Standby:
      • DB_BLOCK_CHECKSUM=FULL,
      • DB_BLOCK_CHECKING=OFF,
      • DB_LOST_WRITE_PROTECT=TYPICAL
  • Network Tuning:
    TCP Send/Receive Buffers: 3 x Bandwith Delay Product or 10 MB, whichever is greater
  • Redo Transport Modes:
    • SYNC is recommended if round-trip-time is less than 5 ms.  Impact of SYNC Mode on primary performance has been improved because local online redo log write and redo shipping is not done sequentially anymore but in parallel.
    • ASYNC: Transport Lag is reduced because Redo is not read from online redo log from disk but from log buffer if possible. init.ora log_buffer might need to be increased for this to yield the maximum benefit.
  • LOGGING/NOLOGGING: Normally, in Data Guard you set database-wide “ALTER DATABASE FORCE LOGGING”. In Data Warehouse environments, it might be advisable to set it to NOLOGGING and decide on a tablespace-basis whether the tablespace should allow or disallow NOLOGGING operations. E.g. a tablespace containing only transient, recreatable  or non-critical data might benefit from being set to NOLOGGING for certain bulk operations. (CTAS, Direct Path Inserts, index rebuilds, etc.)
  • STANDBY-FIRST Patches: Some patches (PSU, CPU, PSE) will be flagged in the patch README with “Standby-First”. This means that they can be applied on a physical standby before being applied on the primary. For regular patches, this was not supported.


Using Grid Control Repository for RDBMS Patch Report

I was looking for a method to utilize the Grid Control Repository, which contains information about installed Oracle Homes, databases and patches, for a patch report.

With a little reverse engineering i came up with these relevant tables:

  • Mgmt_Ecm_Snapshot: Every time the inventory is refreshed, a new line is inserted into this table containing the host name and the snapshot_guid. The most current snapshot has flag IS_CURRENT set to ‘Y’
  • Mgmt_Inv_Container: Every Oracle Home is a container. This table contains the snapshot_guid and the container_guid along with a container_description which is basically the Oracle Home Path
  • Mgmt_Inv_Patch: This table contains container_guid, Patch ID and patch installation timestamp
  • Mgmt_Inv_Component: This table lists all the components of the oracle homes along with their version. There is one component per container with the flag Is_Top_Level set to ‘Y’.  We use this component for getting the base version of the installed product. (e.g. 11.2.0.2)
  • Mgmt_Inv_Versioned_Patch: I am not sure if this table is needed for version information, but one of the mgmt views was using these two tables together, so I used it as a reference.

The complete statement now is:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
CREATE OR REPLACE FORCE VIEW "SYSMAN"."RDBMS_PATCH_REPORT"
AS
SELECT
      N.Target_Name,
    S.Start_Timestamp AS Collected_Time,
    S.Target_Name     AS Host_Name,
    C.Container_Name  AS Oracle_Home_Name,
    Container_Location,
    P.Id AS Patch_Id,
    (
    CASE Id
      WHEN '10157506'
      THEN 'GI Bundle1'
      WHEN '10185523'
      THEN 'OWB Bundle'
      WHEN '10248523'
      THEN 'PSU Jan 2011'
      WHEN '11724916'
      THEN 'PSU Apr 2011'
      WHEN '12311357'
      THEN 'GI Psu Apr 2011'
      ELSE NULL
    END ) description,
    P.Timestamp AS Install_Time,
    CASE
      WHEN VP.version IS NULL
      THEN M.version
      ELSE VP.version
    END AS Version
  FROM Mgmt_Ecm_Snapshot S,
    Mgmt_Inv_Container C,
    Mgmt_Inv_Patch P,
    (SELECT T.Target_Guid,
      T.Host_Name,
      T.Target_Name,
      T.Target_Type,
      Mp.Property_Value AS Oh
    FROM Mgmt_Targets T,
      Mgmt_Target_Properties Mp
    WHERE T.Target_Guid  = Mp.Target_Guid
    AND Mp.Property_Name = 'OracleHome'
    AND Target_Type      = 'oracle_database'
    ) N,
    Mgmt_Inv_Component M ,
    MGMT_INV_VERSIONED_PATCH VP
  WHERE S.Snapshot_Guid = C.Snapshot_Guid
  AND S.Is_Current      = 'Y'
  AND C.Container_Type  = 'O'
  AND P.Container_Guid  = C.Container_Guid
  AND N.Host_Name       = S.Target_Name
  AND N.Oh              = C.Container_Location
  AND M.Component_Guid  = Vp.Component_Guid(+)
  AND M.Is_Top_Level    = 'Y'
  AND M.Container_Guid  = C.Container_Guid
  ORDER BY 1,2,3;


Is 11.2.0.2 ready for production? Judge yourself …

Murphy said: if problems arise, they all come at the same time. After several weeks of stability, this week brought hell of a lot of Oracle problems with 11.2.0.2 and RAC. To list the worst:

  • Downtime because of ASM process limit reached. Normally, the formula to calculate depends on the number of concurrent datafile extensions. In our case 100 ASM processes were not enough. Increased to 200 and found  Note 1287496.1 which describes the issue. Merge Patch for bug is available for 11.2.0.2 GI Bundle 1 but not yet for GI Bundle 2. Ups.
  • CPU Starvation because of Adaptive Cursor Sharing: One server process was taking up 100% of cpu time for the last several hours. It turned out to be an OEM monitoring query having several thousands of child cursors.
    PID 	USER 	PR NI VIRT 	RES SHR S %CPU %MEM TIME+ COMMAND
    8667 	ora11 25 0 	8423m 33m 28m R 99.7 	0.1 358:27.78 ora_pz98_MDDB

    I then checked different databases and found that almost all of our 11.2.0.2 databases have several hundreds or even thousands of child cursors.

    SELECT sql_id, is_shareable, MIN(child_number), MAX(child_number), COUNT(*)
    FROM gv$sql
    GROUP BY sql_id, is_shareable HAVING COUNT(*) &gt;100 ORDER BY 6 DESC
     
    SQL_ID        IS_SHAREABLE MIN(CHILD_NUMBER) MAX(CHILD_NUMBER)  COUNT(*)
    ------------- ------------ ----------------- ------------------ ---------
    c7kt3njhnmtkm Y            0                 5097               1397
    c7kt3njhnmtkm N            3                 3544               1836
    1vnhgmpc17vv0 Y            0                 3022               2697
    1vnhgmpc17vv0 N            6                 2185               444
    93qh89pxuxzuw Y            0                 1949               1522
    93qh89pxuxzuw N            2                 1625               428
    5fk0v8km2f811 Y            0                 1281               1763
    4f3ufvfcgfqsg Y            0                 792                794
    cjbwk0ww7j5rv Y            0                 627                1251
    dyqdzgxcv4d3t Y            0                 626                1252
    5fk0v8km2f811 N            3                 543                260
    f0jxh8d6b5af2 Y            0                 494                564
    f0jxh8d6b5af2 N            0                 290                130
    dbvkky621gqtr Y            0                 266                267
    32rqmpqpfv0gm Y            0                 255                257
    g9uwxs7pr8tjm Y            0                 254                257
    40k6jjt90n4fa Y            3                 199                129

    I suspect this to be Bug 10182051 Extended cursor sharing generates many shareable child cursors and there is a workaround:

    alter system set “_optimizer_extended_cursor_sharing_rel”=none;

  • Limited database availability because of failing queries on gv$ tables:
    SQL> select count(*) from gv$session
    2 ;
    select count(*) from  gv$session
    *
    ERROR at line 1:
    ORA-12850: Could not allocate slaves on  all specified instances: 2 needed, 1
    allocated
    ORA-12801: error signaled  in parallel query server P001, instance 3599

    Currently no other known workaround than bouncing all the RAC instances.

  • DataGuard ASYNC Redo Transport not reliable: We have a RAC primary / single instance physical standby setup and use async redo transport. During times of heavy ETL on the primary, the standby databases stops at recovery of one archivelog with “(in transit)”. Primary is showing this error in alert log:
    ARC7: Creating remote archive destination LOG_ARCHIVE_DEST_2: 'HAMDB' (thread 2 SEQUENCE 4044) (MUCDB2)
    ARC7: Archive log rejected (thread 2 SEQUENCE 4044) at host 'HAMDB'
    FAL[server, ARC7]: FAL archive failed, see trace file.
    ARCH: FAL archive failed. Archiver continuing
    ORACLE Instance MUCDB2 - Archival Error. Archiver continuing.

    On standby side, it says:
    Media Recovery Waiting for thread 2 sequence 4044 (in transit)

    The standby database never recovers from this problem, except when standby database is bounced. The problem appears with and without broker configuration. Currently there is no known workaround.

Maybe some of this issues will be addressed in upcoming PSU April, which will be released this week.



Recyclebin Bug – ORA-600 [ktcdso-1] on Oracle 11.2.0.2.1

Just a short note:

If you are using 11.2.0.2 and 11.2.0.2.1, chances are high that database stability is endangered because of massive ORA-600 [ktcdso-1], unless you have recyclebin deactived with init.ora recyclebin=off.

Oracle is currently working on this issue with Bug 10427260: ORA-00600 [KTCDSO-1], [], [], [] WHEN PURGE RECYCLE BIN.

Unfortunately, the instance has to be bounced in order to deactivate recyclebin.