Triggers système Oracle (AFTER LOGON) et application à SOX


1- Introduction

Avec Sarbanes-Oxley Act, des nouveaux besoins apparaissent pour auditer et contrôler les accès en base et éventuellement accepter et/ou refuser les accès si des accès sont faits par des logins génériques en analysant les programmes/osuser… entrant. Les triggers de logon introduits avec Oracle 8i apportent une réponse.

Dans le contexte de cette documentation, le login Oracle SOP_DATATEAM est utilisé par une équipe en particulier, seulement l'accès ne peut être accepté que si il s'agit de certains utilisateurs OS clairement identifiés.

2- Vue V$SESSION et fonction sys_context

2-1- Vue V$SESSION

La vue V$SESSION permet de déterminer avec précision d'où vient l'utilisateur qui se connecte.

SQL> desc v$session;
Nom                                       NULL ?   Type
----------------------------------------- -------- ----------------------------

SADDR                                              RAW(4)
SID                                                NUMBER
SERIAL#                                            NUMBER
...
USERNAME                                           VARCHAR2(30)
...
OSUSER                                             VARCHAR2(30)
PROCESS                                            VARCHAR2(12)
MACHINE                                            VARCHAR2(64)
TERMINAL                                           VARCHAR2(16)
PROGRAM                                            VARCHAR2(64)
...

La colonne USERNAME donne le login Oracle utilisé et la colonne OSUSER le login OS/NT utilisé , exemple :

SQL> select osuser,username from v$session where osuser !='SYSTEM';
OSUSER                         USERNAME
------------------------------ ------------------------------
lerouxf                        OPS$BRU

Dans l'exemple ci-dessus : l'utilisateur lerouxf (login XP) s'est connecté avec le login Oracle OPS$BRU.

Dans le contexte de cet article, on souhaite n'autoriser que certains OSUSER clairement identifiés dans une table de référence à se connecter avec un login Oracle SOP_DATATEAM.

2-2- Fonction sys_context

La fonction sys_context permet dans une programmation PL/SQL de récupérer les informations courantes de la session et que l'on retrouve dans la vue V$SESSION.

La syntaxe générale de la fonction sys_context est la suivante :

SELECT sys_context('<namespace>', '<parameter>', <length>);
FROM dual;

Pour les informations de l'environnement de l'utilisateur, <namespace> est toujours USERENV.

Pour récupérer l'OSUSER :

select sys_context('USERENV','OS_USER') from dual ; => lerouxf

Bien d'autres paramètres peuvent être récupérés par la fonction sys_context :

select sys_context('USERENV','SESSIONID') from dual ;
select sys_context('USERENV','HOST') from dual ;

La liste des paramètres de l'environnement qui peuvent être récupérés avec le namespace USERENV est donnée en Annexe 1.

3- System triggers (logon, logoff, startup, shutdown, servererror)

A partir d'Oracle 8i, les triggers systèmes peuvent être déclenchés à la connexion et à la déconnexion, mais aussi après quelques autres évènements système ( BEFORE SHUTDOWN, AFTER SERVERERROR ...)

Syntaxe :

CREATE OR REPLACE TRIGGER <trigger_name>
<trigger_type>
ON DATABASE
....

Les types de trigger systèmes peuvent être :

AFTER LOGON
AFTER STARTUP
BEFORE LOGOFF
BEFORE SHUTDOWN
AFTER SERVERERROR

Si il y a une erreur dans un trigger système et notamment dans un trigger de type AFTER STARTUP, la base de données peut ne pas être redémarrée. Pour désactiver les triggers systèmes au démarrage, dans le fichier init.ora, ajouter la ligne ci-dessous :

-- add the following to the init.ora:
_SYSTEM_TRIG_ENABLED=FALSE

4- Application pratique

Dans cet exemple pratique, créons une table de référence dans laquelle seront implémentées tous les osuser autorisés à se connecter avec le login SOP_DATATEAM, cette dernière table sera créée dans le schéma SYS :

SQL > create table SECURITY_OSUSERS
(
  OSUSER VARCHAR2(30) NOT NULL
);

Le trigger AFTER LOGON peut être alors codé : si pour le login Oracle SESSION_USER=SOP_DATATEAM, il n'existe pas de lignes dans la table SECURITY_OSUSERS pour l'OS_USER entrant, une exception est levée et la connexion est refusée.

SQL>CREATE OR REPLACE TRIGGER systrg_logon
  AFTER LOGON
  ON DATABASE
  DECLARE
    username VARCHAR2(30);
    osuser VARCHAR2(30);
    is_authorized NUMBER;

    BEGIN
      SELECT sys_context ('USERENV', 'SESSION_USER')
      INTO username
      FROM dual;

      IF username='SOP_DATATEAM' then

        SELECT sys_context ('USERENV', 'OS_USER') INTO osuser
          FROM dual;

        SELECT COUNT(*) INTO is_authorized from SECURITY_OSUSERS
          WHERE OSUSER=osuser;

        IF is_authorized=0 then
          raise_application_error( -20001, 'Connection refused, OS User not allowed' );
        END IF;
      END IF;
    END;
/

En cas d'échec :

ERROR:
ORA-00604: une erreur s'est produite au niveau SQL rÚcursif 1
ORA-20001: Connection refused, OS User not allowed
ORA-06512: Ó ligne 16

Le trigger peut aller plus loin pour tracer les OSUSER entrants.

5- Annexe 1 : Paramètres du namespace USERENV pour la fonction sys_context

Paramètre Description
ACTION Identifies the position in the module (application name) and is set through the DBMS_APPLICATION_INFO package or OCI.
AUDITED_CURSORID Returns the cursor ID of the SQL that triggered the audit. This parameter is not valid in a fine-grained auditing environment. If you specify it in such an environment, Oracle Database always returns NULL.
AUTHENTICATED_IDENTITY Returns the identity used in authentication. In the list that follows, the type of user is followed by the value returned:
  • Kerberos-authenticated enterprise user: kerberos principal name
  • Kerberos-authenticated external user : kerberos principal name; same as the schema name
  • SSL-authenticated enterprise user: the DN in the user's PKI certificate
  • SSL-authenticated external user: the DN in the user's PKI certificate
  • Password-authenticated enterprise user: nickname; same as the login name
  • Password-authenticated database user: the database username; same as the schema name
  • OS-authenticated external user: the external operating system user name
  • Radius/DCE-authenticated external user: the schema name
  • Proxy with DN : Oracle Internet Directory DN of the client
  • Proxy with certificate: certificate DN of the client
  • Proxy with username: database user name if client is a local database user; nickname if client is an enterprise user
  • SYSDBA/SYSOPER using Password File: login name
  • SYSDBA/SYSOPER using OS authentication: operating system user name
AUTHENTICATION_DATA Data being used to authenticate the login user. For X.503 certificate authenticated sessions, this field returns the context of the certificate in HEX2 format.

Note: You can change the return value of the AUTHENTICATION_DATA attribute using the length parameter of the syntax. Values of up to 4000 are accepted. This is the only attribute of USERENV for which Oracle implements such a change.

AUTHENTICATION_METHOD Returns the method of authentication. In the list that follows, the type of user is followed by the method returned.
  • Password-authenticated enterprise user, local database user, or SYSDBA/SYSOPER using Password File; proxy with username using password: PASSWORD
  • Kerberos-authenticated enterprise or external user: KERBEROS
  • SSL-authenticated enterprise or external user: SSL
  • Radius-authenticated external user: RADIUS
  • OS-authenticated external user or SYSDBA/SYSOPER: OS
  • DCE-authenticated external user: DCE
  • Proxy with certificate, DN, or username without using password: NONE
BG_JOB_ID Job ID of the current session if it was established by an Oracle background process. Null if the session was not established by a background process.
CLIENT_IDENTIFIER Returns an identifier that is set by the application through the DBMS_SESSION.SET_IDENTIFIER procedure, the OCI attribute OCI_ATTR_CLIENT_IDENTIFIER, or the Java class Oracle.jdbc.OracleConnection.setClientIdentifier. This attribute is used by various database components to identify lightweight application users who authenticate as the same user.
CLIENT_INFO Returns user session information that can be stored by an application using the DBMS_APPLICATION_INFO package.
CURRENT_BIND The bind variables for fine-grained auditing.
CURRENT_SCHEMA Name of the default schema being used in the current schema. This value can be changed during the session with an ALTER SESSION SET CURRENT_SCHEMA statement.
CURRENT_SCHEMAID Identifier of the default schema being used in the current session.
CURRENT_SQL Returns the first 4K bytes of the current SQL that triggered the fine-grained auditing event.
CURRENT_SQLn attributes return subsequent 4K-byte increments, where n can be an integer from 1 to 7, inclusive. CURRENT_SQL1 returns bytes 4K to 8K; CURRENT_SQL2 returns bytes 8K to 12K, and so forth. You can specify these attributes only inside the event handler for the fine-grained auditing feature.
CURRENT_SQL_LENGTH The length of the current SQL statement that triggers fine-grained audit or row-level security (RLS) policy functions or event handlers. Valid only inside the function or event handler.
DB_DOMAIN Domain of the database as specified in the DB_DOMAIN initialization parameter.
DB_NAME Name of the database as specified in the DB_NAME initialization parameter.

SELECT name, value
FROM gv$parameter
where name like 'db%name';
DB_UNIQUE NAME Name of the database as specified in the DB_UNIQUE_NAME initialization parameter.

SELECT name, value
FROM gv$parameter
where name like 'db%name';
ENTRYID The available auditing entry identifier. You cannot use this option in distributed SQL statements. To use this keyword in USERENV, the initialization parameter AUDIT_TRAIL must be set to true.
ENTERPRISE_IDENTITY Returns the user's enterprise-wide identity:
  • For enterprise users: the Oracle Internet Directory DN.
  • For external users: the external identity (Kerberos principal name, Radius and DCE schema names, OS user name, Certificate DN).
  • For local users and SYSDBA/SYSOPER logins: NULL.
    The value of the attribute differs by proxy method:
  • For a proxy with DN: the Oracle Internet Directory DN of the client
  • For a proxy with certificate: the certificate DN of the client for external users; the Oracle Internet Directory DN for global users
  • For a proxy with username: the Oracle Internet Directory DN if the client is an enterprise users; NULL if the client is a local database user.
FG_JOB_ID Job ID of the current session if it was established by a client foreground process. Null if the session was not established by a foreground process.
GLOBAL_CONTEXT_MEMORY The number used in the System Global Area by the globally accessed context. GLOBAL_UID Returns the global user ID from Oracle Internet Directory for Enterprise User Security (EUS) logins; returns null for all other logins. HOST Name of the host machine from which the client has connected.
IDENTIFICATION_TYPE Returns the way the user's schema was created in the database. Specifically, it reflects the IDENTIFIED clause in the CREATE/ALTER USER syntax. In the list that follows, the syntax used during schema creation is followed by the identification type returned:
  • IDENTIFIED BY password: LOCAL
  • IDENTIFIED EXTERNALLY: EXTERNAL
  • IDENTIFIED GLOBALLY: GLOBAL SHARED
  • IDENTIFIED GLOBALLY AS DN: GLOBAL PRIVATE
INSTANCE The instance identification number of the current instance.
INSTANCE_NAME The name of the instance.
IP_ADDRESS IP address of the machine from which the client is connected.
ISDBA TRUE if you are logged on as SYS.
LANG The ISO abbreviation for the language name, a shorter form than the existing 'LANGUAGE' parameter.
LANGUAGE The language and territory currently used by your session, along with the database character set, in the form: language_territory.characterset.
MODULE The application name (module) set through the DBMS_APPLICATION_INFO package or OCI.
NETWORK_PROTOCOL Network protocol being used for communication, as specified in the 'PROTOCOL=protocol' portion of the connect string.
NLS_CALENDAR The current calendar of the current session.
NLS_CURRENCY The currency of the current session.
NLS_DATE_FORMAT The date format for the session
NLS_DATE_LANGUAGE The language used for expressing dates.
NLS_SORT BINARY or the linguistic sort basis.
NLS_TERRITORY The territory of the current session.
OS_USER Operating system username of the client process that initiated the database session.
POLICY_INVOKER The invoker of row-level security (RLS) policy functions.
PROXY_ENTERPRISE_IDENTITY Returns the Oracle Internet Directory DN when the proxy user is an enterprise user.
PROXY_GLOBAL_UID Returns the global user ID from Oracle Internet Directory for Enterprise User Security (EUS) proxy users; returns NULL for all other proxy users.
PROXY_USER Name of the database user who opened the current session on behalf of SESSION_USER.
PROXY_USERID Identifier of the database user who opened the current session on behalf of SESSION_USER.
SERVER_HOST The host name of the machine on which the instance is running.
SERVICE_NAME The name of the service to which a given session is connected.
SESSION_USER Database user name by which the current user is authenticated. This value remains the same throughout the duration of the session.
SESSION_USERID Identifier of the database user name by which the current user is authenticated.
SESSIONID The auditing session identifier. You cannot use this option in distributed SQL statements. SID The session number (different from the session ID).
STATEMENTID The auditing statement identifier. STATEMENTID represents the number of SQL statements audited in a given session.
TERMINAL The operating system identifier for the client of the current session. In distributed SQL statements, this option returns the identifier for your local session. In a distributed environment, this is supported only for remote SELECT statements, not for remote INSERT, UPDATE, or DELETE operations. (The return length of this parameter may vary by operating system.)

Annexe

Historique

Version Date Commentaires
1.0 08/2006 Version initiale

Liens

Oracle9i Database Concepts Release 2 (9.2), Triggers on System Events and User Events
Books OnLine Oracle 9i R2
Oracle