Oracle SQLNet Encryption, why is it needed in first place?

I recently wrote a blog post about Oracle SQLNet TLS encryption and how easy it is to configure. See also Oracle SQLNet TLS configuration simplified. This was followed by a short discussion about whether a simple ALTER USER … IDENTIFIED BY is encrypted in a regular connection or not. So let’s validate this by examining the network traffic with tcpdump and Wireshark. For my test I use a local test environment on my MacBook Pro M1 with an ARM based Docker Container for Oracle Database 19c, SQL Developer and sqlcl.

Unencrypted SQL Net connection

For this test, both Native SQLNet encryption and TLS encryption are turned off. By querying V$SESSION_CONNECT_INFO we can see if we have Native SQLNet encryption. The script net.sql does show the network service banner for the current session or you can directly query the view.

SELECT
    sid,network_service_banner
FROM
    v$session_connect_info
WHERE sid=(SELECT sid FROM v$mystat WHERE ROWNUM = 1)
AND NETWORK_SERVICE_BANNER like '%Encryption%';
SID NETWORK_SERVICE_BANNER
___ _____________________________________________________________
296 Encryption service for Linux: Version 19.0.1.0.0 - Production 

You can see that only one row is returned, which means that the network encryption is available but not active. Furthermore, by querying the NETWORK_PROTOCOL in the context USERENV, we can see if we have a TCP or TCPS connection.

SELECT sys_context('userenv','network_protocol') network_protocol
FROM dual;
NETWORK_PROTOCOL    
___________________ 
tcp

Now that we know that SQLNet is not encrypted with either native encryption or TLS, we can start a tcpdump session to record the network traffic. To do this, we start tcpdump as root and provide a specific network interface to collect all TCP packets. In my Docker container, this is the interface eth0.

tcpdump -i eth0 -s 65535 -w /u00/app/oracle/admin/CDBUA190/adhoc/noenc_v1.0.pcap

In the following you can see the connection as pdbadmin via sqlcli and the execution of ALTER USER.

soe@MacBook:~/ > sql pdbadmin@localhost:1521/PDB2

SQLcl: Release 23.2 Production on Tue Sept 19 17:48:37 2023

Copyright (c) 1982, 2023, Oracle.  All rights reserved.

Password? (**********?) ************
Last Successful login time: Tue Sep 19 2023 17:48:39 -07:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

SQL> SHOW user
USER is "PDBADMIN"
SQL> ALTER USER scott IDENTIFIED BY tiger;

User SCOTT altered.

SQL> exit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

Finally lets analyse the pcap file in Wireshark. Just load the file and select follow TCP Stream for protocol TNS, as you can see in the imabe below.

Select Follow the TCP stream for TNS protocol

In the following picture, you do see the TCP stream for the TNS protocol between the client and the server. In my example, red is the transfer of data from the client to the server and blue is the reverse. The data can be searched using find. Thus one finds relatively fast the unencrypted password as it is sent with the execution of ALTER USER from the client to the server.

Unencrypted TCP stream for TNS protocol

When parsing the SQL statement, Oracle then determines that this is a password. Accordingly, the SQL statement is masked in the audit trail.

SELECT sql_text FROM unified_audit_trail 
WHERE dbusername='PDBADMIN' AND action_name='ALTER USER';
SQL_TEXT
-------------------------------------------------
ALTER USER scott IDENTIFIED BY *

Encrypted SQL Net connection

Now let’s try it out with native SQLNet encryption. For this we set the parameter SQLNET.ENCRYPTION_SERVER in sqlnet.ora on the database server to REQUIRED.

# Oracle Net encryption 
# avaiable encryption algorithms in favored priority (default all )
SQLNET.ENCRYPTION_TYPES_CLIENT=(AES256,RC4_256,AES192,AES128)
SQLNET.ENCRYPTION_TYPES_SERVER=(AES256,RC4_256,AES192,AES128)
# enable encryption by following parameters
# ENCRYPTION_CLIENT and ENCRYPTION_SERVER can be set to
#SQLNET.ENCRYPTION_CLIENT = REQUIRED
SQLNET.ENCRYPTION_SERVER = REQUIRED

Again, we start tracing by calling tcpdump as root for interface eth0.

tcpdump -i eth0 -s 65535 -w /u00/app/oracle/admin/CDBUA190/adhoc/enc_v1.0.pcap

The query of V$SESSION_CONNECT_INFO now shows two entries, i.e. the SQLNet encryption is available and is also used with AES256.

SELECT
    sid,network_service_banner
FROM
    v$session_connect_info
WHERE sid=(SELECT sid FROM v$mystat WHERE ROWNUM = 1)
AND NETWORK_SERVICE_BANNER like '%Encryption%';
   SID NETWORK_SERVICE_BANNER                                                          
______ ___________________________________________________________________________
    22 Encryption service for Linux: Version 19.0.1.0.0 - Production
    22 AES256 Encryption service adapter for Linux: Version 19.0.1.0.0 - Production

And now we run the same statements to alter the user password as before without encryption.

soe@MacBook:~/ > sql pdbadmin@localhost:1521/PDB2

SQLcl: Release 23.2 Production on Wed Sept 20 16:50:42 2023

Copyright (c) 1982, 2023, Oracle.  All rights reserved.

Password? (**********?) ************
Last Successful login time: Wed Sep 20 2023 16:50:48 -07:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

SQL> SHOW user
USER is "PDBADMIN"
SQL> ALTER USER scott IDENTIFIED BY tiger;

User SCOTT altered.

SQL> exit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

As before, we load the pcap file and select a TNS package and choose Follow TCP Stream. The following figure shows as before with two colors (red and blue) the data, which were sent between client and server. In contrast to before, you can only read the beginning of the connection in plain text. The rest of the data is encrypted and thus no longer readable. Thus, the ALTER USER statement with the password is also encrypted accordingly.

Encrypted TCP stream for TNS protocol

But what about the Password command?

In SQLPlus, SQL Developer, sqlcl but also in other tools like TOAD, there is a password command. Either as command line command or in a menu e.g. Edit User in SQL Developer. The big question is, what happens in the background when you set a new password with this function?

Analogous to the procedure from before, we can record and view the network traffic for the different variants. For example for sqlcli.

soe@MacBook:~/ > sql pdbadmin@localhost:1521/PDB2

SQLcl: Release 23.2 Production on Wed Sept 20 17:01:30 2023

Copyright (c) 1982, 2023, Oracle.  All rights reserved.

Password? (**********?) ************
Last Successful login time: Wed Sep 20 2023 17:01:32 -07:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

SQL> password scott
New password: *****
Retype new password: *****
Password changed
SQL> exit

The corresponding TCP stream then looks like this.

Unencrypted TCP stream for password command in SQL Developer

Oops, you can see the password because the command is converted to an ALTER USER statement. Let’s check the same with SQLPlus.

soe@MacBook:~/ > sqlplus pdbadmin@localhost:1521/PDB2

SQL*Plus: Release 19.0.0.0.0 - Production on Wed Sep 20 17:16:58 2023
Version 19.8.0.0.0

Copyright (c) 1982, 2020, Oracle.  All rights reserved.

Enter password: 
Last Successful login time: Wed Sep 20 2023 17:01:32 -07:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

SQL> password scott
Changing password for scott
New password: 
Retype new password: 
Password changed
SQL> exit

This unencrypted TCP stream looks better after all. You can see at the bottom that an AUTH_NEWPASSWORD is sent from the client to the server. This is followed by a longer hash value which represents the encrypted password. The encryption is done with the help of the session key.

Unencrypted TCP stream for password command in SQLPlus

Conclusion

This simple test demonstrates that with Wireshark, it is relatively easy to monitor SQLNet traffic between a client and a server. You can accomplish this either directly or by using tcpdump, as I did. In either case, you can observe a lot, including SQL statements. In the case of an ALTER USER operation directly involving a password change, this functions as expected because the SQL statements are ultimately parsed on the database server. Consequently, only the server knows that the statement contains a password. In such cases, the password is masked appropriately, as we saw in the Unified Audit Trail, but just not on the network.

Only in the example involving SQLPlus, where we use the PASSWORD command, is no password transferred in plain text. The reason for this lies in the implementation and the client itself. SQLPlus utilizes the OCI library with suitable functions for altering passwords. On the other hand, SQL Developer, sqlcl, and other tools do not necessarily use the OCI library but implicitly execute an ALTER USER command, which is always visible when transmitted over an unencrypted connection.

Nowadays, encryption is employed for other network protocols and connections. For instance, HTTPS is used instead of HTTP, and LDAPS is preferred over LDAP. However, when it comes to network access to Oracle databases, encryption is often neglected. Yet there are compelling reasons why all access to an Oracle database should be encrypted. You can opt for the easy-to-configure Native Encryption or the TLS-based encryption.

If your main goal is to prevent unauthorized access to data on the network, the variant you choose is less important. It is more important that the network traffic is encrypted in the first place. In contrast to native encryption, certificate-based encryption through TLS over TCPS also provides a certain level of protection against man-in-the-middle attacks. However, it does have the drawback of necessitating the management of corresponding keystores and certificates. It appears that there will soon be a new feature to configure TCPS without the need for dedicated Oracle wallets.

Oracle SQLNet TLS configuration simplified

Most security measures for Oracle databases are usually aimed at protecting and hardening the database itself. This includes secure configuration, implementation of the least privilege principle, reduction of the attack surface, encryption at REST, database audit and much more. Sometimes, however, it is forgotten that the database also communicates with the outside world. Without additional measures, network access to Oracle databases is always unencrypted. This is due to the standard settings and the fact that network encryption was part of the Advanced Security Option until mid-2012 and therefore subject to licensing. Due to the security vulnerability CVE-2012-1675, the licensing of network encryption was subsequently adjusted. The following information can now be found in all Oracle licence documents under Advanced Security.

Network encryption (native network encryption and SSL/TLS) and strong authentication services (Kerberos, PKI, and RADIUS) are no longer part of Oracle Advanced Security and are available in all licensed editions of all supported releases of the Oracle database.

Oracle® Database Database Licensing Information User Manual 21c Oracle Database Options and Their Permitted Features

Although it has been a decade since the adaptation, in my opinion network encryption is still underused. Its use should be standard nowadays.

You ask yourself why? Have you ever created a user or changed its password? Then you may know this statement.

ALTER USER scott IDENTIFIED BY tiger;

It is a regular SQL statement that is sent from the client to the server to be parsed and executed. For non-encrypted connections, the statement is sent in plain text and can be viewed by any tracing.

Why Use TLS Encryption with Oracle SQLNet

With Oracle databases, two different methods are available for network encryption:

  • Oracle Native Network Encryption Standard network encryption is based on symmetric encryption with AES or other algorithms, whereby the key is negotiated when the connection is established. The configuration is very simple with sqlnet.ora on the database server, optionally also on the client side. In addition, no certificates are required. If required, the encryption can also be combined with the integrity check.
  • Oracle TLS Network Encryption SSL or TLS based Network Security uses a certificate based approach to securely establish a connection between a client and an Oracle Database Server. Similar to what is known from HTTPS. The network encryption and integrity check can be combined with the authentication. The use of certificates, dedicated TCPS port etc. makes the configuration a little more complex. However, it offers additional protection against man-in-the-middle attacks or the possibility of single sing on. Thus it’s configuration can be a bit cumbersome.
Sketch of TLS-based Network Encryption

See also Oracle® Database Security Guide 19c Choosing Between Native Network Encryption and Transport Layer Security for a comparsion of the two methods. In this blog post, however, we will discuss only the simple TLS connection without a client wallet i.e., no client authorisation.

Simplified TLS Configuration Steps

Prepare Software Keystore for TLS

Create a folder in TNS_ADMIN or another location suitable for the software Keystore.

mkdir -p $ORACLE_BASE/network/wallet

Create an Oracle software Keystore using orapki. See Oracle® Database Security Guide 19c Appendix F Managing Public Key Infrastructure (PKI) Elements

orapki wallet create -wallet $ORACLE_BASE/network/wallet -pwd <PASSWORD> -auto_login_local

Create a certificate request for the distinguished name of the database server db19.trivadislabs.com.

orapki wallet add -wallet $ORACLE_BASE/network/wallet -dn 'CN=db19,dc=trivadislabs,dc=com' -asym_alg RSA -keysize 4096 -pwd <PASSWORD>

Export the certificate request for transfer to the Certification Authority for signing.

orapki wallet export -wallet $ORACLE_BASE/network/wallet -dn 'CN=db19,dc=trivadislabs,dc=com' -request $ORACLE_BASE/network/wallet/db19.trivadislabs.com.csr

Windows Certification Authority

Depending on the environment, you can send the certificate request to a certification authority and receive the signed certificate back. This eliminates the steps described in this section. In my lab environment, however, I have to do everything myself. This includes the operation of a Certification Authority. But this runs on my Microsoft Active Directory Server anyway. Please adapt the following steps accordingly to your environment.

Copy the certificate request from the database server to the windows server. Ido have putty configured on my AD Server. This makes it easier to push / pullstuff from respectively to the database server.

C:\u00\app\oracle\network\admin
pscp.exe db19.trivadislabs.com:/u01/app/oracle/network/wallet/db19.trivadislabs.com.csr db19.trivadislabs.com.csr

The certreq utility will pop up with a list of CA’s. Select the correct one and let the CA create a signed certificate.

We do also require the Root certificate as well any intermediate certificate for
the software Keystore. Below you find the command certutil to export the Root
certificate. This does create binary version of the Root ceritificate and
display the PEM / Base64 format of the certificate. Make sure, to copy the
Base64 information into a test file. In my case I do store it into trivadislabs.com.pem.

C:\>certutil -ca.cert -f %TNS_ADMIN%\trivadislabs.com.cer
CA cert[0]: 3 -- Valid
CA cert[0]:
-----BEGIN CERTIFICATE-----
MIIFlTCCA32gAwIBAgIQcYnHlk5iwpRJTdc77kEmaTANBgkqhkiG9w0BAQsFADBd
MRMwEQYKCZImiZPyLGQBGRYDY29tMRwwGgYKCZImiZPyLGQBGRYMdHJpdmFkaXNs
YWJzMSgwJgYDVQQDEx9Ucml2YWRpcyBMQUIgRW50ZXJwcmlzZSBSb290IENBMB4X
DTIzMDUwNTA1NTIxOFoXDTI4MDUwNTA2MDIxNVowXTETMBEGCgmSJomT8ixkARkW
A2NvbTEcMBoGCgmSJomT8ixkARkWDHRyaXZhZGlzbGFiczEoMCYGA1UEAxMfVHJp
dmFkaXMgTEFCIEVudGVycHJpc2UgUm9vdCBDQTCCAiIwDQYJKoZIhvcNAQEBBQAD
ggIPADCCAgoCggIBANHr4q+v9SHOI+nofbFA+qa3zVWPXuKzuS+eI1a54n1qNnwL
cEH0/SEXAZ7e/XfHN9KrFLIKhCw3b9LW85Co1PPjcP0B087Se/kwReBkD29L9FJG
qElIaVfKGJ/nZ8jyCrnQg5b5w5N0Xm8cWzMuV2iYu/m4/f3oz1+Rcrwgeka64dbv
IWuVjWkvRvhN0zNJHwY5jKYS59FFpFghhy0VNF7xXH5dFBepE+OPBST+Zfiu13iG
qqvraPdB4TblfBtI2YknlBCuWiNm1I+crSr2rptR4gDOud9YC0+OwmMdwPhdf7DK
sjyt/Gp0hbVT9rc1tmN9MuxxyY3Jg7b0rE+UfNluNQAt2eW8XZ5IsZxiXE+weeC5
+pwojRQPNiZC1k+LMiwCJEspTxWj1M9Qf3spWcjMKiPt1qpT4fjwladdpv5FX9AX
Z+YbgUjqviD1zwOVoc8hRlY6pctaFAx8+icjrsREjIU6yAi3ng/HcjYpiL/pd9M7
buNUB2KCYsgSKMvd++FibOxfGSPfYyYZjJ+cX8TvHpHnq507S1cPcXzQWxhqu2sc
7/OXTO5DKKUxJ/1MWb0X+Nqk7C4RGmONpvdnVTVQfVbnX9j53+8Gt7PmYOac8avJ
DNyuijBf4olcC2IoihLJCHHkToA6KhcYRNMLxOaLXyebWAHZIrMRWQbIeyl1AgMB
AAGjUTBPMAsGA1UdDwQEAwIBhjAPBgNVHRMBAf8EBTADAQH/MB0GA1UdDgQWBBT5
inf+t2/lUJIH2J0fYVUnfn2NBTAQBgkrBgEEAYI3FQEEAwIBADANBgkqhkiG9w0B
AQsFAAOCAgEAblL0JuP8Ql06CYMSHw+3u24c9VKaN8m8+rzaS477j+MPyzsGzbT0
Yq4bcKJFmKnZbN1Tw/sa0u1CxvlJvGeFU4KMaR72/KefEJ1Tc6AfDZrYVMeWCflo
S5lqYrj9+VR4NplPb4vYipO5St4vaergPk5gC35q1/6FL9E2nsucXb5rCgqoqLHM
P7Pg+iA2oaMvaOTfNEVIjDkuVcyTbOFezzKxDQfvdcj82gnHbc+qWq/YsKExzPlC
3rGhSUzb69fzMzzcuPxhkH35vKYSsFvTs2Va6Ztzapzbqrqorm2oZFlwL2yZboA2
AT4Mt33JK514oKeUB5unceqWIUxTeUHOLHhyoDSMRhFCeja7T8CmHD2+TIWWNbwu
q9XfoZkUcBewk+3UVQZCrkQhP6RIxI6H5Dd9fh4A+ugMAxwzUG2unsMa1yN6U/pC
7sLCrgdtZq7hQ1DtgE8Y/RxpPYNt9dtUbXWGM3a7gUBfgz+8BDaeOYPx+IycVipf
p5+Lq1RZl6zEaz1MrVEA6nnncTe1k52E1txQMgHi7x0Kn/k5OGLkJY3dTbwjxM6n
Yh/jzRP5/v0rmC2Ia/MmIiuxtV2K6pAZIlTSPVPW+NErGUn2YvAjl868w0h9Btxp
1VdZEK8h5TwG5W55t6gNGOxgkJPQAV+Ma4FfExK20qBsAIqlSAYfiKA=
-----END CERTIFICATE-----

CertUtil: -ca.cert command completed successfully.

Copy the Root CA as well the signed certificate back to the db server

pscp.exe %TNS_ADMIN%\db19.trivadislabs.com.pem db21:/u01/app/oracle/network/wallet/db19.trivadislabs.com.pem
pscp.exe %TNS_ADMIN%\trivadislabs.com.pem db21:/u01/app/oracle/network/wallet/trivadislabs.com.pem

Finalize Software Keystore

Back on the linux environment we first verify the certificates using openssl.

openssl verify -CAfile $ORACLE_BASE/network/wallet/trivadislabs.com.pem $ORACLE_BASE/network/wallet/db19.trivadislabs.com.pem

Add the trusted certificate from Active Directory to the software keystore.

orapki wallet add -wallet $ORACLE_BASE/network/wallet -trusted_cert -cert $ORACLE_BASE/network/wallet/trivadislabs.com.pem -pwd <PASSWORD>

Add the signed user certificate from Active Directory to the software keystore.

orapki wallet add -wallet $ORACLE_BASE/network/wallet -user_cert -cert $ORACLE_BASE/network/wallet/db19.trivadislabs.com.pem -pwd <PASSWORD>

Show certificates in keystore.

orapki wallet display -wallet $ORACLE_BASE/network/wallet
oracle@db19:~/ [rdbms19] orapki wallet display -wallet $ORACLE_BASE/network/wallet

Oracle PKI Tool Release 19.0.0.0.0 - Production
Version 19.4.0.0.0
Copyright (c) 2004, 2023, Oracle and/or its affiliates. All rights reserved.

Requested Certificates: 
User Certificates:
Subject:        CN=db19,DC=trivadislabs,DC=com
Trusted Certificates: 
Subject:        CN=Trivadis LAB Enterprise Root CA,DC=trivadislabs,DC=com

Configuration of sqlnet.ora

We update the sqlnet.ora file to cover the new wallet and set the SSL / TLS configuration. Just add / update the following parameter.

  • SSL_CLIENT_AUTHENTICATION Parameter to specify whether a client is authenticated using Transport Layer Security (TLS)
  • SQLNET.IGNORE_ANO_ENCRYPTION_FOR_TCPS This parameter is used on the server-side to ignore the value set in SQLNET.ENCRYPTION_SERVER for TCPS connections (effectively disabling ANO encryption on the TCPS listener).
  • SSL_VERSION Used to define valid Transport Layer Security (TLS) versions to be used for connections.
  • SSL_CIPHER_SUITES Parameter to control the combination of authentication, encryption, and data integrity algorithms used by Transport Layer Security (TLS).
  • WALLET_LOCATION Use the sqlnet.ora parameter WALLET_LOCATION to specify the location of Oracle wallets.

More information about the sqlnet.ora parameter can be found in Oracle® Database Database Net Services Reference 19c chapter 5 Parameters for the sqlnet.ora File. Below you find an example of our sqlnet.or configuration.

# ---------------------------------------------------------------
# SSL/TLS Configuration for SQLNet
# ---------------------------------------------------------------
SSL_CLIENT_AUTHENTICATION=FALSE
SQLNET.IGNORE_ANO_ENCRYPTION_FOR_TCPS = TRUE
SSL_VERSION = 1.2
SSL_CIPHER_SUITES = (TLS_ECDHE_ECDSA_WITH_AES_256_GCM_SHA384, TLS_ECDHE_ECDSA_WITH_AES_128_GCM_SHA256, TLS_ECDHE_RSA_WITH_AES_256_GCM_SHA384, TLS_ECDHE_RSA_WITH_AES_128_GCM_SHA256)
WALLET_LOCATION=
  (SOURCE=
      (METHOD=file)
      (METHOD_DATA=
         (DIRECTORY=/u01/app/oracle/network/wallet)))

The sqlnet.ora file must be adapted on both the client and the server. On the database server, the sqlnet.ora applies to both.

Configuration of listener.ora

As is known from HTTP and HTTPS, a separate port must also be configured for SQLNet with TLS. This is done with the help of the listener.ora file. To do this example, we simply extend the default listener with an additional port for TCPS.

vi $TNS_ADMIN/listener.ora
LISTENER =
    (ADDRESS_LIST =
        (ADDRESS = (PROTOCOL=IPC )(KEY=LISTENER ))
        (ADDRESS = (PROTOCOL = TCP ) (HOST = db19 ) (PORT = 1521 ))
        (ADDRESS = (PROTOCOL = TCPS ) (HOST = db19 ) (PORT = 1522 ))
    )

In addition, we add the SSL / TLS configuration to the listener.ora file.

# ---------------------------------------------------------------
# SSL/TLS configuration
# ---------------------------------------------------------------
SSL_VERSION = 1.2
SSL_CLIENT_AUTHENTICATION = FALSE
WALLET_LOCATION=
  (SOURCE=
      (METHOD=file)
      (METHOD_DATA=
         (DIRECTORY=/u01/app/oracle/network/wallet)))

On my environment I do have a firewall running. Therefor we have to open the new port for TCPS.

sudo firewall-cmd --zone=public --add-port=1522/tcp
sudo firewall-cmd --zone=public --add-port=1522/tcp --permanent
sudo systemctl restart firewalld
sudo firewall-cmd --zone=public --list-all

Finally, we restart the listener to activate the changes.

lsnrctl stop
lsnrctl start

Lets use openssl to verify the port and certificate.

openssl s_client -connect db19.trivadislabs.com:1522

Configuration of tnsnames.ora

Last but not least, the corresponding entries in tnsnames.ora must be defined for the connection via the new port. Enclosed is the example of the connection strings for the database TDB01 with and without TLS.

TDB01.trivadislabs.com=(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=db19)(PORT=1521))(CONNECT_DATA=(SERVER=DEDICATED)(SERVICE_NAME=TDB01.trivadislabs.com))(UR=A))
TDB01_TLS.trivadislabs.com=(DESCRIPTION=(ADDRESS=(PROTOCOL=TCPS)(HOST=db19)(PORT=1522))(CONNECT_DATA=(SERVER=DEDICATED)(SERVICE_NAME=TDB01.trivadislabs.com))(UR=A))

Connection Tests

Simple test with SQLPlus and a connection to the regular TCP port.

oracle@db19:~/ [rdbms19] sqlplus system@TDB01

SQL*Plus: Release 19.0.0.0.0 - Production on Fri Sep 8 14:15:44 2023
Version 19.19.0.0.0

Copyright (c) 1982, 2022, Oracle.  All rights reserved.

Enter password: 
Last Successful login time: Thu Sep 07 2023 10:22:42 +02:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

SQL> 

Checking the USERENV context for the network protocol to see if we do use TCP or TCPS.

SQL> SELECT sys_context('userenv','network_protocol') FROM dual;

SYS_CONTEXT('USERENV','NETWORK_PROTOCOL')
--------------------------------------------------------------------------------
tcp

And the same connecting the TCPS port.

oracle@db19:~/ [rdbms19] sqlplus system@TDB01_TLS

SQL*Plus: Release 19.0.0.0.0 - Production on Fri Sep 8 14:18:35 2023
Version 19.19.0.0.0

Copyright (c) 1982, 2022, Oracle.  All rights reserved.

Enter password: 
Last Successful login time: Fri Sep 08 2023 14:15:47 +02:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

SQL

Checking the USERENV context for the network protocol to see if we do use TCP or TCPS.

SQL> SELECT sys_context('userenv','network_protocol') FROM dual;

SYS_CONTEXT('USERENV','NETWORK_PROTOCOL')
--------------------------------------------------------------------------------
tcps

We do see, that we now have the TCPS protocol in use.

Conclusion

If you leave out authentication, configuring TLS network security for Oracle databases is not that difficult. Of course, there is still the effort of managing the certificates and especially their validity period accordingly. Nevertheless, the effort is worth it when security requirements are increased. As a good practice I try to implement the following priorities:

  1. As a standard, configure the Oracle native network encryption with at least REQUESTED. Idealy combined with integrity check also set to REQUESTED.
  2. Enforcing the network encryption by setting it on the Database Server to REQUIRED.
  3. Implement TLS based network security to protect against man-in-the-middle attacks.
  4. Consider the use of strong authentication i.e. Kerberos or TLS based authentication.

References and Further Reading

A few links and references to relevant documentation, blog posts and other external resources for further reading.

SQL Toolbox for simplified Oracle Unified Audit Data Analysis

On my journey through the area of database security, Oracle Unified Audit has been a constant companion. I not only created audit concepts, but also often had the opportunity to implement them. Besides the configuration, the administration and evaluation of the audit data was always part of it. Occasionally I used scripts for this. However, I often evaluated the audit data ad hoc. There are only a handful of data dictionary views that have to be taken into account. So that was usually enough. Nevertheless, creating a collection of scripts for Unified Audit has been on my bucket list for a long time. At least until today. I finally found the time to put together a small toolbox of scripts, which I would like to show you in this blog post.

The scripts for the database audit are among others part of my GitHub repository oehrlis/oradba and are available to everyone. You are welcome to share them, use them, improve them or just like them.

What is currently covered by my scripts for Oracle Unified Audit?

  • Configuration of the audit infrastructure, i.e. tablespace, housekeeping jobs, etc.
  • Information on audit trails and storage usage
  • Administration of audit policies. This includes the creation, deletion, activation and display of policies.
  • Assessment of the unified audit trail showing various top events, e.g. policy, user, objects, etc.
  • Overview of the audit session and analysis of the statements per session

Current list of scripts

The following SQL scripts are currently available for the assessment of Oracle Unified Audit data. Further information on the scripts can be found in the comments of the file headers.

scriptPurpose
saua_info.sqlShow information about the audit trails
daua_pol.sqlDisable all audit policies and drop all non-Oracle maintained policies
cdua_init.sqlInitialize Audit environment (create tablespace, reorganize tables, create jobs)
caua_pol.sqlCreate custom local audit policies policies
iaua_pol.sqlInitialize / Enable custom local audit policies policies
saua_pol.sqlShow local audit policies policies. A join of the views AUDIT_UNIFIED_POLICIES and AUDIT_UNIFIED_ENABLED_POLICIES
saua_teact.sqlShow top unified audit events by action for current DBID
saua_tecli.sqlShow top unified audit events by client_program_name for current DBID
saua_tedbid.sqlShow top unified audit events by DBID
saua_teusr.sqlShow top unified audit events by dbusername for current DBID
saua_teobj.sqlShow top unified audit events by object_name for current DBID
saua_teobjusr.sqlShow top unified audit events by Object Name without Oracle maintained schemas for current DBID
saua_teown.sqlShow top unified audit events by object_schema for current DBID
saua_teosusr.sqlShow top unified audit events by os_username for current DBID
saua_tepol.sqlShow top unified audit events by unified_audit_policies for current DBID
saua_tepoldet.sqlShow top unified audit events by unified_audit_policies, dbusername, action for current DBID
saua_tehost.sqlShow top unified audit events by userhost for current DBID
saua_asdbv.sqlShow audit sessions for audit type Database Vault
saua_asdp.sqlShow audit sessions for audit type Datapump
saua_asfga.sqlShow audit sessions for audit type Fine Grained Audit
saua_asbck.sqlShow audit sessions for audit type RMAN
saua_asstd.sqlShow audit sessions for audit type Standard
saua_as.sqlShow audit sessions for audit any type
saua_asdet.sqlShow entries of a particular audit session with unified_audit_policies
saua_asdetsql.sqlShow entries of a particular audit session with SQL_TEXT
sdua_usage.sqlShow Unified Audit trail storage usage
saua_tabsize.sqlShow Unified Audit trail table and partition size
sdua_enpolstm.sqlGenerate statements to enable all audit policies as currently set in AUDIT_UNIFIED_ENABLED_POLICIES
sdua_crpolstm.sqlGenerate statements to create all audit policies as currently set in AUDIT_UNIFIED_ENABLED_POLICIES
sdua_drpolstm.sqlGenerate statements to drop all audit policies as currently set in AUDIT_UNIFIED_ENABLED_POLICIES
sdua_dipolstm.sqlGenerate statements to disable all audit policies as currently set in AUDIT_UNIFIED_ENABLED_POLICIES
sdua_prgstm.sqlGenerate Unified Audit trail storage purge statements
sdua_stostm.sqlGenerate Unified Audit trail storage usage modification statements
List of SQL Scripts

A few Examples and Use Cases

Overview of Audit Trails saua_info.sql

Some information on the different audit trails and there size. Some data depend on up to date statistics.

Overview of Unified Audit Trail Storage Usage sdua_usage.sql

Summary of various information about the unified audit trail, e.g. number of records, oldest records, size etc. The output is always for the current DBID. If audit records are also available for other DBIDs, they are displayed as foreign DBIDs. These audit data can potentially be deleted. There is also the script saug_tabsize.sql, which displays information about the partitions.

Generate Unified Audit Trail purge statements sdua_prgstm.sql

Generate dbms_audit_mgmt statements based on the current setting / configuration. These statements can be used as a copy template directly or adapted to maintain the audit trail. There is also the script sdua_stostm.sql to create modification statements.

Show local audit policies policies saua_pol.sql

Show current audit policy settings. This script does join the views AUDIT_UNIFIED_POLICIES and AUDIT_UNIFIED_ENABLED_POLICIES. There are also corresponding script to create (caua_pol.sql), drop (daua_pol.sql) and enable/initialize (iaua_pol.sql) the audit policies.

Show Top Audit Events

There are several scripts to show top audit events e.g. by user (saua_teusr.sql), action (saua_teact.sql), policy (saua_tepol.sql), object name (saua_teobj.sql) and more. These script can be used to find the root cause of hig amout of audit data.

Below you see an example for top audit actions.

Audit Session Overview saua_as.sql

Show an overview of audit sessions in the audit trail, where the information is grouped by the session ID. This script also accepts parameters to limit the information based on days or fractions thereof. The following query limits the output to the last 2h. In addition, there are variants of this script that limit the information to the individual audit types, e.g. Datapump (saua_asdp.sql), RMAN (saua_asbck.sql) or Fine Grained Audit (saua_asfga.sql).

Audit Session Details saua_asdet.sql

This script does show all audit records for a specific audit session id. You can see what somebody did during its session. There is also a version of the script (saua_asdetsql.sql) which does show the sql_text. Below we see an example what session ID (scott) has done during its session. This script does also perfectly work for proxy sessions.

Naming Concept

A little confused by the script names? I have tried to somehow bring a bit of order to my scripts in the GitHub repository oehrli/oradba. That is an attempt. But I’m not sure I’ve been successful. Enclosed the information about the different abbreviations and prefixes.

The script names follow the format:

<script_qualifier><privileges_qualifier><topic_qualifier>_<use_case>.sql

Script Qualifier

The script qualifier is used to determine whether a script is used to read information or to configure, e.g. create, modify, activate, etc.

QualifierStands ForComment
sShowOutput only on screen
dDeleteDelete any objects, configuration etc
iInitializeInitializes or enable a configuration
cCreateCreate any objects, configuration etc.
uUpdateUpdate any object
gGrantGrants some objects or system privileges
Script Qualifier

Privileges Qualifier

The privilege qualifier is used to determine what privileges are required by a script.

QualifierStands ForComment
sSYSSYS, SYSDBA or Internal
dDBASYSTEM or any other user with DBA role
oOwnerObject owner
pCreateNeeds some special privileges according to the scripts inline comments
aAuditAudit roles like AUDIT_ADMIN or AUDIT_VIEWER
Privileges Qualifier

Topic Qualifier

Topic Qualifier is used to assign the different scripts to a certain topic and thus to be able to sort them better.

QualifierStands ForComment
uaUnified AuditEverything related to Oracle Unified Audit
taTraditional AuditEverything related to Oracle traditional Audit
secSecurityOracle security related stuff
encEncryptionOracle Transparent DataEncryption
aAdminDatabase Administration
Topic Qualifier

Conclusion

This collection of SQL scripts around Oracle Unified Audit is certainly not perfect or conclusive. Nevertheless, it is helpful for the configuration and a first analysis of the audit data in the Unified Audit Trail. As already mentioned, you can find the scripts on GitHub under oehrlis/oradba. I would be happy if you share or like them. Feedback and ideas as comments to this blogpost or better directly as a GitHub issue are very welcome.

Unleash the Power of the User Home SQLNet Config

Introduction

A crucial functionality of databases is that they are accessible via a network. This also applies to Oracle databases, where network access is controlled by the Oracle Net Service components. The two files sqlnet.ora and tnsnames.ora belong to the key configuration files and can be used on both the client machines and the database server. While you may be familiar with the essential configuration files, did you know that there’s a hidden path to unlock greater flexibility in Oracle Net Service?

  • tnsnames.ora is a configuration file that contains network service names mapped to connect descriptors for the local naming method, or net service names mapped to listener protocol addresses.
  • sqlnet.ora is the SQLNet configuration file. It resides on the client machines and the database server. Among other things, sqlnet.ora is used to enable the following configurations:
    • Specify the client domain to append to unqualified names
    • Prioritize naming methods
    • Enable logging and tracing features
    • Configure parameters for external naming
    • Configure Oracle Advanced Security

By default, both files are stored in the ORACLE_HOME/network/admin directory, or in ORACLE_BASE_HOME/network/admin for a read-only Oracle Home. The environment variable TNS_ADMIN can also be used to specify an alternative directory. This is especially useful on systems where you have several Oracle Home directories, but only want to work with one central Oracle Net Service configuration.

The order in which these files are searched is documented in Oracle® Database Database Net Services Reference 19c and in the Oracle Support Document 464410.1. All right, so that brings us to the end of this blog post, doesn’t it? Of course not, there is one small detail that is not in the documentation, or at least not any more. Oracle searches for sqlnet.ora and tnsnames.ora will also include other locations. So lets discover a less known path to greater flexibility and efficiency for Oracle Net Service.

Exploring the Alternative tnsnames.ora and sqlnet.ora Location

The easiest way to figure out which path or files are being read is to use strace when calling an Oracle tool like tnsping or sqlnet. The strace utility is very powerful and provides us with all kinds of trace information about a programme or process. In our case, however, we are only interested in seeing which files are being accessed. If strace is not available on your system, you can simply install it with yum or dnf.

sudo yum install -y strace

Below you find a simple example to call tnsping using strace. Since strace is quite chatty, we limit the output to open and access events and froward the output to a file.

strace -e trace=open,access,stat,openat -o strace_tnsping.out \
tnsping TDB01

The output of tnsping is irrelevant in our case. Let’s take a look at the file generated by strace and search for tnsnames.ora.

grep -in tnsnames.ora strace_tnsping.out
274:access("/home/oracle/.tnsnames.ora", F_OK) = -1 ENOENT (No such file or directory)
275:access("/u01/app/oracle/network/admin/tnsnames.ora", F_OK) = 0
276:stat("/u01/app/oracle/network/admin/tnsnames.ora", {st_mode=S_IFREG|0644, st_size=484, ...}) = 0
277:openat(AT_FDCWD, "/u01/app/oracle/network/admin/tnsnames.ora", O_RDONLY) = 6

Eureka there is something. We can see, that tnsping was tring to access to files. One is tnsnames.ora, which is in my TNS_ADMIN directory, and the other is .tnsnames.ora, which is in my user home directory. The same applies to sqlnet.ora. Let’s check this with a call to sqlplus.

strace -e trace=open,access -o strace_sqlplus.out  \
sqlplus /@TEASPARX_pdbadmin <<EOFSQL
    SHOW USER
EOFSQL 

Again, the effective output of sqlplus is irrelevant. Let’s take a look at the file created by strace and search for sqlnet.ora.

grep -in sqlnet.ora strace_sqlplus.out
61:access("/u01/app/oracle/network/admin/sqlnet.ora", F_OK) = 0
62:open("/u01/app/oracle/network/admin/sqlnet.ora", O_RDONLY) = 6
63:access("/home/oracle/.sqlnet.ora", F_OK) = -1 ENOENT (No such file or directory)
76:access("/u01/app/oracle/network/admin/sqlnet.ora", F_OK) = 0
77:open("/u01/app/oracle/network/admin/sqlnet.ora", O_RDONLY) = 8

We see, also here a hidden sqlnet.ora is accessed in the User Home.

Configuring the Alternative Location

The configuration is rather simple. You just have to create a hidden tnsnames.ora or sqlnet.ora file in the user home directory. Files are hidden in Linux if their name begins with a dot (.).

Lets create a Oracle net service entry for the database TDB01.

cat << EOF >$HOME/.tnsnames.ora
TDB01_system.trivadislabs.com=
   (DESCRIPTION=
     (ADDRESS=
       (PROTOCOL=TCP)
       (HOST=db19)
       (PORT=1521)
     )
     (CONNECT_DATA=
       (SERVER=DEDICATED)
       (SERVICE_NAME=TDB01.trivadislabs.com)
     )
     (UR=A)
   )
EOF

Then we test with tnsping whether the hidden tnsnames.ora is being read.

strace -e trace=open,access,stat,openat -o strace_tnsping.out \
tnsping TDB01_system
TNS Ping Utility for Linux: Version 19.0.0.0.0 - Production on 28-JUN-2023 09:41:39

Copyright (c) 1997, 2023, Oracle.  All rights reserved.

Used parameter files:
/u01/app/oracle/network/admin/sqlnet.ora


Used TNSNAMES adapter to resolve the alias
Attempting to contact (DESCRIPTION= (ADDRESS= (PROTOCOL=TCP) (HOST=db19) (PORT=1521)) (CONNECT_DATA= (SERVER=DEDICATED) (SERVICE_NAME=TDB01.trivadislabs.com)) (UR=A))
OK (10 msec)

We see tnsping finds the new Oracle Net Service entry and returns a correct response. What about the output of strace?

grep -in tnsnames.ora strace_tnsping.out
275:access("/home/oracle/.tnsnames.ora", F_OK) = 0
276:access("/u01/app/oracle/network/admin/tnsnames.ora", F_OK) = 0
277:stat("/home/oracle/.tnsnames.ora", {st_mode=S_IFREG|0644, st_size=245, ...}) = 0
278:openat(AT_FDCWD, "/home/oracle/.tnsnames.ora", O_RDONLY) = 6

As expected, the new Oracle Net Service entry is read from the hidden tnsnames.ora file in the user home directory. If we do another tnsping on the Net Service Name TDB01 as we did at the beginning, we see that both files are read. First the hidden file .tnsnames.ora and because TDB01 is not found, the central tnsnames.ora from the TNS_ADMIN directory.

strace -e trace=open,access,stat,openat -o strace_tnsping.out \
tnsping TDB01
grep -in tnsnames.ora strace_tnsping.out
269:access("/home/oracle/.tnsnames.ora", F_OK) = 0
270:access("/u01/app/oracle/network/admin/tnsnames.ora", F_OK) = 0
271:stat("/home/oracle/.tnsnames.ora", {st_mode=S_IFREG|0644, st_size=245, ...}) = 0
272:openat(AT_FDCWD, "/home/oracle/.tnsnames.ora", O_RDONLY) = 6
273:stat("/u01/app/oracle/network/admin/tnsnames.ora", {st_mode=S_IFREG|0644, st_size=484, ...}) = 0
274:openat(AT_FDCWD, "/u01/app/oracle/network/admin/tnsnames.ora", O_RDONLY) = 6

If we do another tnsping on the net service name TDB01, as we did at the beginning, we see that both files are read. First the hidden file .tnsnames.ora and because TDB01 is not found, the central tnsnames.ora from the $TNS_ADMIN directory.

The examples shown above were all with tnsnames.ora. But for sqlnet.ora the whole thing works analogously.

Use Cases and Advantages

With this undocumented functionality of Oracle Net Services, a wide range of use cases can be covered.

  • Personal Oracle Net service names or aliases
  • Test Adhoc SQL Net configurations. E.g. for troubleshooting, tracing or testing special functions, etc.
  • Overrule or extend central SQL Net configurations
  • Use of a local wallet for Secure External Password Store (SEPS)

Let’s take a look at the example of Secure External Password Store, where we use a wallet for authentication. First, we generate a password using pwgen and create an Oracle wallet using mkstore.

mkdir -p $HOME/.pwd $HOME/wallet
pwgen -s -1 15 >$HOME/.pwd/.wallet_password.txt
chmod 600 $HOME/.pwd/.wallet_password.txt
chmod 700 $HOME/.pwd
mkstore -wrl $HOME/wallet -create <<CREATE
$(cat $HOME/.pwd/.wallet_password.txt)
$(cat $HOME/.pwd/.wallet_password.txt)
CREATE
Oracle Secret Store Tool Release 19.0.0.0.0 - Production
Version 19.4.0.0.0
Copyright (c) 2004, 2023, Oracle and/or its affiliates. All rights reserved.

Enter password:   
Enter password again:

For testing, we create a simple user SEPS_TEST in the DB TDB01. The password is generated using pwgen and temporary stored in a text file for easier deployment. The following SQL statements are packed in a here doc. Convenient way to execute SQL directly with a copy/paste. The prerequisite is, of course, that the corresponding Oracle environment is set.

pwgen -s -1 15 >$HOME/.pwd/.seps_test_password.txt
chmod 600 $HOME/.pwd/.seps_test_password.txt
${ORACLE_HOME}/bin/sqlplus -S -L /nolog <<EOFSQL 
    CONNECT / AS SYSDBA
    DROP USER seps_test;
    CREATE USER seps_test IDENTIFIED BY "$(cat $HOME/.pwd/.seps_test_password.txt)";
    GRANT create session TO seps_test;
    GRANT select_catalog_role TO seps_test;
EOFSQL

Next, we create a TNS entry TDB01_seps_test.trivadislabs.com in the hidden tnsnames.ora

cat << EOF >>$HOME/.tnsnames.ora
TDB01_seps_test.trivadislabs.com=
   (DESCRIPTION=
     (ADDRESS=
       (PROTOCOL=TCP)
       (HOST=db19)
       (PORT=1521)
     )
     (CONNECT_DATA=
       (SERVER=DEDICATED)
       (SERVICE_NAME=TDB01.trivadislabs.com)
     )
     (UR=A)
   )
EOF

Don’t forget to test if we can connect to the database using this new net service name.

tnsping TDB01_seps_test
TNS Ping Utility for Linux: Version 19.0.0.0.0 - Production on 28-JUN-2023 13:27:41

Copyright (c) 1997, 2023, Oracle.  All rights reserved.

Used parameter files:
/u01/app/oracle/network/admin/sqlnet.ora


Used TNSNAMES adapter to resolve the alias
Attempting to contact (DESCRIPTION= (ADDRESS= (PROTOCOL=TCP) (HOST=db19) (PORT=1521)) (CONNECT_DATA= (SERVER=DEDICATED) (SERVICE_NAME=TDB01.trivadislabs.com)) (UR=A))
OK (0 msec)

We store the credentials using mkstore in the previously created wallet.

mkstore -wrl $HOME/wallet -createCredential \
 TDB01_seps_test seps_test <<ADD
$(cat $HOME/.pwd/.seps_test_password.txt)
$(cat $HOME/.pwd/.seps_test_password.txt)
$(cat $HOME/.pwd/.wallet_password.txt)
ADD
Oracle Secret Store Tool Release 19.0.0.0.0 - Production
Version 19.4.0.0.0
Copyright (c) 2004, 2023, Oracle and/or its affiliates. All rights reserved.

Your secret/Password is missing in the command line 
Enter your secret/Password:   
Re-enter your secret/Password:   
Enter wallet password: 

For SEPS to work, we still need to create a WALLET entry in sqlnet.ora. We now do this in the hidden sqlnet.ora file.

cat >> $HOME/.sqlnet.ora <<CAT
WALLET_LOCATION=(SOURCE=(METHOD=FILE)(METHOD_DATA=(DIRECTORY="$HOME/wallet")))
SQLNET.WALLET_OVERRIDE=TRUE
CAT

With the help of Secure External Password Store, we can now log on directly to the database without entering the password. To do this, we use the defined TNS entry. SQLPlus then reads the corresponding information from the wallet. Lets to a simple test.

${ORACLE_HOME}/bin/sqlplus /@TDB01_seps_test <<EOFSQL 
    SHOW USER
EOFSQL
SQL*Plus: Release 19.0.0.0.0 - Production on Wed Jun 28 13:49:19 2023
Version 19.19.0.0.0

Copyright (c) 1982, 2022, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

SQL> USER is "SEPS_TEST"
SQL> Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0

And now let’s control the whole stuff with strace and run grep to verify the output.

strace -e trace=open,access,stat,openat -o strace_sqlplus.out \
${ORACLE_HOME}/bin/sqlplus /@TDB01_seps_test <<EOFSQL 
    SHOW USER
EOFSQL
grep -in tnsnames.ora strace_sqlplus.out
69:access("/u01/app/oracle/network/admin/sqlnet.ora", F_OK) = 0
70:openat(AT_FDCWD, "/u01/app/oracle/network/admin/sqlnet.ora", O_RDONLY) = 6
71:access("/home/oracle/.sqlnet.ora", F_OK) = 0
72:openat(AT_FDCWD, "/home/oracle/.sqlnet.ora", O_RDONLY) = 6
96:access("/u01/app/oracle/network/admin/sqlnet.ora", F_OK) = 0
97:openat(AT_FDCWD, "/u01/app/oracle/network/admin/sqlnet.ora", O_RDONLY) = 8
402:access("/home/oracle/.tnsnames.ora", F_OK) = 0
403:access("/u01/app/oracle/network/admin/tnsnames.ora", F_OK) = 0
404:stat("/home/oracle/.tnsnames.ora", {st_mode=S_IFREG|0644, st_size=493, ...}) = 0
405:openat(AT_FDCWD, "/home/oracle/.tnsnames.ora", O_RDONLY) = 12
407:stat("/home/oracle/.tnsnames.ora", {st_mode=S_IFREG|0644, st_size=493, ...}) = 0
408:stat("/home/oracle/.tnsnames.ora", {st_mode=S_IFREG|0644, st_size=493, ...}) = 0

As expected, the files from TNS_ADMIN as well as the hidden files in the user home directory are being read.

Do not forget to save the password for the wallet and the test user in a password manager and remove the temporarily created files.

rm -rf $HOME/.pwd/.seps_test_password.txt $HOME/.pwd/.wallet_password.txt

Best Practices, Considerations and Common Issues

First of all, it is important to know that you can use these hidden Net Service configuration files to control the behaviour. It is a bit unfortunate when someone else creates such files without your knowledge. e.g. to direct you to another database or to switch off a configuration such as encryption. Therefore, the feature should be used wisely.

  • Avoid using it in shared user environment where multiple user login into the same OS user e.g. like oracle software owner
  • Douple check whats stored in your home folder
  • Be aware, that you can disable settings which are centrally defined in a TNS_ADMIN folder
  • If necessary you can also user INFILE to include additional tnsnames.ora or sqlnet.ora files

Conclusion

Especially for ad hoc tests and troubleshooting of Oracle SQL Net, the hidden configuration files in the User Home are extremely helpful. It is relatively easy to verify certain configurations with a local user. There are only restrictions where the Oracle server process also requires certain information, e.g. the server-side Kerberos and SSL configuration with corresponding reference to the keytab or wallet file. There is no way around working with TNS_ADMIN. For things like Secure External Password Store, however, this feature is worth its weight in gold. You can configure and use a local wallet relatively easily. Yet an other reason why you should work with personal and not shared accounts on the database server 😉.

Additional Resources

A few links and references to relevant documentation, blog posts and other external resources for further reading.

AOUG User Conference 2023 Recap in a Nutshell

Over the past two days, I had the opportunity to participate in the AOUG User Conference as a speaker and presenter. Like in previous years, the conference took place at the Austria Trend Hotel Savoyen. The theme for this year was “Everything Cloud?”

The first day of the conference started off in a smaller setting with various hands-on sessions and initial technical presentations. One definite highlight was Mike Dietrich’s session on Oracle Traditional and Unified Audit, which he spontaneously filled in. It was my first Oracle Security session with Mike, and I thoroughly enjoyed it. I look forward to more sessions like that in the future.

To conclude the first day, the AOUG board invited the speakers to a bowling event at Kugeltanz followed by a joint dinner at Luftburg. Aside from the conference itself, this is always a hidden highlight. Even though it was my third time participating, my bowling skills haven’t improved much, but I still look forward to next year.

The second day is the main conference day, featuring keynotes and four streams covering various topics related to Oracle Database, Cloud, PostgreSQL, APEX, and more. This year, Dominic Giles delivered the keynote, discussing the upcoming Oracle 23c version and providing exciting hints about new features.

I myself presented two sessions this year:

While the conference may not be as large as the DOAG Conference, it provides a unique opportunity to expand one’s network and engage in discussions with colleagues, customers, partners, and Oracle representatives. You can find the complete agenda and further information on the AOUG website.

How to safely resize an LVM volume on Linux

I have several Oracle Cloud Infrastructure (OCI) based Lab environments, which I build with Terraform and corresponding shell scripts. Unfortunately the labs are not one size fits all. Depending on what I’m testing, I have different requirements for the available filesystems. So every now and then I face the problem that I have to increase or decrease the size of the corresponding logical volumes. And just as often I then look for the commands from my notes. I would say that it is time for a blog post.

Caution: Make sure you have a full backup of your logical volume, as tampering with the file system or logical volume can lead to data loss if done incorrectly or something goes wrong. I assume no liability for any errors that may occur as a result of this blog post.

This article is based on examples of how I made changes to the volume groups, logical volumes, and file systems in my lab environment. It may not cover all aspects. Be careful when performing similar steps in your environment.

Check Available Space

First of all, we check our current configuration as well as the used and available memory space. Let’s verify how the situation looks on the file systems. In the following example, we restrict the query to all Oracle mount points with /u0x.

df -kh /u0?
Filesystem                 Size  Used Avail Use% Mounted on
/dev/mapper/vgora-vol_u01   76G   12G   60G  17% /u01
/dev/mapper/vgora-vol_u02   76G   20G   52G  28% /u02
/dev/mapper/vgora-vol_u04   76G  9.5G   62G  14% /u04

With lvs we display information about our logical volumes.

sudo lvs
  LV      VG        Attr       LSize   Pool Origin Data%  Meta%  Move Log Cpy%Sync Convert
  oled    ocivolume -wi-ao----  10.00g                                                    
  root    ocivolume -wi-ao----  35.47g                                                    
  vol_u01 vgora     -wi-ao---- <76.80g                                                    
  vol_u02 vgora     -wi-ao---- <76.80g                                                    
  vol_u04 vgora     -wi-ao---- <76.80g

Using vgs shows us if there is some space left on the logical volume vgora.

sudo vgs
  VG        #PV #LV #SN Attr   VSize    VFree  
  ocivolume   1   2   0 wz--n-   45.47g      0 
  vgora       1   3   0 wz--n- <256.00g <25.61g

If there is some space left, we can go ahead and extend the logical volume vol_ora01. If not, we must either expand the volume group vgora with an additional disk or shrink another logical volume in the group.

Extend Volume Group

List all block devices using lsblk

sudo lsblk

Create a partition using fdisk. Make sure the system id of the partitions should be set to “Linux LVM” (8e)

fdisk /dev/sdc

Create a physical volume using pvcreate

sudo pvcreate /dev/sdc1

List the new LVM devices using lvmdiskscan

sudo lvmdiskscan -l

Finally extend the volume group vgora with the new device

sudo vgextend vgora /dev/sdc

Extend Logical Volume

We now extend the logical volume vol_u01 from 76G to 95G. Check the man page of lvextend for a couple of other option to extend the logical volume.

sudo lvextend -L 95G /dev/mapper/vgora-vol_u01
  Size of logical volume vgora/vol_u01 changed from <76.80 GiB (19660 extents) to 95.00 GiB (24320 extents).
  Logical volume vgora/vol_u01 successfully resized.

Resize the filesystem using resize2fs

sudo resize2fs /dev/mapper/vgora-vol_u01
resize2fs 1.46.2 (28-Feb-2021)
Filesystem at /dev/mapper/vgora-vol_u01 is mounted on /u01; on-line resizing required
old_desc_blocks = 10, new_desc_blocks = 12
The filesystem on /dev/mapper/vgora-vol_u01 is now 24903680 (4k) blocks long.

Verify the new size of the volumes using df

df -kh /u0?
Filesystem                 Size  Used Avail Use% Mounted on
/dev/mapper/vgora-vol_u01   93G   24G   66G  27% /u01
/dev/mapper/vgora-vol_u02   76G   14G   59G  19% /u02
/dev/mapper/vgora-vol_u04   76G   24G   49G  33% /u04

Shrink Logical Volume

Shrinking a logical volume essentially consists of the same steps as increasing it, only in reverse order. In addition, however, the logical volume is checked beforehand and taken offline for this purpose. In the following we will perform this using the example of the logical volume vol_u02.

Caution: Make sure you have a full backup of your logical volume, as downsizing can lead to data loss if you do it wrong or something goes wrong.

Unmount the logical volume vol_u02

sudo umount /dev/mapper/vgora-vol_u02

Run a filesystem check using e2fsck

sudo e2fsck -f /dev/mapper/vgora-vol_u02
e2fsck 1.46.2 (28-Feb-2021)
Pass 1: Checking inodes, blocks, and sizes
Inode 4325387 extent tree (at level 2) could be narrower.  Optimize<y>? yes
Pass 1E: Optimizing extent trees
Pass 2: Checking directory structure
Pass 3: Checking directory connectivity
Pass 4: Checking reference counts
Pass 5: Checking group summary information

/dev/mapper/vgora-vol_u02: ***** FILE SYSTEM WAS MODIFIED *****
/dev/mapper/vgora-vol_u02: 65/5038080 files (24.6% non-contiguous), 3908739/20131840 blocks

We resize the filesystem using resize2fs. But be careful when you set new files. And don’t get nervous, it can take a few seconds longer… 😉

sudo resize2fs /dev/mapper/vgora-vol_u02 25G
resize2fs 1.46.2 (28-Feb-2021)
Resizing the filesystem on /dev/mapper/vgora-vol_u02 to 6553600 (4k) blocks.

The filesystem on /dev/mapper/vgora-vol_u02 is now 6553600 (4k) blocks long.

After reducing the filesystem size we finally can reduce the size of the logical volume using lvreduce.

sudo lvreduce -L 25G /dev/mapper/vgora-vol_u02
  WARNING: Reducing active logical volume to 25.00 GiB.
  THIS MAY DESTROY YOUR DATA (filesystem etc.)
Do you really want to reduce vgora/vol_u02? [y/n]: y
  Size of logical volume vgora/vol_u02 changed from <76.80 GiB (19660 extents) to 25.00 GiB (6400 extents).
  Logical volume vgora/vol_u02 successfully resized.

Run resize2fs again to set the new file system size of the logical volume.

sudo resize2fs /dev/mapper/vgora-vol_u02
resize2fs 1.46.2 (28-Feb-2021)
The filesystem is already 6553600 (4k) blocks long.  Nothing to do!

Finally mount the filesystem again and check the new space.

sudo mount /dev/mapper/vgora-vol_u02
df -kh /u0?
Filesystem                 Size  Used Avail Use% Mounted on
/dev/mapper/vgora-vol_u01   93G   24G   66G  27% /u01
/dev/mapper/vgora-vol_u02   25G   14G  9.7G  58% /u02
/dev/mapper/vgora-vol_u04   76G   24G   49G  33% /u04

Conclusion

Manipulating file systems, logical volumes or volume groups is not as complicated as it looks at first. Nevertheless, you must be aware that some things can go wrong during these steps. It is like an open heart surgery. It is always recommended to have enough disk space from the beginning and to keep manipulations as low as possible. And if you have to do something anyway, you should have appropriate backups of the affected file systems, databases, etc. In my case this is the Terraform configuration of my LAB to rebuild it.

References

A few links and references used to create this blog post. Whereby most of them are much more extensive than my contribution. But as I said, my blog post is just a personal note.

There are a thousand other good sites on this subject….

Get Oracle Database 23c for free on your Mac M1

Oracle Database 23c Free – Developer Release is all over since Oracle released it yesterday. See the Official Oracle pages Oracle Database Free or the blog post by Gerald Venzl Introducing Oracle Database 23c Free – Developer Release. Connor McDonald even got a special delivery from Oracle.

A few important web pages related to Oracle Database 23c Free.

Ok, so what do we do now in order to be able to use Oracle Database 23c Free on a Mac with Apple Silicon? Setup a Vagrant VM, Docker Container or rather use a cloud based solution? Below I show you how to do this relatively easily using a Docker container that runs reasonably well.

Requirements

Basically, x86-64 based Docker containers also run on Apple Silicon / ARM. However, these are emulated with Rosetta2 and are not as stable / performant. But the whole thing is a bit more complex than described there. Docker and colima can both use Rosetta 2, although Rosetta 2 is always slower than native ARM code but faster than QEMU. Because Rosetta 2 does not know or provide all instructions, it can lead to problems depending on the container. Therefore certain containers are less stable. QEMU on the other hand interprets every instruction. Thus it is more stable but slower. Therefore things are somewhat better when using colima with x86-64. In the end, the performance is not that great. However, it is sufficient for simple tests on the road. Maybe I will find some time to go deeper into the topics of ARM/x86-64 with Rosetta 2, QEMU etc.

Setup and Run

You can either configure all the stuff mentioned above manual or use brew. I do prever brew whenever possible. So let’s install brew first

/bin/bash -c "$(curl -fsSL https://raw.githubusercontent.com/Homebrew/install/HEAD/install.sh)"

Update and upgrade your brew installation

brew update
brew upgrade

Install colima and Docker for MacOS

brew install colima docker

We are now ready to start colima. See GitHub repository abiosoft/colima for full usage

colima start --arch x86_64 --memory 4

Start up the Oracle Database 23c Free Docker container. As Docker has to pull about 3GB, it will take a while depending on the networkspeed.

docker run -d --name db23c -P container-registry.oracle.com/database/free

As usual, you have to wait a month for an Oracle database to be created. With Docker logs you can check when the database is available.

docker logs -f db23c
Starting Oracle Net Listener.
Oracle Net Listener started.
Starting Oracle Database instance FREE.
Oracle Database instance FREE started.

The Oracle base remains unchanged with value /opt/oracle
#########################
DATABASE IS READY TO USE!
#########################
The following output is now a tail of the alert.log:
===========================================================
Dumping current patch information
===========================================================
No patches have been applied
===========================================================
2023-04-05T06:35:33.856200+00:00
FREEPDB1(3):Opening pdb with Resource Manager plan: DEFAULT_PLAN
2023-04-05T06:35:40.175165+00:00
Completed: Pluggable database FREEPDB1 opened read write 
Completed: ALTER DATABASE OPEN

Set a new SYS password using setPassword.sh

docker exec db23c ./setPassword.sh <PASSWORD>

And here we go let’s connect via sqlplus as SYSDBA

docker exec -it db23c sqlplus / as sysdba
SQL*Plus: Release 23.0.0.0.0 - Developer-Release on Wed Apr 5 09:11:04 2023
Version 23.2.0.0.0

Copyright (c) 1982, 2023, Oracle.  All rights reserved.


Connected to:
Oracle Database 23c Free, Release 23.0.0.0.0 - Developer-Release
Version 23.2.0.0.0

SQL> select sysdate;

SYSDATE
---------
05-APR-23

SQL>

If you prefer, you can also use SQL Developer. Just login to localhost, port and service name. If you started the container with -P like me, docker ps or docker ports shows the corresponding port.

docker port db23c
1521/tcp -> 0.0.0.0:49153
1521/tcp -> :::49153

SQL Developer configuration for the local Docker container. Port must be adjusted accordingly.

And here we go…

First Steops

Installation of the SCOTT schema. But first update the script to connect to the pluggable database.

docker exec db23c sed -i "s|CONNECT SCOTT/tiger$|CONNECT SCOTT/tiger@freepdb1|" \
/opt/oracle/product/23c/dbhomeFree/rdbms/admin/utlsampl.sql

Run SQLPlus to create the SCOTT schema

docker exec -it db23c sqlplus / as sysdba
ALTER SESSION SET CONTAINER=freepdb1;
@?/rdbms/admin/utlsampl.sql

Create a new user and grant him read access to the tables of the SCOTT schema.

ALTER SESSION SET CONTAINER=freepdb1;
CREATE USER king IDENTIFIED BY tiger;
GRANT CREATE SESSION TO king;
GRANT READ ANY TABLE ON SCHEMA scott TO king;

And test it as KING

CONNECT king/tiger@freepdb1
SET PAGESIZE 200
SET LINESIZE 120
SET PAGESIZE 200
SELECT * FROM scott.emp;
     EMPNO ENAME      JOB	       MGR HIREDATE	    SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK	      7902 17-DEC-80	    800 		   20
      7499 ALLEN      SALESMAN	      7698 20-FEB-81	   1600        300	   30
      7521 WARD       SALESMAN	      7698 22-FEB-81	   1250        500	   30
      7566 JONES      MANAGER	      7839 02-APR-81	   2975 		   20
      7654 MARTIN     SALESMAN	      7698 28-SEP-81	   1250       1400	   30
      7698 BLAKE      MANAGER	      7839 01-MAY-81	   2850 		   30
      7782 CLARK      MANAGER	      7839 09-JUN-81	   2450 		   10
      7788 SCOTT      ANALYST	      7566 19-APR-87	   3000 		   20
      7839 KING       PRESIDENT 	   17-NOV-81	   5000 		   10
      7844 TURNER     SALESMAN	      7698 08-SEP-81	   1500 	 0	   30
      7876 ADAMS      CLERK	      7788 23-MAY-87	   1100 		   20
      7900 JAMES      CLERK	      7698 03-DEC-81	    950 		   30
      7902 FORD       ANALYST	      7566 03-DEC-81	   3000 		   20
      7934 MILLER     CLERK	      7782 23-JAN-82	   1300 		   10

14 rows selected.

Excellent, full READ access to a schema respectively the tables of a schema with only one statement.

Conclusion

The Developer Release of Oracle Database 23c is great. A unique opportunity to test various Oracle features very early without having to join the Oracle Beta Program. But be aware, do not expect light speed when runing an Oracle Database Container on Apple Silicon. This workaround is ideal when you are on the road and want to test nes stuff. For reliable speed, there is no way around running Oracle Database 23c on an x86-64 system. Either you have an old Mac lying around or you build a small environment in the cloud. But who knows, maybe Oracle will surprise us with an ARM version of Oracle Database 23c…

Great, I found my Audit Policies again

A while ago I wrote a blog post about issues with some Oracle Unified Audit Policies see Help I lost my brand new Unified Audit Policy? In the meantime, the whole thing no longer looks so tragic. The problem is an official bug for which Oracle has already released a one-off patch. See Oracle Support Document 30769454.8 Bug 30769454 – Policy Created For Some Actions Are Not Showing In Audit_Unified_Policies.

Install and Test

Let’s see how our system looks before we install the patch. The output of OPatch shows that nothing special has been installed except RU 19.18.

oracle@db19:~/ [TSEC02] $cdh/OPatch/opatch lspatches
34777391;JDK BUNDLE PATCH 19.0.0.0.230117
34786990;OJVM RELEASE UPDATE: 19.18.0.0.230117 (34786990)
34765931;Database Release Update : 19.18.0.0.230117 (34765931)
29585399;OCW RELEASE UPDATE 19.3.0.0.0 (29585399)

I’ll create an other audit policy to verify that we still have the issue.

CREATE AUDIT POLICY tvdlm_dir_access
  ACTIONS
    READ DIRECTORY,
    WRITE DIRECTORY,
    EXECUTE DIRECTORY
  ONLY TOPLEVEL;

And as expected, we do not see these in AUDIT_UNIFIED_POLICIES.

SET pagesize 200
SET linesize 160
COL policy_name FOR A25
SELECT policy_name FROM audit_unified_policies
  WHERE policy_name LIKE 'TVD%' 
  GROUP BY policy_name ORDER BY policy_name;
no rows selected

But in the view DBA_OBJECTS.

SET pagesize 200
SET linesize 160
COL object_name FOR A25
COL object_type FOR A25
SELECT object_name, object_type FROM dba_objects
  WHERE object_name LIKE 'TVD%' ORDER BY object_name;
OBJECT_NAME		  OBJECT_TYPE
------------------------- -------------------------
TVDLM_DIR_ACCESS	  UNIFIED AUDIT POLICY

Run opatch apply to install the one-off patch

oracle@db19:/tmp/30769454/ [TSEC02] $cdh/OPatch/opatch apply
Oracle Interim Patch Installer version 12.2.0.1.36
Copyright (c) 2023, Oracle Corporation.  All rights reserved.


Oracle Home       : /u01/app/oracle/product/19.0.0.0
Central Inventory : /u01/app/oraInventory
   from           : /u01/app/oracle/product/19.0.0.0/oraInst.loc
OPatch version    : 12.2.0.1.36
OUI version       : 12.2.0.7.0
Log file location : /u01/app/oracle/product/19.0.0.0/cfgtoollogs/opatch/opatch2023-04-04_22-41-48PM_1.log

Verifying environment and performing prerequisite checks...
OPatch continues with these patches:   30769454  

Do you want to proceed? [y|n]
y
User Responded with: Y
All checks passed.
Backing up files...
Applying interim patch '30769454' to OH '/u01/app/oracle/product/19.0.0.0'

Patching component oracle.rdbms.dbscripts, 19.0.0.0.0...
Patch 30769454 successfully applied.
Log file location: /u01/app/oracle/product/19.0.0.0/cfgtoollogs/opatch/opatch2023-04-04_22-41-48PM_1.log

OPatch succeeded.

And finally datapatch

oracle@db19:/tmp/30769454/ [TSEC02] $cdh/OPatch/datapatch
SQL Patching tool version 19.18.0.0.0 Production on Tue Apr  4 22:43:53 2023
Copyright (c) 2012, 2023, Oracle.  All rights reserved.

Log file for this invocation: /u01/app/oracle/cfgtoollogs/sqlpatch/sqlpatch_8785_2023_04_04_22_43_53/sqlpatch_invocation.log

Connecting to database...OK
Gathering database info...done
Bootstrapping registry and package to current versions...done
Determining current state...done

Current state of interim SQL patches:
Interim patch 30769454 (POLICY CREATED FOR SOME ACTIONS ARE NOT SHOWING IN AUDIT_UNIFIED_POLICIES):
  Binary registry: Installed
  SQL registry: Not installed
Interim patch 31668882 (OJVM RELEASE UPDATE: 19.9.0.0.201020 (31668882)):
  Binary registry: Not installed
  SQL registry: Rolled back successfully on 30-MAR-23 04.22.06.093772 PM
Interim patch 34786990 (OJVM RELEASE UPDATE: 19.18.0.0.230117 (34786990)):
  Binary registry: Installed
  SQL registry: Applied with errors on 30-MAR-23 04.25.21.102732 PM

Current state of release update SQL patches:
  Binary registry:
    19.18.0.0.0 Release_Update 230111171738: Installed
  SQL registry:
    Applied 19.18.0.0.0 Release_Update 230111171738 with errors on 30-MAR-23 04.25.21.097389 PM

Adding patches to installation queue and performing prereq checks...done
Installation queue:
  No interim patches need to be rolled back
  Patch 34765931 (Database Release Update : 19.18.0.0.230117 (34765931)):
    Apply from 19.9.0.0.0 Release_Update 200930183249 to 19.18.0.0.0 Release_Update 230111171738
  The following interim patches will be applied:
    34786990 (OJVM RELEASE UPDATE: 19.18.0.0.230117 (34786990))
    30769454 (POLICY CREATED FOR SOME ACTIONS ARE NOT SHOWING IN AUDIT_UNIFIED_POLICIES)

Installing patches...
Patch installation complete.  Total patches installed: 3

Validating logfiles...done
Patch 34765931 apply: SUCCESS
  logfile: /u01/app/oracle/cfgtoollogs/sqlpatch/34765931/25078403/34765931_apply_TSEC02_2023Apr04_22_44_17.log (no errors)
Patch 34786990 apply: SUCCESS
  logfile: /u01/app/oracle/cfgtoollogs/sqlpatch/34786990/25032666/34786990_apply_TSEC02_2023Apr04_22_44_16.log (no errors)
Patch 30769454 apply: SUCCESS
  logfile: /u01/app/oracle/cfgtoollogs/sqlpatch/30769454/25157729/30769454_apply_TSEC02_2023Apr04_22_47_53.log (no errors)
SQL Patching tool complete on Tue Apr  4 22:48:16 2023

opatch now lists the oneonf patch

oracle@db19:/tmp/30769454/ [TSEC02] $cdh/OPatch/opatch lspatches
30769454;POLICY CREATED FOR SOME ACTIONS ARE NOT SHOWING IN AUDIT_UNIFIED_POLICIES
34777391;JDK BUNDLE PATCH 19.0.0.0.230117
34786990;OJVM RELEASE UPDATE: 19.18.0.0.230117 (34786990)
34765931;Database Release Update : 19.18.0.0.230117 (34765931)
29585399;OCW RELEASE UPDATE 19.3.0.0.0 (29585399)

OPatch succeeded.

Without further adjustments the created policy is now visible in AUDIT_UNIFIED_POLICIES.

SET pagesize 200
SET linesize 160
COL policy_name FOR A25
SELECT policy_name FROM audit_unified_policies
  WHERE policy_name LIKE 'TVD%' 
  GROUP BY policy_name ORDER BY policy_name;
POLICY_NAME
-------------------------
TVDLM_DIR_ACCESS

Conclusion

As written in the original blog post, the issue is not critical, but can cause problems during automated deployment. Especially if you check in AUDIT_UNIFIED_POLICIES if a policy already exists. The workaround is to query DBA_OBJECTS directly instead of AUDIT_UNIFIED_POLICIES. Or install the One-Off patch. It is a pleasure when issues are fixed quickly by a bugfix. The probability is by the way relatively high, that this bugfix will be fixed with the next release update in April. We’ll see…

Help I lost my brand new Unified Audit Policy?

I am currently working on audit concepts as well as corresponding Unified Audit Policies for various customer projects. That’s why today I once again had a closer look at Oracle Unified Audit.

One requirement in the security concept is to be able to track if someone accesses the operating system via Oracle DIRECTORY OBJECTS. To do this, you can either work with an explicit object action on a specific directory or you can generally audit the object actions on directories. An audit policy with one or more explicit object actions must of course be managed accordingly. Therefore I decided to monitor actions on Oracle directories in general. I.e. READ, WRITE and EXECUTE.

The Problem

My audit policy looks as follows:

CREATE AUDIT POLICY tvdlm_dir_access
  ACTIONS
    READ DIRECTORY,
    WRITE DIRECTORY,
    EXECUTE DIRECTORY
  ONLY TOPLEVEL;

Cheerfully we check once in the data dictionary view audit_unified_policies our policy

SET pagesize 200
SET linesize 160
COL policy_name FOR A25
SELECT policy_name FROM audit_unified_policies
GROUP BY policy_name ORDER BY policy_name;

As you can see the new policy is not shown in the data dictionary view audit_unified_policies.

POLICY_NAME
-------------------------
ORA_ACCOUNT_MGMT
ORA_CIS_RECOMMENDATIONS
ORA_DATABASE_PARAMETER
ORA_DV_AUDPOL
ORA_DV_AUDPOL2
ORA_LOGON_FAILURES
ORA_RAS_POLICY_MGMT
ORA_RAS_SESSION_MGMT
ORA_SECURECONFIG

9 rows selected.

But when you try to create it once more you get an error ORA-46358.

CREATE AUDIT POLICY tvdlm_dir_access
  ACTIONS
    READ DIRECTORY,
    WRITE DIRECTORY,
    EXECUTE DIRECTORY
  ONLY TOPLEVEL;
CREATE AUDIT POLICY tvdlm_dir_access
*
ERROR at line 1:
ORA-46358: Audit policy TVDLM_DIR_ACCESS already exists.

But where is it? Lets see if we found it in dba_objects.

SET pagesize 200
SET linesize 160
COL object_name FOR A25
COL object_type FOR A25
SELECT object_name, object_type FROM dba_objects
  WHERE object_name LIKE 'TVD%' ORDER BY object_name;
OBJECT_NAME		  OBJECT_TYPE
------------------------- -------------------------
TVDLM_DIR_ACCESS	  UNIFIED AUDIT POLICY

OK in dba_objects we can see the policy. Can we also use / enable it?

Test Case

Let’s setup a simple test case to see if this audit policy does work even when it is not shown as valid audit policy in audit_unified_policies. As a first step we do enable the audit policy for all user.

AUDIT POLICY tvdlm_dir_access;

Verify all active unified audit policies by quering audit_unified_enabled_policies.

SET linesize 160 pagesize 200
COL policy_name FOR A20
COL entity_name FOR A10

SELECT * FROM audit_unified_enabled_policies;
POLICY_NAME          ENABLED_OPTION  ENTITY_NAM ENTITY_ SUC FAI
-------------------- --------------- ---------- ------- --- ---
ORA_SECURECONFIG     BY USER         ALL USERS  USER    YES YES
ORA_LOGON_FAILURES   BY USER         ALL USERS  USER    NO  YES
TVDLM_DIR_ACCESS     BY USER         ALL USERS  USER    YES YES

3 rows selected.

This looks promising. At least the active audit policy is shown correctly. Now, to test access, we create an Oracle directory object. For the test I use the user scott.

CREATE OR REPLACE DIRECTORY exttab AS '/u01/app/oracle/admin/TSEC02/adhoc';
GRANT READ, WRITE ON DIRECTORY exttab TO scott;

In the adhoc folder we do create a csv file scott.emp.csv with the following content.

SELECT empno||','||ename||','||job csv_output FROM scott.emp;
CSV_OUTPUT
-------------------------------------------------------------
7369,SMITH,CLERK
7499,ALLEN,SALESMAN
7521,WARD,SALESMAN
7566,JONES,MANAGER
7654,MARTIN,SALESMAN
7698,BLAKE,MANAGER
7782,CLARK,MANAGER
7788,SCOTT,ANALYST
7839,KING,PRESIDENT
7844,TURNER,SALESMAN
7876,ADAMS,CLERK
7900,JAMES,CLERK
7902,FORD,ANALYST
7934,MILLER,CLERK

14 rows selected.

And finally we do create a simple external table on this csv file.

CREATE TABLE scott.emp_external(
    EMPNO NUMBER(4),
    ename VARCHAR2(10),
    job VARCHAR2(9)
)
ORGANIZATION EXTERNAL(
    TYPE oracle_loader
    DEFAULT DIRECTORY exttab
    ACCESS PARAMETERS 
    (FIELDS TERMINATED BY ',')
    LOCATION ('scott.emp.csv'));

Before we query the external table, we purge the audit trail to have a clean trail 😊

EXEC dbms_audit_mgmt.clean_audit_trail( audit_trail_type => dbms_audit_mgmt.audit_trail_unified,use_last_arch_timestamp => FALSE);

Run the query on the external table scott.emp_external.

SELECT * FROM scott.emp_external;
     EMPNO ENAME      JOB
---------- ---------- ---------
      7369 SMITH      CLERK
      7499 ALLEN      SALESMAN
      7521 WARD       SALESMAN
      7566 JONES      MANAGER
      7654 MARTIN     SALESMAN
      7698 BLAKE      MANAGER
      7782 CLARK      MANAGER
      7788 SCOTT      ANALYST
      7839 KING       PRESIDENT
      7844 TURNER     SALESMAN
      7876 ADAMS      CLERK
      7900 JAMES      CLERK
      7902 FORD       ANALYST
      7934 MILLER     CLERK

14 rows selected.

Verify what we do have in the unified_audit_trail.

COL event_timestamp FOR A26
COL entry_id FOR 999
COL dbusername FOR A5
COL dbproxy_username FOR A10
COL action_name FOR A18
COL return_code FOR 999999
COL object_schema FOR A10
COL object_name FOR A16
COL unified_audit_policies FOR A20
SET LINES 200
SET PAGES 999
SELECT
   to_char(event_timestamp,'DD.MM.YY HH24:MI:SS') "Timestamp",
   entry_id,
   action_name,
   object_name
   --, unified_audit_policies
FROM
    unified_audit_trail
ORDER BY
    event_timestamp ,
    entry_id;
Timestamp         ENTRY_ID ACTION_NAME        OBJECT_NAME                                                                                                                                               
----------------- -------- ------------------ ----------------                                                                                                                                          
16.03.23 15:52:17       42 EXECUTE            DBMS_AUDIT_MGMT                                                                                                                                           
16.03.23 15:52:36        1 READ DIRECTORY     EXTTAB                                                                                                                                                    
16.03.23 15:52:36        2 EXECUTE DIRECTORY  EXTTAB                                                                                                                                                    
16.03.23 15:52:36        3 WRITE DIRECTORY    EXTTAB                                                                                                                                                    
16.03.23 15:52:36        4 READ DIRECTORY     EXTTAB                                                                                                                                                    
16.03.23 15:52:36        5 EXECUTE DIRECTORY  EXTTAB                                                                                                                                                    
16.03.23 15:52:36        6 WRITE DIRECTORY    EXTTAB                                                                                                                                                    
16.03.23 15:52:36        7 READ DIRECTORY     EXTTAB                                                                                                                                                    
16.03.23 15:52:36        8 EXECUTE DIRECTORY  EXTTAB                                                                                                                                                    
16.03.23 15:52:36        9 WRITE DIRECTORY    EXTTAB                                                                                                                                                    
16.03.23 15:52:36       10 READ DIRECTORY     EXTTAB                                                                                                                                                    
16.03.23 15:52:36       11 EXECUTE DIRECTORY  EXTTAB                                                                                                                                                    
16.03.23 15:52:36       12 WRITE DIRECTORY    EXTTAB                                                                                                                                                    
16.03.23 15:52:36       13 READ DIRECTORY     EXTTAB                                                                                                                                                    
16.03.23 15:52:36       14 EXECUTE DIRECTORY  EXTTAB                                                                                                                                                    
16.03.23 15:52:36       15 WRITE DIRECTORY    EXTTAB                                                                                                                                                    
16.03.23 15:52:36       16 READ DIRECTORY     EXTTAB                                                                                                                                                    
16.03.23 15:52:36       17 EXECUTE DIRECTORY  EXTTAB                                                                                                                                                    
16.03.23 15:52:36       18 WRITE DIRECTORY    EXTTAB                                                                                                                                                    

19 rows selected.

Conclusion

So the whole thing is not as bad as it looked at the beginning. The audit policy is created, can be activated and the corresponding audit records are created. Nevertheless, not seeing the audit policy in audit_unified_policies is a bit confusing. Especially since according to Oracle documentation this view should list all available audit policies. After a bit of research and a service request, it sure turned out that this is a known issue. A corresponding bugfix seems to be in the works. Until then you have to query dba_objects to check if a policy really exists.

A few final facts…

  • Oracle Support Document 30769454.8 Bug 30769454 – Policy Created For Some Actions Are Not Showing In Audit_Unified_Policies.
  • Oracle Support Document 2419064.1 Audit Policy is Not Seen in AUDIT_UNIFIED_POLICIES After Dropping Objects.
  • Oracle Database Enterprise Edition up to 21.3 is affected. Testing with 21c RU January 2023 (21.9.0.0) showed that in this version the problem is fixed.
  • Audit policies on directory action do create a couple of audit records. It seems that this is related to how external tables are accessed. This can be reduced by explicitly set NOLOGFILE, NOBADFILE or NODISCARDFILE. But still then there will always be more than just one single entry.

Easily mitigate log4j vulnerability in Oracle Unified Directory

In December 2021, the critical vulnerability in Apache Log4j (CVE-2021-44228) was disclosed. With a CVSS rating of 10 out of 10, this vulnerability was or is extremely critical. Especially since Log4j is used relatively widely. Despite a great effort, many applications could only be corrected with a delay. Thus, it is not surprising that this vulnerability is still on our minds. This is also the case with Oracle Unified Directory in several customer projects. In this blog post I show how to find and install the appropriate patch for Oracle Unified Directory and check if the vulnerability is fixed.

Background

As with many other products, Oracle Unified Directory also includes the Apache Log4j library. In particular the directory oracle_common/modules/thirdparty includes a bunch of third party modules. Accordingly, the home directory of Oracle Unified Directory is in the focus of security scanners, which find the corresponding Apache Log4j library and identify it as a potential vulnerability. See also Oracle Support Document 2830143.1.

But as far as I know, Log4j is not used at all in a regular OUD instance. However, it seems reasonable to assume that this is the case. The Java head dump of an OUD instance at least does not list any corresponding Log4j classes. For a simple plausibility test, I used jProfiler to create a head dump of an Oracle Unified Directory instance and inspected the classes.

Java Head Dump of an OUD Instance

There are certainly other tools and better methods to verify this. But since I am not a Java developer, this simple test was sufficient for me.

What now? Oracle Unified Directory does not seem to use Log4j. But the security scanners still show a vulnerability. The easiest thing to do is to define a security exception and ignore the security finding at least for a while and wait for an official patch. It has been a while since December 2021. It will be difficult to justify the security exception for such a long time. So let’s look at possible mitigation measures.

Mitigation

At first, I assumed that the latest April 2022 bundle patch for Oracle Unified Directory would fix this vulnerability. But after the security scanner continued to show the Apache Log4j vulnerability on a new OUD instance with April 2022 bundle patch, I took a closer look. My mistake then was to first look for security fixes for Oracle Unified Directory. In doing so, I disregarded Fusion Middleware, especially Weblogic Server. Finally I made a standalone installation of Oracle Unified Directory to keep the size of the binaries small.

On the third attempt, I read the Oracle Support Document 2827793.1 a little more closely…

Scope of Oracle Support Document 2827793.1

It looks like I finally found my patch to fix CVE-2021-44228. Ok, you have to search a bit more until you find the correct patch.

Update in Oracle Support Document 2827793.1

With an update from April 19, reference is made to Oracle Support Document 2806740.2 Critical Patch Update (CPU) Patch Advisor for Oracle Fusion Middleware – Updated for July 2022. This is the Oracle Support Document, which is updated with every Critical Patch Advisory and lists the different patches for the whole Fusion Middleware Stack. Not so easy to find Oracle Unified Directory the first time. With time you get used to it. Oracle Unified Directory is listed under Identity & Access Management. If you select the current version 12.2.1.4, you get a table with the latest patches around Oracle Unified Directory.

Latest patches for Oracle Unified Directory 12.2.1.4 (Standalone)

Typical case of not reading closely. Anyway, in April I overlooked this patch and only installed the regular bundle patch for OUD. Any way, patching is then as usual easy.

  • Download the patch 34287807 to your directory server
  • Stop all OUD instances using a script or stop-ds
  • Unzip the patch
  • Install the patch using opatch apply
  • Start all OUD instances using a script or start-ds

In summary, the command line commands look like this.

stop-ds
cd /opt/stage
unzip p34287807_122140_Generic.zip
cd 34287807
$ORACLE_HOME/OPatch/opatch apply
start-ds

Verification

Verification is not that easy. Especially since I do not have the same security scanners as the customer. The first check is therefore with the OPatch tool. Below I just grep for Log4j to simplify the output.

$cdh/OPatch/opatch lsinventory -details|grep -i log4j
     compDef.xml --> ORACLE_HOME/inventory/Components/oracle.log4j.log4j/2.11.1.0.0/patches/24823841/compDef.xml
     oracle.log4j.log4j_2.11.1.0.0.xdiff --> ORACLE_HOME/inventory/Components/oracle.log4j.log4j/2.11.1.0.0/patches/24823841/oracle.log4j.log4j_2.11.1.0.0.xdiff
     log4j-2.11.1.jar --> ORACLE_HOME/oracle_common/modules/thirdparty/log4j-2.11.1.jar

As we see the name of the JAR is still log4j-2.11.1.jar. This makes it appear that Oracle is still using the version with the vulnerability. Let’s see what’s in the Manifest file.

unzip -q -c $ORACLE_HOME/oracle_common/modules/thirdparty/log4j-2.11.1.jar META-INF/MANIFEST.MF
Manifest-Version: 1.0
Bundle-Description: The Apache Log4j Implementation
Implementation-Title: Apache Log4j
Bundle-SymbolicName: org.apache.logging.log4j
Implementation-Version: 2.17.1
Archiver-Version: Plexus Archiver
Built-By: Oracle
Specification-Vendor: The Apache Software Foundation
Specification-Title: Apache Log4j
Bundle-Vendor: The Apache Software Foundation
Implementation-Vendor: The Apache Software Foundation
Bundle-Version: 2.17.1
Created-By: Apache Maven 3.6.0
Build-Jdk: 1.8.0_221

It seems that at least the manifest file has been updated. Of course I hope that Oracle has also updated the corresponding classes. If the scanner only checks the filename it will still list a vulnerability. When checking the manifest file and/or the hash value of the classes, no vulnerability is listed anymore.

While searching for ways to easily check the Apache Log4j vulnerability, I came across the GitHub project rubo77/log4j_checker_beta. This project does provide a set of script and hash files to check the environment for possible Apache Log4j vulnerabilities. It is available for Linux, MacOS and Windows.

Let’s have a try and check what the script is finding on a system which just have been patched with 34287807.

curl -s https://raw.githubusercontent.com/rubo77/log4j_checker_beta/main/log4j_checker_beta.sh -o /tmp/log4j_checker_beta.sh
chmod 755 /tmp/log4j_checker_beta.sh
sudo /tmp/log4j_checker_beta.sh -e /u01/app/oracle/product/oud12.2.1.4.0

An extract of a scan with the script looks as follows. You can see that the vulnerability was still found. However, the file with the old version of Apache Log4j is located in the $ORACLE_HOME/.patch_storage directory. This directory contains the old files and is used when patches need to be uninstalled again. To be able to install / uninstall patches correctly, you have to leave this directory as it is. See also Oracle Support Document 2852759.1.

sudo /tmp/log4j_checker_beta.sh -e /u01/app/oracle/product/oud12.2.1.4.0
[INFO] using default hash file. If you want to use other hashes, set another URL as first argument
[INFO] Created vulnerable hashes file from https://raw.githubusercontent.com/rubo77/log4j_checker_beta/main/hashes-pre-cve.txt

[INFO] Looking for files containing log4j...
[INFO] Using locate, which could be using outdated data. Be sure to have called updatedb recently
[WARNING] Maybe vulnerable, those files contain the name:
...
/u01/app/oracle/product/oud12.2.1.4.0/.patch_storage/34287807_Jun_16_2022_09_31_07/files/oracle.log4j.log4j/2.11.1.0.0/thirdparty.symbol/modules/thirdparty/log4j-2.11.1.jar
...
/u01/app/oracle/product/oud12.2.1.4.0/oracle_common/modules/thirdparty/log4j-2.11.1.jar
...
[INFO] Checking installed packages: (solr\|elastic\|log4j)
[INFO] No yum packages found

[INFO] Checking if Java is installed...
[INFO] Java is not installed

[INFO] Analyzing JAR/WAR/EAR files in /var /etc /usr /opt /lib* /u01/app/oracle/product/oud12.2.1.4.0 ...
[INFO] Also checking hashes
...
[WARNING] [463 - contains log4j files] /u01/app/oracle/product/oud12.2.1.4.0/oracle_common/modules/thirdparty/log4j-2.11.1.jar
...
[WARNING] [1308 - vulnerable binary classes] /u01/app/oracle/product/oud12.2.1.4.0/.patch_storage/34287807_Jun_16_2022_09_31_07/files/oracle.log4j.log4j/2.11.1.0.0/thirdparty.symbol/modules/thirdparty/log4j-2.11.1.jar
...
[INFO] Found 1314 files in unpacked binaries containing the string 'log4j' with 1 vulnerabilities
[WARNING] Found 1 vulnerabilities in unpacked binaries
[INFO] _________________________________________________
[WARNING] Some apps bundle the vulnerable library in their own compiled package, so even if 'java' is not installed, one of the applications could still be vulnerable.

[WARNING] This script does not guarantee that you are not vulnerable, but is a strong hint.

Conclusion

The Apache Log4j has been around for a while and is relatively easy to fix in the meantime. As we have seen, it can also be fixed with Oracle Unified Directory. From that point of view, this blog post does not convey breaking news at this point. Since I had to deal with this topic several times in the past in a couple of projects, I have put together this information. I hope one or the other will find this helpful as well.

Finally, a few notes to myself 🙄:

  • Read Oracle support documents carefully. Sometimes they contain an update.
  • Oracle Unified Directory is and will remain a part of Oracle Fusion Middleware. Therefore, general information and patches are also relevant.
  • Always study the whole list of patches in Oracle Support Document 2806740.2 Critical Patch Update (CPU) Patch Advisor for Oracle Fusion Middleware – Updated for July 2022

References

Some references and hints on this topic:

  • Apache Log4j Security Vulnerabilities
  • NIST vulnerability database CVE-2021-44228
  • CVE MITRE database CVE-2021-44228
  • Oracle Support Document 2830143.1 Impact of December 2021 Apache Log4j Vulnerabilities on Oracle on-premises products (CVE-2021-44228, CVE-2021-45046)
  • Oracle Support Document 2847142.1 General impact of Apache Log4j vulnerabilities on Oracle Products and Services
  • Oracle Support Document 2827611.1 Impact of December 2021 Apache Log4j Vulnerabilities on Oracle Products and Services (CVE-2021-44228, CVE-2021-45046)
  • Oracle Support Document 2827793.1 Security Alert CVE-2021-44228 / CVE-2021-45046 Patch Availability Document for Oracle WebLogic Server and Fusion Middleware
  • Oracle Support Document 2806740.2 Critical Patch Update (CPU) Patch Advisor for Oracle Fusion Middleware – Updated for July 2022
  • Oracle Support Document 1074055.1 Security Vulnerability FAQ for Oracle Database and Fusion Middleware Products
  • Oracle Support Document 2768441.1 Details for Oracle Fusion Middleware Third-Party Component Updates
  • Oracle Support Document 2640772.1 Information And Bug Listing of Oracle Unified Directory Bundle Patches: 12.2.1.4.x (12cR2PS4) Version 
  • Oracle Support Document 2638933.1 Summarized Steps to Patch the Underlying Components Used in Oracle Unified Directory 12.2.1.4.x Installations
  • Oracle Support Document 2852759.1 Can Files be Deleted From the .patch_storage Directory After Patches Has Been Applied Successfully
  • rubo77/log4j_checker_beta Log4j check scripts for Linux, macOS and Windows Scripts
  • Common Vulnerability Scoring System version 3.1 Specification Document
  • Blog Post List All the Classes Loaded in the JVM