Wednesday, May 6, 2009

pga_aggregate_target, sort_area_size and optimal memory usage

First of all thanks to Nobert Debes for exploring PGA memory related parameters.

I ran test in my own environment to compare sort_area_size with PGA and how PGA is being used. Results are as follows:

Table Size: 5.125
Index Size (One that I used for testing with DOP 4): 4.3942

Size in MB


PGA memory and Temporary table space usage (Output from v$sql_workarea_active):

Case 1:

SID TIME WORK_AREA_SIZE MAX_MEM_USED PASSES TEMPSEG_SIZE

81 42:11 2.3 512 1 1050
83 42:11 2.3 512 1 1041
86 42:11 2.3 512 1 1034
92 42:11 3.3 512.1 1 1558

Case 2:

SID TIME WORK_AREA_SIZE MAX_MEM_USED PASSES TEMPSEG_SIZE

87 05:02 1.1 1024 1 1034
88 05:02 1.1 1024 1 1041
89 05:02 1.1 1024 1 1050
90 05:02 1.1 1024 1 1558

Case 3:

SID TIME WORK_AREA_SIZE MAX_MEM_USED PASSES TEMPSEG_SIZE

86 17:47 1103.8 1103.8 0 0
87 17:47 1086.5 1086.5 0 0
88 17:47 1092.8 1092.8 0 0
89 17:47 1.1 1536 1 1558

Case 4 (sort_area_size) :

SID TIME WORK_AREA_SIZE MAX_MEM_USED PASSES TEMPSEG_SIZE

82 39:10 0 .1 4099 1219
88 39:10 0 .1 4102 1795
89 39:10 0 .1 3710 1248
90 39:10 0 .1 3947 1258



Case 1: This is default setting. MAX_MEM_USED used for each parallel process was 512 MB ie _smm_px_max_size/4.

Case 2: I increased all (_) parameter to a higher value. There was some gain in performance but not much as it still has to spill sorts to temporary tablespace. See MAX_MEM_USED used for each parallel process was 1024 MB ie _smm_px_max_size/4

Case 3: As per Case 1 and Case 2 max it has to spill to temporary tablespace was 1558 MB. So I increased PGA to 6 GB _smm_px_max_size to 6GB so that I can accomodate most of the sorting in memory. I could manage to do it with 3 slaves (see PASSES = 0 for 3 slaves) where as fourth slave needed 1558 MB but Oracle will allocate least of _smm_max_size= 1536 MB and _smm_px_max_size/4 = 1536 MB. Response time improved from 8 mins 27 seconds to 6 mins 57 seconds.

Case 4: I used old way of sorting with sort_area_size but it took lot of time. Also I observed SORT/MERGE after SORT operation which took most of the time.

SID % Complete Time Now ELAPSED_SECONDS MESSAGE
--------------- ---------- --------------- --------------- ----------------------------------------------
90.22 .51 090506 12:36:38 111 Sort/Merge: : 5039 out of 995618 Blocks done
82.9 .49 090506 12:36:38 111 Sort/Merge: : 5025 out of 1027136 Blocks done
89.164 .54 090506 12:36:38 111 Sort/Merge: : 5038 out of 934140 Blocks done
88.33 .32 090506 12:36:38 111 Sort/Merge: : 5015 out of 1581604 Blocks done

Conclude: On large Warehouse systems where PGA is set in range of 10G-32G, changing PGA (_) parameters for load and batch processes for sorting, PL/SQL collections will help speed up operations that use PGA memory. Also it can help in multiple node RAC environments where one node is dedicated for Warehouse type of operation.

Friday, February 27, 2009

Estimated Interconnect traffic (KB) - Oracle RAC

In 10g AWR package dbms_workload_repository is wrapped so if you want to find formulae for any statistics its difficult. If you want to plot interconnect traffic Vs Time in Oracle RAC environment you can use following script and create chart using excel:

Note: It will run full AWR report for range of snap id's so do not run during peak hours.

-----------------------------------------------------------------------------------------------
set echo off
set feed off
ACCEPT startt PROMPT'Please enter start time (MM/DD/YYYY):'
ACCEPT endt PROMPT'Please enter end time (MM/DD/YYYY):'
ACCEPT instid PROMPT'Please enter instance number:'
drop table interconnect_traffic;

create table interconnect_traffic (stime varchar2(100), svalue varchar2(100)) tablespace users;
create or replace procedure interconnect_traffic_pr1 (stime date,etime date,instid number)is

intraffic varchar2(100);
databaseid number;
ssnapid number;
esnapid number;
display_date varchar2(100);
i number;
begin
select min(snap_id) into ssnapid from dba_hist_snapshot where (to_date(to_char(begin_interval_time,'MM/DD/YYYY'),'MM/DD/YYYY')) = stime and instance_number = instid;

select max(snap_id)-1 into esnapid from dba_hist_snapshot where (to_date(to_char(begin_interval_time,'MM/DD/YYYY'),'MM/DD/YYYY')) = etime and instance_number = instid;

select dbid into databaseid from v$database ;

for i in ssnapid..esnapid loop

select replace(output,'Estd Interconnect traffic (KB)','') into intraffic from table(dbms_workload_repository.awr_report_text( databaseid,instid,i, i+1,0 )) where output like '%Interconnect%';

select to_char(begin_interval_time,'MM/DD/YYYY HH24:MI') into display_date from dba_hist_snapshot where snap_id = i+1 and instance_number = instid;

insert into interconnect_traffic values (display_date,intraffic);

commit;
end loop;
exception
when others then
dbms_output.put_line(i);
end;
/

execute interconnect_traffic_pr1('&startt','&endt','&instid');

drop procedure interconnect_traffic_pr1;

set echo on
set feed on
column stime format a30
column svalue format a30
select stime,svalue from interconnect_traffic;

---------------------------------------------------------------------------------------------------------------------------------------


spreport.sql shows forumlae of Interconnect traffic as follows:

Estd Interconnect traffic (KB):' hd2, round( ( ((:gccrrv+:gccurv +:gccrsv+:gccusv) :bs) + ((:dpms+:dnpms+:pmrv+:npmrv) 200) * )/&&btokb/:ela,2)

where
gccrrv = gc cr blocks received
gccurv = gc current blocks received
gccrsv = gc cr blocks served
gccusv = gc current blocks served
bs = block_size
dpms = gcs messages sent
dnpms = ges messages sent
pmrv = gcs msgs received
npmrv = ges msgs received
btokb = 1024
ela = elapsed time between two snapshots in seconds.

According to above formulae, script to calculate interconnect traffic is as shown below. Interconnect traffic caculated by below script is close to one calcuated by AWR but not same.

------------------------------------------------------------------------------------------------

set echo off
set feed off
ACCEPT startt PROMPT'Please enter start time (MM/DD/YYYY):'
ACCEPT endt PROMPT'Please enter end time (MM/DD/YYYY):'
ACCEPT instid PROMPT'Please enter instance number:'
drop table interconnect_traffic;
create table interconnect_traffic (stime varchar2(100), svalue varchar2(100)) tablespace users;
create or replace procedure interconnect_traffic_pr1 (stime date,etime date,instid number)isssnapid number;
esnapid number;
ogcstats number;
ngcstats number;
ogmstats number;
ngmstats number;
blksize number;
start_time date;
end_time date;
intraffic number;
cnt number :=2;
display_date varchar2(100);
begin
select min(snap_id) into ssnapid from dba_hist_snapshot where (to_date(to_char(begin_interval_time,'MM/DD/YYYY'),'MM/DD/YYYY')) = stime and instance_number = instid;

select max(snap_id) into esnapid from dba_hist_snapshot where (to_date(to_char(begin_interval_time,'MM/DD/YYYY'),'MM/DD/YYYY')) = etime and instance_number = instid;

select value into blksize from v$parameter where name ='db_block_size';
for i in ssnapid..esnapid loop
select sum(value) into ogcstats from dba_hist_sysstat where stat_name in ('gc cr blocks received','gc current blocks received','gc cr blocks served','gc current blocks served')and snap_id = i and instance_number = instid;
select sum(value) into ngcstats from dba_hist_sysstat where stat_name in ('gc cr blocks received','gc current blocks received','gc cr blocks served','gc current blocks served')and snap_id = i+1 and instance_number = instid;
select to_char(begin_interval_time,'MM/DD/YYYY HH24:MI') into display_date from dba_hist_snapshot where snap_id = i and instance_number = instid;
select sum(value) into ogmstats from dba_hist_sysstat where stat_name in ('gcs messages sent','ges messages sent','gcs msgs received','ges msgs received')and snap_id = i and instance_number = instid;
select sum(value) into ngmstats from dba_hist_sysstat where stat_name in ('gcs messages sent','ges messages sent','gcs msgs received','ges msgs received')and snap_id = i+1 and instance_number = instid;
select (to_date(to_char(begin_interval_time,'MM/DD/YYYY HH24:MI:SS'),'MM/DD/YYYY HH24:MI:SS')) into start_time from dba_hist_snapshot where snap_id = i and instance_number = instid;
select (to_date(to_char(begin_interval_time,'MM/DD/YYYY HH24:MI:SS'),'MM/DD/YYYY HH24:MI:SS')) into end_time from dba_hist_snapshot wheresnap_id = i + 1 and instance_number = instid;
intraffic := (((ngcstats - ogcstats)*blksize ) + ((ngmstats - ogmstats)*200))/1024/((end_time-start_time)*1440*60);
insert into interconnect_traffic values (display_date,intraffic);
commit;
end loop;
end;
/

execute interconnect_traffic_pr1('&startt','&endt','&instid');

drop procedure interconnect_traffic_pr1;
set echo on
set feed onc
olumn stime format a30
column svalue format a30
select stime,svalue from interconnect_traffic;
-------------------------------------------------------------------------------------------------