This blog contains experience gained over the years of implementing (and de-implementing) large scale IT applications/software.

Kill All Oracle Sessions For Specific User – 11gR2

Here’s a small script to display, then kill all sessions in an Oracle 11gR2 database for a specific username.

First let’s check the sessions of the specific username:

NOTE: Change “<USER NAME HERE>” in both blocks of code, for the actual username to be killed.

SQL> set serveroutput on size 10000;
SELECT sid,serial#
  FROM v$session
WHERE username = '<USER NAME HERE>';

Now run the code to kill the user sessions:

SQL> DECLARE
   dummy NUMBER;
   c     NUMBER := dbms_sql.open_cursor;
BEGIN
   FOR c1_row IN (SELECT sid,serial#
                  FROM v$session
                  WHERE username = '<USER NAME HERE>') LOOP
      DBMS_OUTPUT.PUT_LINE('Killing session: '||c1_row.sid||' serial#: '||c1_row.serial#);
      DBMS_SQL.PARSE(c,'alter system kill session '||''''||c1_row.sid||','||c1_row.serial#||'''',dbms_sql.NATIVE);
      dummy := DBMS_SQL.EXECUTE(c);
      DBMS_OUTPUT.PUT_LINE('Session: '||c1_row.sid||' serial#: '||c1_row.serial#||' killed.');
   END LOOP;

   dbms_sql.close_cursor(c);
EXCEPTION
   WHEN OTHERS THEN
      DBMS_OUTPUT.PUT_LINE(SUBSTR(SQLERRM,1,250));
END;
/

You can now run the check code again to see that all sessions for the user have been killed.

Oracle 11g Transparent Data Encrpytion (TDE) Tablespace Conversion Script

After needing to configure and setup an Oracle tablespace in an 11g database so that it was encrypted with Transparent Data Encryption (TDE), I devised a scripted method of doing this quickly and simply.

The script is hardcoded to only work on a tablespace called “USERS_TDE” at the moment, but if you find and replace this for your specific tablespaces. I’ve even included commented out code showing how to do more than one tablespace at a time.

You should also change the disk locations within the script for the location of the export/import dump files and the wallet file location.
As per the Oracle docs, the wallet file is stored outside of the Oracle home in /etc/ORACLE.

The basic process is:

  • Create wallet dir.
  • Adjust sqlnet.ora.
  • Create dpump dir.
  • Export tablespace data.
  • Export tablespace DDL metadata.
  • Adjust tablespace DDL to include TDE commands.
  • Enable TDE encryption at database level (sets the enc key).
  • Offline & drop existing tablespace.
  • Create TDE version of tablespace.
  • Import tablespace data.

!/bin/bash
#############################################################################
# Author: D.Griffiths
# Script: oracle_TDE_encrypt.sh
# Params: None.
# RunAs:  Oracle home owner.
# Desc:   Script to automatically export a tablespace called USERS_TDE

#         (change as you wish), drop it, re-create it ENCRYPTED with TDE
#         then re-import the data objects back into the tablespace.
#
# HISTORY ###################################################################
# v1.0, Created.
#############################################################################

# Variable definitions.
wallet_dir="/etc/ORACLE/WALLETS/$ORACLE_SID"
walletpw=""
dp_dir="/data/backup/tblspace_export_pre_TDE/$ORACLE_SID" # Datapump export/import dir.

# Check required variables.
if [ -z "$ORACLE_SID" -o `grep -c "^$ORACLE_SID:" /etc/oratab` -ne 1 ] ; then
   echo "ERROR: Invalid ORACLE_SID."
   exit 1;
fi

if [ -z "$ORACLE_HOME" ] ; then
   export ORACLE_HOME = "`awk '/'$ORACLE_SID'/ { split($0,a,":"); print a[2] }' /etc/oratab`"

   if [ -z "$ORACLE_HOME" ] ; then
      echo "ERROR: Failed to set ORACLE_HOME."
      exit 1;
   fi
fi

# Show setup.
echo "------------------------------------------"
echo "Starting TDE setup script."
date
echo "The following has been defined:"
echo " ORACLE_SID : $ORACLE_SID"
echo " ORACLE_HOME : $ORACLE_HOME"
echo " WALLET DIR : $wallet_dir"
echo " DATAPUMP DIR: $dp_dir"
echo "------------------------------------------"
echo " "

# Check if DB already has wallet/encryption.
retval="`sqlplus -s "/ as sysdba" <<EOF
set head off
set newpage none
set feedback off
set trimout on
set tab on
select DECODE(count(status),0,'NONE','SOME') from v\$wallet;
EOF`"

if [ "$retval" != "NONE" ] ; then
   echo "ERROR: Encryption may already be enabled on this database."
   exit 1;
 else
   echo "Encryption is not already enabled on this database."
fi

# Check for existence of Wallet Dir.
if [ ! -d $wallet_dir ] ; then
   mkdir -p $wallet_dir
   if [ $? -ne 0 ] ; then
      echo "ERROR: Failed to create wallet dir $wallet_dir"
      exit 1;
   fi
   

   echo "WALLET directory created: $wallet_dir"
 else
   echo "WARNING: Wallet directory already exists:"
   echo "$wallet_dir"
   echo -n "Continue to use this? {Y|N} : "
   read reply
   if [ "$reply" != "Y" -a "$reply" != "y" ] ; then
      exit 1;
   fi
 

   echo "Using wallet dir: $wallet_dir"
fi
 

if [ ! -d $dp_dir ]; then
   mkdir -p $dp_dir;
   if [ $? -ne 0 ] ; then
      echo "ERROR: Failed to create datapump dir $dp_dir"
      exit 1;
   fi
 else
   echo "ERROR: Datapump dir already exists, files can not be overwritten."
   echo "Check: $dp_dir"
   exit 1;
fi

# Check sqlnet.ora file.
if [ "`grep -c '^ENCRYPTION_WALLET_LOCATION' $ORACLE_HOME/network/admin/sqlnet.ora`" -ne 1 ] ; then
   echo "Adding ENCRYPTION_WALLET_LOCATION to sqlnet.ora in $ORACLE_HOME/network/admin/sqlnet.ora"
   cat <<EOF >>$ORACLE_HOME/network/admin/sqlnet.ora
# Added WALLET location for TDE see 1228046.1.
ENCRYPTION_WALLET_LOCATION =
(SOURCE = (METHOD = FILE)
(METHOD_DATA =
(DIRECTORY = ${wallet_dir}/)))
EOF

   if [ $? -ne 0 ] ; then
      echo "ERROR: Failed to update sqlnet.ora."
      exit 1;
   fi
 else
   echo "Section ENCRYPTION_WALLET_LOCATION already exists in sqlnet.ora"
fi

# Get list of unencrypted non-system tablespaces
list_tblspace="`sqlplus -s "/ as sysdba" <<EOF
ttitle off
btitle off
set newpage none
set feedback off
set head off
set wrap off
set trim on
set tab on
set linesize 30
set pagesize 1000
-- select rpad(UPPER(t.name),30)
-- from v$tablespace t
-- where t.name not in ('SYSTEM','SYSAUX','UNDO','TEMP')
-- and t.ts# not in (select ts# from v$encrypted_tablespaces);
select rpad('USERS_TDE',30) from dual;
EOF`"

# Confirm tablespaces.
echo " "
echo "The following non-system unencrypted tablespaces have been found:"
echo "$list_tblspace"
echo -n "Setup these for TDE? {Y|N} : "
read reply

if [ "$reply" != "Y" -a "$reply" != "y" ] ; then
   exit 1;
fi

# Check dbdump oracle directory doesnt exist.
retval="`sqlplus -s "/ as sysdba"<<EOF
set head off
set newpage none
set feedback off
set trimout on
set tab on
select trim(directory_path) from dba_directories
where directory_name='DPDUMP_BACKUP';
EOF`"

if [ -n "$retval" ] ; then
   echo "WARNING: Oracle directory DPDUMP_BACKUP already exists."
   echo "It is assigned to path: $retval"
   echo "OK to recreate it to $dp_dir"
   echo -n "Enter {Y|N} : "
   read reply
   if [ "$reply" != "Y" -a "$reply" != "y" ] ; then
      exit 1;
   fi
fi

# Create the datapump export/import dir in oracle.
sqlplus -s "/ as sysdba" <<EOF
create or replace directory dpdump_backup as '$dp_dir';
EOF

echo "------------------------------------------"
echo "Exporting tablespaces and generating DDL."

# Export the tablespaces to the backup directory location and generate DDL.
echo "$list_tblspace" | while read tablespace
do
   expdp userid="'/ as sysdba'" dumpfile=$tablespace.dmp directory=dpdump_backup logfile=${tablespace}_exp.log tablespaces="$tablespace"

   # Generate the tablespace creation DDL to the backup directory location.
   sqlplus -s "/ as sysdba" << EOF
SET LONG 10000
set head off
set newpage none
set trimspool on
spool $dp_dir/cre_$tablespace.sql
SELECT dbms_metadata.get_ddl('TABLESPACE','$tablespace') FROM DUAL;
SPOOL OFF
EOF

   # Adjust the DDL file to include the ENCRYPTION string.
   cat $dp_dir/cre_$tablespace.sql | grep -e '^.*[A-Z0-9]' > $dp_dir/cre_TDE_$tablespace.sql

   echo " ENCRYPTION using 'AES256'" >> $dp_dir/cre_TDE_$tablespace.sql
   echo " STORAGE (ENCRYPT)" >> $dp_dir/cre_TDE_$tablespace.sql
 

done

########### ENABLE ENCRYPTION FROM HERE ON IN ################################

while [ -z "$walletpw" ] ; do
   echo -n "Enter the wallet encryption key to use: "
   read walletpw
   echo -n " Re-enter the wallet encryption key: "
   read reply
   if [ "$walletpw" != "$reply" ] ; then
      echo "WARNING: Typed keys do not match."
      echo -n "Try again? {Y|N} : "
      read reply
      if [ "$reply" != "Y" -a "$reply" != "y" ] ; then
         exit 1;
      fi
      walletpw=""
   fi

done

# Alter the DB to enable encryption.
sqlplus "/ as sysdba" << EOF
alter system set encryption key identified by "$walletpw";
EOF

if [ $? -ne 0 ] ; then
   echo "WARNING: Enabling encryption may have failed in the DB."
   exit 1;
fi

# Change permissions on all files in the wallet dir.
chmod 600 "$wallet_dir/*"

# Offline and then drop the tablespace and datafiles.
# WARNING: You should have a backup at this point.
echo "WARNING: About to offline and drop tablespaces:"
echo "$list_tblspace"
echo "##################################################"
echo "You should check the expdp export logs in $dp_dir."
echo "##################################################"

echo -n "Continue? [Y|N]: "
read reply
if [ "$reply" != "Y" -a "$reply" != "y" ]; then
   echo "Cancelling."
   exit 1
fi

# Offline and drop each tablespace (including datafiles) then re-create and import export dump file.
echo "$list_tblspace" | while read tablespace
do
   sqlplus "/ as sysdba" << EOF
alter tablespace $tablespace offline;
drop tablespace $tablespace including contents and datafiles;
@$dp_dir/cre_TDE_$tablespace.sql
-- @$dp_dir/cre_$tablespace.sql <<-- Recreates original non-TDE tablespace.
/
EOF

   impdp userid="'/ as sysdba'" dumpfile=$tablespace.dmp directory=dpdump_backup logfile=${tablespace}_imp.log tablespaces="$tablespace"

done

echo "#######################################################"
echo "You should enable auto-open of the wallet if necessary."
date
echo "End of script."
############################################################################

SQL_OPCODE values from an 11gR2 Database

If you have a need to find the actual numeric operation code for different SQL operations, then this is possible if you can access the ASH table as highlighted below.

The snapshot was taken from an 11gR2 database:

SQL> select distinct sql_opname,
                     sql_opcode
       from dba_hist_active_sess_history;

SQL_OPNAME                SQL_OPCODE
------------------------- -----------------
ALTER TABLESPACE          40
DELETE                    7
ALTER DATABASE            35
ANALYZE TABLE             62
ALTER TABLE               15
INSERT                    2
UPSERT                    189
ALTER SUMMARY             172
CREATE TABLE              1
SELECT                    3
LOCK TABLE                26
CREATE INDEX              9
PL/SQL EXECUTE            47
TRUNCATE TABLE            85
CALL METHOD               170
                          0
UPDATE                    6

I guess the newer the “feature” the higher the number, since Oracle couldn’t just go and change the number between releases.

ORA-08103 in 11.2.0.3.3 in SAP With REVOKE

UPDATE 10-06-2013, SAP have confirmed to me that fix for bug 15996357 is scheduled for SBP of August 2013.

UPDATE 22-04-2013, I can confirm this is Oracle bug 15996357, but the bug is still not fixed. 

Scenario: After an upgrade from 10.2.0.5.0 to 11.2.0.3, then SAP SBP 092012 applied (taking it to 11.2.0.3.3), we were getting an error when running the following SQL:

SQL> revoke resource from SAPR3;

ERROR at line 1:
ORA-08103: object no longer exists

It is possible to grant the resource role (even though it’s deprecated in 11gR2), without any errors.

Following Oracle document 8103.1 “OERR: ORA-08103 object no longer exists / Troubleshooting, Diagnostic and Solution” (aptly named don’t you think), I performed the following actions as per the document:

  • We flushed the buffer cache: “alter session set events ‘immediate trace name flush_cache level 1’;”
  • Traced the SQL statement with EVENT 10236 & EVENT 10200 and a generic SQL session trace with BINDS.
  • Performed an “ANALYZE [table|index] VALIDATE STRUCTURE;” on all concerned tables & indexes found in the generic SQL session trace, with no corrupt objects reported.
  • We followed Oracle doc id 136697.1 (the DB is using DICTIONARY managed tablespaces), to check for overlapped extents, which returned no substantial findings.
  • The only warning from the hcheck.sql was for: “UPDATE STMT_AUDIT_OPTION_MAP set option#=234 WHERE NAME=’ON COMMIT REFRESH’;”
  • We ran RMAN “backup check logical validate database;” to check for corrupt blocks, with no rows reported in V$DATABASE_BLOCK_CORRUPTION at the end of run.

After reporting the issue to SAP, who subsequently forwarded the issue to Oracle, we were pointed to an issue captured in our SQL session trace.

There was one line that contained the text “ERROR”:

WAIT #11529215045787303928: nam='db file sequential read' ela= 4337 file#=8 block#=2 blocks=1 obj#=-1 tim=8321110421922
EXEC #11529215045787303928:c=1000000,e=5300151,p=6873,cr=41312,cu=8,mis=0,r=0,dep=0,og=1,plh=0,tim=8321110422039
ERROR #11529215045787303928:err=8103 tim=8321110422064
Checking which data file was affected showed it was a SAP standard datafile:

SQL> select file_id,tablespace_name,file_name from dba_data_files where file_id='8';

Oracle support suggested we dump the block contents:

sqlplus /nolog
SQL> connect as sysdba
SQL> oradebug setmypid
SQL> set pages 100 lines 80
SQL> spool dump.log
SQL> alter system dump datafile '<data file path & name>' block 2;
SQL> oradebug tracefile_name
SQL> spool off
SQL> exit

The resultant trace file containing the dump of the block looked as follows:

Oradebug command 'setmypid' console output: <none>
Start dump data block from file <data file path & name> minblk 2 maxblk 2
V10 STYLE FILE HEADER:
Compatibility Vsn = 186646528=0xb200000
Db ID=3010416539=0xb36f4f9b, Db Name='DB1'
Activation ID=0=0x0
Control Seq=6514478=0x63672e, File size=3840=0xf00
File Number=8, Blksiz=8192, File Type=3 DATA
Dump all the blocks in range:
buffer tsn: 7 rdba: 0x20000002 (128/2)
scn: 0x0000.20a5a720 seq: 0x01 flg: 0x00 tail: 0xa7201001
frmt: 0x02 chkval: 0x0000 type: 0x10=DATA SEGMENT HEADER - UNLIMITED
Hex dump of block: st=0, typ_found=1
Dump of memory from 0x9FFFFFFFEF506A00 to 0x9FFFFFFFEF508A00
9FFFFFFFEF506A00 10020000 20000002 20A5A720 00000100 [.... ... .. ....]
9FFFFFFFEF506A10 00000000 00000000 00000007 00000000 [................]
9FFFFFFFEF506A20 00000000 00000001 00000002 10200000 [............. ..]
9FFFFFFFEF506A30 00000000 00000001 00000002 20000004 [............ ...]
9FFFFFFFEF506A40 00000000 00000000 00000000 00000001 [................]
Repeat 1 times
9FFFFFFFEF506A60 00000000 00004DBC 00000000 20000003 [......M..... ...]
9FFFFFFFEF506A70 00000002 00000000 00000000 00000000 [................]
9FFFFFFFEF506A80 00000000 00000000 00000000 00000000 [................]
Repeat 250 times
9FFFFFFFEF507A30 00000000 00000001 00010100 00010000 [................]
9FFFFFFFEF507A40 00000000 00000000 20000003 20000003 [........ ... ...]
9FFFFFFFEF507A50 00000000 00000000 00000000 00000000 [................]
Repeat 249 times
9FFFFFFFEF5089F0 00000000 00000000 00000000 A7201001 [............. ..]
Extent Control Header
-----------------------------------------------------------------
Extent Header:: spare1: 0 spare2: 7 #extents: 1 #blocks: 2
last map 0x00000000 #maps: 0 offset: 4128
Highwater:: 0x20000004 ext#: 0 blk#: 1 ext size: 2
#blocks in seg. hdr's freelists: 0
#blocks below: 1
mapblk 0x00000000 offset: 0
Unlocked
Map Header:: next 0x00000000 #extents: 1 obj#: 19900 flag: 0x0
Extent Map
-----------------------------------------------------------------
0x20000003 length: 2

nfl = 1, nfb = 1 typ = 1 nxf = 0 ccnt = 0
SEG LST:: flg: USED lhd: 0x20000003 ltl: 0x20000003
End dump data block from file <data file path & name> minblk 2 maxblk 2

The type of block was specified as “DATA SEGMENT HEADER”.
In the Extent Header, we can see the object ID (obj#) is 19900, which matches an object:

SQL> set linesize 400
SQL> col object_name format A30
SQL> col owner format A10
SQL> select owner,object_name,object_type from dba_objects where object_id=19900;

OWNER OBJECT_NAME OBJECT_TYPE
----- ----------- -------------------
SAPR3 T063D       TABLE

This is confirmed by checking in DBA_SEGMENTS:

SQL> select owner, segment_name, tablespace_name from dba_segments where HEADER_FILE=8 and HEADER_BLOCK=2;

OWNER SEGMENT_NAME TABLESPACE_NAME
----- ------------ ------------------------------
SAPR3 T063D        PSAPLOADD

The block looks good and data can be selected.

Oracle support finally confirmed that there is a bug in the Oracle 11gR2 core code.
If you perform the following SELECT statement:

SQL> select ts#, blocks,maxblocks,grantor#,priv1,priv2,priv3 from tsq$
where user#=(select user# from user$ where name = 'SAPR3')
and maxblocks=0;


If you have any results returned, then the inherent bug could cause the ORA-08103 error.
At the moment an Oracle bug has been filed. I’ll update further when I know the bug details and the SAP SBP that fixes it.

UPDATE 22-04-2013, I can confirm this is Oracle bug 15996357, but the bug is still not fixed. 

Oracle 11gR2, KEWBMBTA: Maintain BSLN Thresholds failed

If you tighten up the security in an Oracle 11gR2 database, you may be tempted to remove access to the DBMS_OBFUSCATION_TOOLKIT package from PUBLIC (“revoke execute on DBMS_OBFUSCATION_TOOLKIT from PUBLIC;“).

This causes an issue, seen in 11gR2 11.2.0.3.
The error was visible in the user traces:

*** 2012-09-11 20:00:43.692
KEWBMBTA: Maintain BSLN Thresholds failed, check for details.

This was tracked to an invalid package body DBSNMP.BSLN.

SQL> alter package DBSNMP.BSLN compile body;

Warning: Package Body altered with compilation errors.

SQL> show errors
Errors for PACKAGE BODY DBSNMP.BSLN:

LINE/COL ERROR
-------- -----------------------------------------------------------------
88/5 PL/SQL: Statement ignored
88/19 PLS-00201: identifier 'DBMS_OBFUSCATION_TOOLKIT' must be declared
200/7 PL/SQL: Statement ignored
200/21 PLS-00201: identifier 'DBMS_OBFUSCATION_TOOLKIT' must be declared
241/7 PL/SQL: Statement ignored
242/8 PLS-00201: identifier 'DBMS_OBFUSCATION_TOOLKIT' must be declared
1332/7 PL/SQL: Statement ignored
1332/21 PLS-00201: identifier 'DBMS_OBFUSCATION_TOOLKIT' must be declared

Re-granting access to the DBMS_OBFUSCATION_TOOLKIT package to the PUBLIC user, fixes the issue again:

SQL> connect / as sysdba

Connected.

SQL> grant execute on DBMS_OBFUSCATION_TOOLKIT to PUBLIC;
Grant succeeded.

SQL> alter package DBSNMP.BSLN compile body;

Package body altered.