Monday, May 26, 2008

A Security Hardening Approach for userproof databases

What if you have some confusion about some of your database users and want to trace the users or even be notified about their actions in the database or just want to warn them about probable mistakes can be made by db users. Oracle Database software has some solutions about likely cases. Auditing is one of the most used option with tracing. DDL triggers can also be used. There are also some solutions at the opsys level.

1- Logon Triggers to Trace Users
Oracle database has logon triggers to run on any users login to the database. DBA can use this feature to set a trace file for the logged in user. tkprof utility can be used to examine users activity.

CREATE OR REPLACE TRIGGER SYS.TRG_SESSION_LOGON after logon on database
declare
s_username varchar2(20);
s_sessid varchar2(20);
s_stamp varchar2(20);
begin

-- obtain sid of the session
select distinct(substr(sid,1,20)) into s_sessid from v$mystat;

-- obtain username of the session
select username into s_username from v$session where sid=s_sessid;

-- create a timestamp to uniquely identify the trace file
select to_char(sysdate,'DDMMYYYY_HH24MISS') into s_stamp from dual;

-- set the tracefile size to unlimited. careful about that (!)
execute immediate 'alter session set max_dump_file_size=unlimited';

-- define an identifier to the tracefile to distinguish the trace files
execute immediate 'alter session set tracefile_identifier=' || s_username ||
'_' || s_sessid || '_' || s_stamp;

-- i will take 10046 trace level 8 to see the waits
-- (check timed_statistics init parameter!)
execute immediate 'alter session set events ''10046 trace name context forever, level 8''';

-- finally start the trace
execute immediate 'alter session set sql_trace=true';

exception
when others then
raise;

end TRG_LOGON;

You can find the trace files from user_dump_dest parameter

SQL> show parameter user_dump_dest;

NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
user_dump_dest string D:\ORACLEDB10G\ADMIN\ORCL\UDUMP

To examine the dump file tkprof utility can be used.

tkprof orcl_ora_5412_epeker_148_22052008_162752.trc tkprof.out

tkprof.out file.

2- Database Audit
To enable audit option, audit_trail init parameter should be set.

select name, value from v$parameter where name = 'audit_trail';
alter system set audit_trail='DB_EXTENTED' scope=spfile;
--After changing audit_trail parameter bounce the database.

audit select table, insert table, update table, delete table by epeker;
audit session by epeker;


Now login to the database with the audited user and make some ddl.

select * from EPEKER.T_TABLE_DBA_TABLES;
insert into EPEKER.T_TABLE_DBA_TABLES select * from DBA_TABLES where rownum<10;
commit;
select * from EPEKER.T_TABLE_DBA_TABLES;


All the audit information should be in the SYS.AUD$ table

select
SESSIONID, USERID, USERHOST,TERMINAL, OBJ$CREATOR, OBJ$NAME, NTIMESTAMP#, SCN, SQLTEXT
from
SYS.AUD$
order by NTIMESTAMP# desc;


/*
SESSIONID USERID OBJ$CREATOR OBJ$NAME NTIMESTAMP# SCN SQLTEXT
1249 EPEKER SYS, USER$ 5/23/2008 11:45:00 AM 935996 insert into EPEKER.T_TABLE_DBA_TABLES select * from DBA_TABLES where rownum<10
1249 EPEKER SYS, TS$ 5/23/2008 11:45:00 AM 935996 insert into EPEKER.T_TABLE_DBA_TABLES select * from DBA_TABLES where rownum<10
1249 EPEKER SYS, SEG$ 5/23/2008 11:45:00 AM 935996 insert into EPEKER.T_TABLE_DBA_TABLES select * from DBA_TABLES where rownum<10
1249 EPEKER SYS, X$KSPPCV 5/23/2008 11:45:00 AM 935996 insert into EPEKER.T_TABLE_DBA_TABLES select * from DBA_TABLES where rownum<10
1249 EPEKER SYS, TAB$ 5/23/2008 11:45:00 AM 935996 insert into EPEKER.T_TABLE_DBA_TABLES select * from DBA_TABLES where rownum<10
1249 EPEKER SYS, OBJ$ 5/23/2008 11:45:00 AM 935996 insert into EPEKER.T_TABLE_DBA_TABLES select * from DBA_TABLES where rownum<10
1249 EPEKER SYS, DBA_TABLES 5/23/2008 11:45:00 AM 935996 insert into EPEKER.T_TABLE_DBA_TABLES select * from DBA_TABLES where rownum<10
1249 EPEKER SYS, X$KSPPI 5/23/2008 11:45:00 AM 935996 insert into EPEKER.T_TABLE_DBA_TABLES select * from DBA_TABLES where rownum<10
1249 EPEKER EPEKER, T_TABLE_DBA_TABLES 5/23/2008 11:44:10 AM 935944 select * from T_TABLE_DBA_TABLES
1268 EPEKER 5/23/2008 12:01:56 PM
*/

You can revoke the audit by noaudit command.

noaudit select table, insert table, update table, delete table by epeker;
noaudit session by epeker;


3- DDL Triggers
Oracle database has many different trigger options. You have just read about "logon triggers". There is also ddl triggers can be used to disable specific users from mistakenly running dangerous ddl statements. Any user wants to execute a ddl statment (create, truncate.. etc) can be logged and the user can also be warned by the administrator. The following trigger simply disables a user to drop and/or truncate database tables.

CREATE OR REPLACE TRIGGER SYS.TRG_DDL before ddl
ON DATABASE
declare
s_sysevent varchar2(32);
s_owner varchar2(32);
s_objname varchar2(32);
s_user varchar2(32);
begin

select ora_sysevent, ora_dict_obj_owner, ora_dict_obj_name, USER
into s_sysevent, s_owner, s_objname, s_user from dual;

insert into epeker.t_trg_ddl_test values (ora_sysevent);
if s_sysevent in ('DROP','TRUNCATE') then
if s_user = 'EPEKER' then
raise_application_error(-20010,'You are not authorized to drop a segment!.. ');
null;
end if;
end if;

end TRG_DDL;


4- database privileges
Privileges is important (maybe the most important) checklist to be careful about. Privileges and Roles should be carefully assgined and also revoked from users to minimize the mistakenly made data loss in the databases.

5- opsys suggested tasks (alias, sudo, execute privileges, op.sys groups)
Beside database auditing tasks, some securtiy hardening can be made in operating system side. Aliases can be used as of direct op. sys. commands for auditing and preventing mistakes by end users or application users. Some commands need root privileges, this kind of commands can be run through sudo in unix. Application users should not be in dba group and Oracle Home and datafiles should be protected with op. sys. file permissions. Grid agent like management and monitoring tools can be used to audit or proactively solve the likely problems.

Monday, May 19, 2008

Table Monitoring worked well

I was logged in one of our forgotten databases to partition some tables and maintain dba routines. After all my work is done i decided to examine the tables which are not used any more.

First thing is to find if it worths to spend some time on it. I checked the sizes of the tables and found that one of the unused tables consume approximately 21Gb of space. That should be so valuable to drop this table on this database because of the problematic disk space usage.

select
segment_name, sum(bytes/1024/1024) as MB
from
dba_segments
where
segment_name in ('WAP_STATREC','PAYFORME_TEMP','PAY4ME_TEMP') and
owner ='PQ'
group by
segment_name
order by MB desc;

SEGMENT_NAME MB
------------ --
WAP_STATREC 21443
PAYFORME_TEMP 145
PAY4ME_TEMP 1


To obtain if these tables are actively used by developers or any application, i altered these tables to enable monitoring and logout the system.


alter table pq.wap_statrec monitoring
alter table pq.payforme_temp monitoring
alter table pq.pay4me_temp monitoring


Today, when i remembered what have i done for a few weeks earlier, i logged in the database and check the dba_tab_modifications management view to find if any modifications done to the tables.


select
table_owner, table_name, inserts, updates, deletes, timestamp, truncated
from
sys.dba_tab_modifications
where
table_name in ('WAP_STATREC','PAYFORME_TEMP','PAY4ME_TEMP');

TABLE_OWNER TABLE_NAME INSERTS UPDATES DELETES TIMESTAMP TRUNCATED
----------- ---------- ------- ------- ------- --------- ---------
PQ PAYFORME_TEMP 10695476 0 0 5/7/2008 YES



As you can see only one of the tables is actively used by an application and the others are not used for 2 weeks. Now time to talk with the application operation or development group to drop their unused tables.

Tuesday, May 6, 2008

Handling Partitioned Tables

Subject: We have lots of partitioned tables to handle manually. Every begining of the month or year we have add new partitions to prevent "ORA-14400: inserted partition key does not map to any partition". As we have a increasing number of partitioned tables, we faced this problem increasingly for last months.

I decided to write a plsql script that runs in period by a scheduled job. You can find the scheduled job settings in my previous postings. In this posting i will share the procedure that automatically creates the new months partition, archives, compresses and deletes the older partitions by the supplied retention.


CREATE OR REPLACE procedure AVEA_SYSMON.p_check_partition2
(s_table_name IN varchar2,
s_schema_name IN varchar2,
s_archive_ts IN varchar2,
n_archive_ret number,
n_delete_ret number)
/*As i run this procedure from a job. I want running user to own the privileges*/
AUTHID CURRENT_USER
AS
s_compression varchar2(20);
s_ts_name varchar2(20);

n_max_month number;
n_max_year number;

n_next_month number;
n_next_year number;

n_this_year number;
n_this_month number;

part_next_month number;
part_next_year number;

n_ctl number;

d_next_month date;
s_part_less_than varchar2(200);
s_cmd varchar2(200);
begin

/*I will read the dba_tab_partitions management view to find the table partitions.
This procedure works with the formatted name of the partition.
Here you should have YYYYMM at the end of the partition name*/

select
max(substr(partition_name,-6,4)) into n_max_year
from
dba_tab_partitions t1
where
table_owner=s_schema_name and
table_name=s_table_name;

-- get max month of table partition

select
max(substr(partition_name,-2,2)) into n_max_month
from
dba_tab_partitions t1
where
table_owner=s_schema_name and
table_name=s_table_name and
substr(partition_name,-6,4) = n_max_year;

-- find this month this year;
n_this_year := to_number(to_char(sysdate,'YYYY'));
n_this_month := to_number(to_char(sysdate,'MM'));

-- find next month next year
n_next_year := to_number(to_char(add_months(sysdate,1),'YYYY'));
n_next_month := to_number(to_char(add_months(sysdate,1),'MM'));

-- partition definition for next month next year should be one more
part_next_year := to_number(to_char(add_months(sysdate,2),'YYYY'));
part_next_month := to_number(to_char(add_months(sysdate,2),'MM'));


-- check if next months partition exists, create it if not exists

if mod(n_this_month,12) = mod(n_max_month,12) then

s_part_less_than := 'to_date(''01.' || trim(to_char(part_next_month,'09')) || '.' || part_next_year || ''',''DD.MM.YYYY'')';

s_cmd:='alter table ' || s_schema_name || '.' || s_table_name || ' add partition ' || s_table_name || '_' || n_next_year || '_' || trim(to_char(n_next_month,'09')) || ' values less than (' || s_part_less_than || ') ';

--dbms_output.put_line(s_cmd);
begin
execute immediate (s_cmd);
exception
when others then
null;
end;
end if;

/*compress and move partitions to archive tablespace which are
months older*/

begin
select
compression, tablespace_name into s_compression, s_ts_name
from
dba_tab_partitions
where
table_owner=s_schema_name and
table_name=s_table_name and
substr(partition_name,-6,4)=to_char(add_months(sysdate,n_archive_ret),'YYYY') and
substr(partition_name,-2,2)=to_char(add_months(sysdate,n_archive_ret),'MM');

/*first i should be sure if the partition to be compressed and archived
is exists. And move the partition to archive tablespace if it is not already
there and compress if it is not already compresses*/

if s_ts_name!=s_archive_ts then
s_cmd := 'alter table ' || s_schema_name || '.' || s_table_name ||
' move partition ' || s_table_name || '_' ||
trim(to_char(add_months(sysdate,n_archive_ret),'YYYY')) || '' ||
trim(to_char(add_months(sysdate,n_archive_ret),'MM')) ||
' tablespace ' || s_archive_ts;
if s_compression!='ENABLED' then
s_cmd := s_cmd || ' COMPRESS';
end if;
s_cmd := s_cmd || ' update global indexes';
execute immediate (s_cmd);
end if;

s_cmd:='';
exception
when no_data_found then
null;
end;

-- drop partitions of year old

select
count(*) into n_ctl
from
dba_tab_partitions
where
table_owner=s_schema_name and
table_name=s_table_name and
substr(partition_name,-6,4)=to_char(add_months(sysdate,n_delete_ret),'YYYY') and
substr(partition_name,-2,2)=to_char(add_months(sysdate,n_delete_ret),'MM');

/* if the partition to be dropped exists then drop it */

if n_ctl=1 then
s_cmd := 'alter table ' || s_schema_name || '.' || s_table_name ||
' drop partition ' || s_table_name || '_' ||
to_char(add_months(sysdate,n_delete_ret),'YYYY') || '' ||
to_char(add_months(sysdate,n_delete_ret),'MM') ||
' update global indexes';

execute immediate (s_cmd);
end if;

end p_check_partition2;
/


The procedure is OK now. You should now be careful to give the right parameters. Be sure not to drop something should not be dropped. In our site our delete retention is one year and archive retention is 3 months. I run this procedure like the following parameters;

begin
p_check_partition2('PAYFORME','PQ','PQ_ARCHIVE',-3,-12);
end;