SELECT POLICY_NAME,ENABLED,AUDIT_TRAIL FROM DBA_AUDIT_POLICIES;
Result:
POLICY_NAME | ENABLED | AUDIT_TRAIL |
---|---|---|
MY_FGAPOLICY_1 | YES | DB+EXTENDED |
MY_FGAPOLICY_2 | YES | DB+EXTENDED |
MY_FGAPOLICY_3 | YES | DB+EXTENDED |
MY_FGAPOLICY_4 | YES | DB+EXTENDED |
Minimalistic Oracle contains a collection of practical examples from my encounters with Oracle technologies. When relevant, I also write about other technologies, like Linux or PostgreSQL. Many of the posts starts with "how to" since they derive directly from my own personal experience. My goal is to provide simple examples, so that they can be easily adapted to other situations.
SELECT POLICY_NAME,ENABLED,AUDIT_TRAIL FROM DBA_AUDIT_POLICIES;
POLICY_NAME | ENABLED | AUDIT_TRAIL |
---|---|---|
MY_FGAPOLICY_1 | YES | DB+EXTENDED |
MY_FGAPOLICY_2 | YES | DB+EXTENDED |
MY_FGAPOLICY_3 | YES | DB+EXTENDED |
MY_FGAPOLICY_4 | YES | DB+EXTENDED |
select os_username,username,userhost,timestamp,obj_name,action_name,priv_used from dba_audit_trail where action_name='DROP USER' and to_char(cast ( timestamp as date),'dd.mm.yyyy') > '08.02.2019' AND OBJ_NAME IN ('JIM','DWIGHT') order by timestamp desc;Result:
OS_USERNAME | USERNAME | USERHOST | TIMESTAMP | OBJ_NAME | ACTION_NAME | PRIV_USED |
---|---|---|---|---|---|---|
root | SYSTEM | hostname1.mydomain.com | 12.02.2019 11:31:05 | JIM | DROP USER | DROP USER |
root | SYSTEM | hostname1.mydomain.com | 12.02.2019 11:28:10 | DWIGHT | DROP USER | DROP USER |
BEGIN SYS.DBMS_STATS.GATHER_INDEX_STATS ( OwnName => 'SCOTT' ,IndName => 'STATUS_IDX_1' ,Estimate_Percent => DBMS_STATS.AUTO_SAMPLE_SIZE ,Degree => DBMS_STATS.DEFAULT_DEGREE ,No_Invalidate => DBMS_STATS.AUTO_INVALIDATE); END; /
ORA-01013: user requested cancel of current operation ORA-00600: internal error code, arguments: [KGL-heap-size-exceeded], [0x114890D28], [6], [1263979496], [], [], [], [], [], [], [], []
set lines 200 col name format a40 col description format a80 col KSPPSTVL format a20 select nam.ksppinm NAME, nam.ksppdesc DESCRIPTION, val.KSPPSTVL from x$ksppi nam, x$ksppsv val where nam.indx = val.indx and nam.ksppinm like '%kgl_large_heap_%_threshold%'; NAME DESCRIPTION KSPPSTVL ----------------------------------- ------------------------------------------------------------------ -------------- _kgl_large_heap_warning_threshold maximum heap size before KGL writes warnings to the alert log 524288000 _kgl_large_heap_assert_threshold maximum heap size before KGL raises an internal error 524288000
alter system set "_kgl_large_heap_warning_threshold"=1572864000 scope=spfile; System altered.
alter system set "_kgl_large_heap_assert_threshold"=2147483648 scope=spfile; ERROR at line 1: ORA-02017: integer value required
alter system set "_kgl_large_heap_assert_threshold"=2147483648 scope=spfile;
toalter system set "_kgl_large_heap_assert_threshold"=2147483647 scope=spfile;
ALTER TABLE JIM.TRANSACTION ADD ( CONSTRAINT TRANSACTION_FK FOREIGN KEY (TRANS_ID) REFERENCES DWIGHT.TRANSACTION_HISTORY(TRANS_ID) );
GRANT REFERENCES ON DWIGHT.TRANSACTION_HISTORY TO JIM;
2019-02-12T13:27:30.506714+01:00 Errors in file /u01/oracle/diag/rdbms/proddb01/proddb01/trace/proddb01_j000_20661.trc: ORA-12012: error on auto execute of job 98 ORA-30967: operation directly on the Path Table is disallowedThis error was connected to a procedure I had made earlier, in this post.
sqlplus username/password begin sys.dbms_job(98); commit; end; /
sqlplus / as sysdba begin sys.dbms_ijob(98); commit; end; /
RMAN-04014: startup failed: ORA-27069: attempt to do I/O beyond the range of the fileThis happened after media recovery was complete, and after the oracle instance was started, as can be seen from the log file below:
RMAN-08181: media recovery complete, elapsed time: 00:00:21 RMAN-03091: Finished recover at 06-FEB-19 RMAN-08031: released channel: c1 RMAN-08031: released channel: c2 RMAN-08031: released channel: aux1 RMAN-08031: released channel: aux2 RMAN-06196: Oracle instance started Total System Global Area 22749904896 bytes Fixed Size 8632928 bytes Variable Size 3758097824 bytes Database Buffers 18924699648 bytes Redo Buffers 58474496 bytes RMAN-08161: contents of Memory Script: { sql clone "alter system set db_name = ''TESTDB01'' comment= ''Reset to original value by RMAN'' scope=spfile"; sql clone "alter system reset db_unique_name scope=spfile"; } RMAN-08162: executing Memory Script RMAN-06162: sql statement: alter system set db_name = ''TESTDB01'' comment= ''Reset to original value by RMAN'' scope=spfile RMAN-06162: sql statement: alter system reset db_unique_name scope=spfile RMAN-00571: =========================================================== RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS =============== RMAN-00571: =========================================================== RMAN-03002: failure of Duplicate Db command at 02/06/2019 04:39:51 RMAN-05501: aborting duplication of target database RMAN-04014: startup failed: ORA-27069: attempt to do I/O beyond the range of the file Additional information: 51 Additional information: 1 Additional information: 48
create role my_ro_role;
grant create job to scott;
ORA-30510: system triggers cannot be defined on the schema of SYS user
conn system/password create or replace trigger scott.add_to_ro_role after CREATE on schema declare l_str varchar2(255); l_job number; begin if ( ora_dict_obj_type = 'TABLE' ) then l_str := 'execute immediate "grant select on ' || ora_dict_obj_name || ' to my_ro_role";'; dbms_job.submit( l_job, replace(l_str,'"','''') ); end if; end; /