In general, you want the redo logs to be large enough that you are not constantly swapping logs (generally not more than every 15 or 20 minutes) and small enough that you aren't risking too much data should there be a catastrophic server failure (assuming that archived redo logs are written to a different server and that you aren't using something like DataGuard to replicate the redo to a backup server in real time).
select b.recid,to_char(b.first_time,'DD/MM/YY HH24:MI:SS') start_time,a.recid,
to_char(a.first_time,'DD/MM/YY HH24:MI:SS') end_time,
round(((a.first_time-b.first_time)*25)*60,2) minutes from v$log_history a,v$log_history b where a.recid=b.recid+1 order by
a.first_time asc;
Who is generating redo logs now?
One of the first question, which cover firefighter is: "Who is generating redo logs in this moment". Idea is to determine action on ad hoc basis. For that I use following script, which I call top_redo.sql:
view sourceprint?
/* -----------------------------------------------------------------------------
Filename: top_redo.sql
CR/TR# :
Purpose : Shows current redo logs generation info (RAC-non RAC environment)
Date : 12.08.2008.
Author : Damir Vadas, damir.vadas@gmail.com
Remarks : run as privileged user
Changes (DD.MM.YYYY, Name, CR/TR#):
--------------------------------------------------------------------------- */
col machine for a15
col username for a10
col redo_MB for 999G990 heading "Redo |Size MB"
column sid_serial for a13;
select b.inst_id,
lpad((b.SID || ',' || lpad(b.serial#,5)),11) sid_serial,
b.username,
machine,
b.osuser,
b.status,
a.redo_mb
from (select n.inst_id, sid,
round(value/1024/1024) redo_mb
from gv$statname n, gv$sesstat s
where n.inst_id=s.inst_id
and n.name = 'redo size'
and s.statistic# = n.statistic#
order by value desc
) a,
gv$session b
where b.inst_id=a.inst_id
and a.sid = b.sid
and rownum <= 30
;
PROMPT Top 30 from gv$sesstat view according generated redo logs
Result is something like:
SQL> @top_redo
Redo
INST_ID SID_SERIAL USERNAME MACHINE OSUSER STATUS Size MB
---------- ------------- ---------- --------------- ------------------------------ -------- --------
1 788, 1 iis1 oracle ACTIVE 2,073
4 788, 1 iis4 oracle ACTIVE 1,928
1 792, 1 iis1 oracle ACTIVE 1,168
Top 30 from gv$sesstat view according generated redo logs
SQL>
If you want to concentrate on real oracle users (avoid core Oracle processes in result) place next condition in outer where clause:
and b.username is not null
When and how many redo logs generation occurred?
Beside current analyze in many times wider analyze/compare is even more interesting. So questions like:
When do we have most of redo log generation?
Where was the peak of log generation?
Did we have any "strange" redo log generation?
need a little different approach-query v$log_history view. It holds historic data which retention period is initially controlled with MAXLOGHISTORY, defined while creating database (fixed not changeable without recreation of control file) and CONTROL_FILE_RECORD_KEEP_TIME which is changeable. In mine case it was set to 31 days (exact number of days for longest month):
SQL> show parameter CONTROL_FILE_RECORD_KEEP_TIME
NAME_COL_PLUS_SHOW_PARAM TYPE VALUE_COL_PLUS_SHOW_PARAM
------------------------------ ----------- ---------------------------------------------
control_file_record_keep_time integer 31
Script to gather data through mentioned period looks like.
/* -----------------------------------------------------------------------------
Filename: rl.sql
CR/TR# :
Purpose : redo logs distribution per hours on each day ...
Date : 07.08.2007.
Author : Damir Vadas, damir.vadas@hypo-alpe-adria.com
Remarks : run as privileged user
Changes (DD.MM.YYYY, Name, CR/TR#):
--------------------------------------------------------------------------- */
set pagesize 120;
set linesize 200;
col day for a8;
spool rl.txt
PROMPT Archive log distribution per hours on each day ...
select
to_char(first_time,'YY-MM-DD') day,
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'00',1,0)),'999') "00",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'01',1,0)),'999') "01",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'02',1,0)),'999') "02",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'03',1,0)),'999') "03",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'04',1,0)),'999') "04",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'05',1,0)),'999') "05",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'06',1,0)),'999') "06",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'07',1,0)),'999') "07",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'08',1,0)),'999') "08",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'09',1,0)),'999') "09",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'10',1,0)),'999') "10",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'11',1,0)),'999') "11",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'12',1,0)),'999') "12",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'13',1,0)),'999') "13",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'14',1,0)),'999') "14",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'15',1,0)),'999') "15",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'16',1,0)),'999') "16",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'17',1,0)),'999') "17",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'18',1,0)),'999') "18",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'19',1,0)),'999') "19",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'20',1,0)),'999') "20",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'21',1,0)),'999') "21",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'22',1,0)),'999') "22",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'23',1,0)),'999') "23",
COUNT(*) TOT
from v$log_history
group by to_char(first_time,'YY-MM-DD')
order by day
;
Result looks like:
SQL>@rl
Archive log distribution per hours on each day ...
DAY 00 01 02 03 04 05 06 07 08 09 10 11 12 13 14 15 16 17 18 19 20 21 22 23 TOT
-------- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- -----
11-01-14 0 0 23 16 17 16 16 16 22 39 23 18 22 18 18 18 22 18 19 16 19 16 16 17 425
11-01-15 24 23 17 18 21 16 16 16 22 18 20 19 19 18 18 21 20 18 20 16 18 16 16 17 447
11-01-16 40 39 43 24 17 16 16 16 22 18 18 21 21 18 19 19 22 18 19 17 18 16 16 16 509
SQL>
Redo logs generation is grouped by hours where last column (TOT) is sum of all redo logs in one day. According this it is more then obvious where redo log generation was highest, so our interest may be focused on presented point in time.
How much is that in Mb?
Total redo logs size (and according that, archived log size) cannot be computed from previous query because not all redo log switches occur when redo log was full. For that you might want to use this very easy query:
SQL> select sum(value)/1048576 redo_MB from sys.gv_$sysstat where name = 'redo size';
REDO_MB
----------
1074623.75
SQL>
If you want to calculate on instance grouping, then use this:
SQL> select inst_id, sum(value)/1048576 redo_MB from sys.gv_$sysstat where name = 'redo size'
2 group by inst_id;
INST_ID REDO_MB
---------- ----------
1 370325.298
2 4712.567
4 405129.283
3 294457.100
SQL>
Both queries works on single instances as well.
Which segments are generating redo logs?
After we found out our point of interest, in mine case where were most of the redo logs generation, it is very useful to find out which segments (not tables only) are causing redo log generation. For that we need to use "dba_hist" based tables, part of "Oracle AWR (Automated Workload Repository)", which usage I have described in topic Automated AWR reports in Oracle 10g/11g. For this example I'll focus on data based on time period: 11-01-28 13:00-11-01-28 14:00. Query for such a task should be:
SELECT to_char(begin_interval_time,'YY-MM-DD HH24') snap_time,
dhso.object_name,
sum(db_block_changes_delta) BLOCK_CHANGED
FROM dba_hist_seg_stat dhss,
dba_hist_seg_stat_obj dhso,
dba_hist_snapshot dhs
WHERE dhs.snap_id = dhss.snap_id
AND dhs.instance_number = dhss.instance_number
AND dhss.obj# = dhso.obj#
AND dhss.dataobj# = dhso.dataobj#
AND begin_interval_time BETWEEN to_date('11-01-28 13:00','YY-MM-DD HH24:MI')
AND to_date('11-01-28 14:00','YY-MM-DD HH24:MI')
GROUP BY to_char(begin_interval_time,'YY-MM-DD HH24'),
dhso.object_name
HAVING sum(db_block_changes_delta) > 0
ORDER BY sum(db_block_changes_delta) desc ;
Reduced result from previously shown query would be:
SNAP_TIME OBJECT_NAME BLOCK_CHANGED
----------- ------------------------------ -------------
11-01-28 13 USR_RACUNI_MV 1410112
11-01-28 13 TROK_TAB_RESEAU_I 734592
11-01-28 13 TROK_VOIE_I 638496
11-01-28 13 TROK_DATUM_ULAZA_I 434688
11-01-28 13 TROK_PAIEMENT_I 428544
11-01-28 13 D_DPX_VP_RAD 351760
11-01-28 13 TROK_SVE_OK_I 161472
11-01-28 13 I_DATPBZ_S002 135296
11-01-28 13 IDS2_DATUM_I 129904
11-01-28 13 IDS2_PZNBR 129632
11-01-28 13 IDS2_IDS1_FK_I 128848
11-01-28 13 IDS2_DATTRAN_I 127440
11-01-28 13 IDS2_DATSOC_I 127152
11-01-28 13 IDS2_VRSTA_PROD_I 122816
...
Let us focus on first segment "USR_RACUNI_MV", segment with highest number of changed blocks (what mean directly highest redo log generation). Just for information, this is MATERIALIZED VIEW.
What SQL was causing redo log generation
Now when we know when, how much and what, time is to find out how redo logs are generated. In next query "USR_RACUNI_MV" and mentioned period are hard codded, because we are focused on them. Just to point that SQL that start with "SELECT" are not point of our interest because they do not make any changes.
SELECT to_char(begin_interval_time,'YYYY_MM_DD HH24') WHEN,
dbms_lob.substr(sql_text,4000,1) SQL,
dhss.instance_number INST_ID,
dhss.sql_id,
executions_delta exec_delta,
rows_processed_delta rows_proc_delta
FROM dba_hist_sqlstat dhss,
dba_hist_snapshot dhs,
dba_hist_sqltext dhst
WHERE upper(dhst.sql_text) LIKE '%USR_RACUNI_MV%'
AND ltrim(upper(dhst.sql_text)) NOT LIKE 'SELECT%'
AND dhss.snap_id=dhs.snap_id
AND dhss.instance_number=dhs.instance_number
AND dhss.sql_id=dhst.sql_id
AND begin_interval_time BETWEEN to_date('11-01-28 13:00','YY-MM-DD HH24:MI')
AND to_date('11-01-28 14:00','YY-MM-DD HH24:MI')
;
Result is like:
WHEN SQL inst_id sql_id exec_delta rows_proc_delta
------------- ------------------------------------------------- ------- ------------- ---------- ---------------
2011_01_28 13 DECLARE 1 duwxbg5d1dw0q 0 0
job BINARY_INTEGER := :job;
next_date DATE := :mydate;
broken BOOLEAN := FALSE;
BEGIN
dbms_refresh.refresh('"TAB"."USR_RACUNI_MV"');
:mydate := next_date;
IF broken THEN :b := 1;
ELSE :b := 0;
END IF;
END;
2011_01_28 13 delete from "TAB"."USR_RACUNI_MV" 1 5n375fxu0uv89 0 0
For both of examples it was impossible to find out number of rows changed according operation that was performed. Let us see output of another example (NC_TRANSACTION_OK_T table) where we can meet with DDL that generate redo logs!
WHEN SQL inst_id sql_id exec_delta rows_proc_delta
------------- ------------------------------------------------- ------- ------------- ---------- ---------------
2011_01_28 13 alter table TAB.NC_TRANSACTION_OK_T 4 g5gvacc8ngnb8 0 0
shrink space cascade
If you are focused on pure number of changes, then you might to perform query where inst_id and sql_id are irrelevant (excluded from query). Here is a little modified previous example, for "Z_PLACENO" segment (pure oracle table):
SELECT when, sql, SUM(sx) executions, sum (sd) rows_processed
FROM (
SELECT to_char(begin_interval_time,'YYYY_MM_DD HH24') when,
dbms_lob.substr(sql_text,4000,1) sql,
dhss.instance_number inst_id,
dhss.sql_id,
sum(executions_delta) exec_delta,
sum(rows_processed_delta) rows_proc_delta
FROM dba_hist_sqlstat dhss,
dba_hist_snapshot dhs,
dba_hist_sqltext dhst
WHERE upper(dhst.sql_text) LIKE '%Z_PLACENO%'
AND ltrim(upper(dhst.sql_text)) NOT LIKE 'SELECT%'
AND dhss.snap_id=dhs.snap_id
AND dhss.instance_Number=dhs.instance_number
AND dhss.sql_id = dhst.sql_id
AND begin_interval_time BETWEEN to_date('11-01-25 14:00','YY-MM-DD HH24:MI')
AND to_date('11-01-25 15:00','YY-MM-DD HH24:MI')
GROUP BY to_char(begin_interval_time,'YYYY_MM_DD HH24'),
dbms_lob.substr(sql_text,4000,1),
dhss.instance_number,
dhss.sql_id
)
group by when, sql;
Result is like:
WHEN SQL exec_delta rows_proc_delta
------------- ---------------------------------------------------------------------- ---------- ---------------
2011_01_25 14 DELETE FROM Z_PLACENO 4 7250031
2011_01_25 14 INSERT INTO Z_PLACENO(OBP_ID,MT_SIFRA,A_TOT) 4 7250830
SELECT P.OBP_ID,P.MT_SIFRA,SUM(P.OSNOVICA)
FROM (SELECT OPI.OBP_ID,
OPO.MT_SIFRA,
SUM(OPO.IZNKN) OSNOVICA
WHERE OPI.OBP_ID = OPO.OPI_OBP_ID
AND OPI.RBR = OPO.OPI_RBR
AND NVL(OPI.S_PRETPOREZA,'O') IN ( 'O','N','A','Z','S')
GROUP BY OPI.OBP_ID,OPO.MT_SIFRA
)
Here you can see directly number executions and number of involved rows.
Query based on segment directly
Sometimes you do not want to focus on period, so your investigation may start with segment as starting point. For such a tasks I use next query. This is small variation of previous example where "USR_RACUNI_MV" segment is hard codded.
SELECT to_char(begin_interval_time,'YY-MM-DD HH24') snap_time,
sum(db_block_changes_delta)
FROM dba_hist_seg_stat dhss,
dba_hist_seg_stat_obj dhso,
dba_hist_snapshot dhs
WHERE dhs.snap_id = dhss.snap_id
AND dhs.instance_number = dhss.instance_number
AND dhss.obj# = dhso.obj#
AND dhss.dataobj# = dhso.dataobj#
AND dhso.object_name = 'USR_RACUNI_MV'
GROUP BY to_char(begin_interval_time,'YY-MM-DD HH24')
ORDER BY to_char(begin_interval_time,'YY-MM-DD HH24');
Reduced result is:
SNAP_TIME SUM(DB_BLOCK_CHANGES_DELTA)
----------- ---------------------------
...
11-01-28 11 1224240
11-01-28 12 702880
11-01-28 13 1410112
11-01-28 14 806416
11-01-28 15 2008912
11-01-28 16 1103648
...
select b.recid,to_char(b.first_time,'DD/MM/YY HH24:MI:SS') start_time,a.recid,
to_char(a.first_time,'DD/MM/YY HH24:MI:SS') end_time,
round(((a.first_time-b.first_time)*25)*60,2) minutes from v$log_history a,v$log_history b where a.recid=b.recid+1 order by
a.first_time asc;
Who is generating redo logs now?
One of the first question, which cover firefighter is: "Who is generating redo logs in this moment". Idea is to determine action on ad hoc basis. For that I use following script, which I call top_redo.sql:
view sourceprint?
/* -----------------------------------------------------------------------------
Filename: top_redo.sql
CR/TR# :
Purpose : Shows current redo logs generation info (RAC-non RAC environment)
Date : 12.08.2008.
Author : Damir Vadas, damir.vadas@gmail.com
Remarks : run as privileged user
Changes (DD.MM.YYYY, Name, CR/TR#):
--------------------------------------------------------------------------- */
col machine for a15
col username for a10
col redo_MB for 999G990 heading "Redo |Size MB"
column sid_serial for a13;
select b.inst_id,
lpad((b.SID || ',' || lpad(b.serial#,5)),11) sid_serial,
b.username,
machine,
b.osuser,
b.status,
a.redo_mb
from (select n.inst_id, sid,
round(value/1024/1024) redo_mb
from gv$statname n, gv$sesstat s
where n.inst_id=s.inst_id
and n.name = 'redo size'
and s.statistic# = n.statistic#
order by value desc
) a,
gv$session b
where b.inst_id=a.inst_id
and a.sid = b.sid
and rownum <= 30
;
PROMPT Top 30 from gv$sesstat view according generated redo logs
Result is something like:
SQL> @top_redo
Redo
INST_ID SID_SERIAL USERNAME MACHINE OSUSER STATUS Size MB
---------- ------------- ---------- --------------- ------------------------------ -------- --------
1 788, 1 iis1 oracle ACTIVE 2,073
4 788, 1 iis4 oracle ACTIVE 1,928
1 792, 1 iis1 oracle ACTIVE 1,168
Top 30 from gv$sesstat view according generated redo logs
SQL>
If you want to concentrate on real oracle users (avoid core Oracle processes in result) place next condition in outer where clause:
and b.username is not null
When and how many redo logs generation occurred?
Beside current analyze in many times wider analyze/compare is even more interesting. So questions like:
When do we have most of redo log generation?
Where was the peak of log generation?
Did we have any "strange" redo log generation?
need a little different approach-query v$log_history view. It holds historic data which retention period is initially controlled with MAXLOGHISTORY, defined while creating database (fixed not changeable without recreation of control file) and CONTROL_FILE_RECORD_KEEP_TIME which is changeable. In mine case it was set to 31 days (exact number of days for longest month):
SQL> show parameter CONTROL_FILE_RECORD_KEEP_TIME
NAME_COL_PLUS_SHOW_PARAM TYPE VALUE_COL_PLUS_SHOW_PARAM
------------------------------ ----------- ---------------------------------------------
control_file_record_keep_time integer 31
Script to gather data through mentioned period looks like.
/* -----------------------------------------------------------------------------
Filename: rl.sql
CR/TR# :
Purpose : redo logs distribution per hours on each day ...
Date : 07.08.2007.
Author : Damir Vadas, damir.vadas@hypo-alpe-adria.com
Remarks : run as privileged user
Changes (DD.MM.YYYY, Name, CR/TR#):
--------------------------------------------------------------------------- */
set pagesize 120;
set linesize 200;
col day for a8;
spool rl.txt
PROMPT Archive log distribution per hours on each day ...
select
to_char(first_time,'YY-MM-DD') day,
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'00',1,0)),'999') "00",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'01',1,0)),'999') "01",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'02',1,0)),'999') "02",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'03',1,0)),'999') "03",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'04',1,0)),'999') "04",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'05',1,0)),'999') "05",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'06',1,0)),'999') "06",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'07',1,0)),'999') "07",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'08',1,0)),'999') "08",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'09',1,0)),'999') "09",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'10',1,0)),'999') "10",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'11',1,0)),'999') "11",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'12',1,0)),'999') "12",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'13',1,0)),'999') "13",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'14',1,0)),'999') "14",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'15',1,0)),'999') "15",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'16',1,0)),'999') "16",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'17',1,0)),'999') "17",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'18',1,0)),'999') "18",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'19',1,0)),'999') "19",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'20',1,0)),'999') "20",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'21',1,0)),'999') "21",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'22',1,0)),'999') "22",
to_char(sum(decode(substr(to_char(first_time,'HH24'),1,2),'23',1,0)),'999') "23",
COUNT(*) TOT
from v$log_history
group by to_char(first_time,'YY-MM-DD')
order by day
;
Result looks like:
SQL>@rl
Archive log distribution per hours on each day ...
DAY 00 01 02 03 04 05 06 07 08 09 10 11 12 13 14 15 16 17 18 19 20 21 22 23 TOT
-------- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- ---- -----
11-01-14 0 0 23 16 17 16 16 16 22 39 23 18 22 18 18 18 22 18 19 16 19 16 16 17 425
11-01-15 24 23 17 18 21 16 16 16 22 18 20 19 19 18 18 21 20 18 20 16 18 16 16 17 447
11-01-16 40 39 43 24 17 16 16 16 22 18 18 21 21 18 19 19 22 18 19 17 18 16 16 16 509
SQL>
Redo logs generation is grouped by hours where last column (TOT) is sum of all redo logs in one day. According this it is more then obvious where redo log generation was highest, so our interest may be focused on presented point in time.
How much is that in Mb?
Total redo logs size (and according that, archived log size) cannot be computed from previous query because not all redo log switches occur when redo log was full. For that you might want to use this very easy query:
SQL> select sum(value)/1048576 redo_MB from sys.gv_$sysstat where name = 'redo size';
REDO_MB
----------
1074623.75
SQL>
If you want to calculate on instance grouping, then use this:
SQL> select inst_id, sum(value)/1048576 redo_MB from sys.gv_$sysstat where name = 'redo size'
2 group by inst_id;
INST_ID REDO_MB
---------- ----------
1 370325.298
2 4712.567
4 405129.283
3 294457.100
SQL>
Both queries works on single instances as well.
Which segments are generating redo logs?
After we found out our point of interest, in mine case where were most of the redo logs generation, it is very useful to find out which segments (not tables only) are causing redo log generation. For that we need to use "dba_hist" based tables, part of "Oracle AWR (Automated Workload Repository)", which usage I have described in topic Automated AWR reports in Oracle 10g/11g. For this example I'll focus on data based on time period: 11-01-28 13:00-11-01-28 14:00. Query for such a task should be:
SELECT to_char(begin_interval_time,'YY-MM-DD HH24') snap_time,
dhso.object_name,
sum(db_block_changes_delta) BLOCK_CHANGED
FROM dba_hist_seg_stat dhss,
dba_hist_seg_stat_obj dhso,
dba_hist_snapshot dhs
WHERE dhs.snap_id = dhss.snap_id
AND dhs.instance_number = dhss.instance_number
AND dhss.obj# = dhso.obj#
AND dhss.dataobj# = dhso.dataobj#
AND begin_interval_time BETWEEN to_date('11-01-28 13:00','YY-MM-DD HH24:MI')
AND to_date('11-01-28 14:00','YY-MM-DD HH24:MI')
GROUP BY to_char(begin_interval_time,'YY-MM-DD HH24'),
dhso.object_name
HAVING sum(db_block_changes_delta) > 0
ORDER BY sum(db_block_changes_delta) desc ;
Reduced result from previously shown query would be:
SNAP_TIME OBJECT_NAME BLOCK_CHANGED
----------- ------------------------------ -------------
11-01-28 13 USR_RACUNI_MV 1410112
11-01-28 13 TROK_TAB_RESEAU_I 734592
11-01-28 13 TROK_VOIE_I 638496
11-01-28 13 TROK_DATUM_ULAZA_I 434688
11-01-28 13 TROK_PAIEMENT_I 428544
11-01-28 13 D_DPX_VP_RAD 351760
11-01-28 13 TROK_SVE_OK_I 161472
11-01-28 13 I_DATPBZ_S002 135296
11-01-28 13 IDS2_DATUM_I 129904
11-01-28 13 IDS2_PZNBR 129632
11-01-28 13 IDS2_IDS1_FK_I 128848
11-01-28 13 IDS2_DATTRAN_I 127440
11-01-28 13 IDS2_DATSOC_I 127152
11-01-28 13 IDS2_VRSTA_PROD_I 122816
...
Let us focus on first segment "USR_RACUNI_MV", segment with highest number of changed blocks (what mean directly highest redo log generation). Just for information, this is MATERIALIZED VIEW.
What SQL was causing redo log generation
Now when we know when, how much and what, time is to find out how redo logs are generated. In next query "USR_RACUNI_MV" and mentioned period are hard codded, because we are focused on them. Just to point that SQL that start with "SELECT" are not point of our interest because they do not make any changes.
SELECT to_char(begin_interval_time,'YYYY_MM_DD HH24') WHEN,
dbms_lob.substr(sql_text,4000,1) SQL,
dhss.instance_number INST_ID,
dhss.sql_id,
executions_delta exec_delta,
rows_processed_delta rows_proc_delta
FROM dba_hist_sqlstat dhss,
dba_hist_snapshot dhs,
dba_hist_sqltext dhst
WHERE upper(dhst.sql_text) LIKE '%USR_RACUNI_MV%'
AND ltrim(upper(dhst.sql_text)) NOT LIKE 'SELECT%'
AND dhss.snap_id=dhs.snap_id
AND dhss.instance_number=dhs.instance_number
AND dhss.sql_id=dhst.sql_id
AND begin_interval_time BETWEEN to_date('11-01-28 13:00','YY-MM-DD HH24:MI')
AND to_date('11-01-28 14:00','YY-MM-DD HH24:MI')
;
Result is like:
WHEN SQL inst_id sql_id exec_delta rows_proc_delta
------------- ------------------------------------------------- ------- ------------- ---------- ---------------
2011_01_28 13 DECLARE 1 duwxbg5d1dw0q 0 0
job BINARY_INTEGER := :job;
next_date DATE := :mydate;
broken BOOLEAN := FALSE;
BEGIN
dbms_refresh.refresh('"TAB"."USR_RACUNI_MV"');
:mydate := next_date;
IF broken THEN :b := 1;
ELSE :b := 0;
END IF;
END;
2011_01_28 13 delete from "TAB"."USR_RACUNI_MV" 1 5n375fxu0uv89 0 0
For both of examples it was impossible to find out number of rows changed according operation that was performed. Let us see output of another example (NC_TRANSACTION_OK_T table) where we can meet with DDL that generate redo logs!
WHEN SQL inst_id sql_id exec_delta rows_proc_delta
------------- ------------------------------------------------- ------- ------------- ---------- ---------------
2011_01_28 13 alter table TAB.NC_TRANSACTION_OK_T 4 g5gvacc8ngnb8 0 0
shrink space cascade
If you are focused on pure number of changes, then you might to perform query where inst_id and sql_id are irrelevant (excluded from query). Here is a little modified previous example, for "Z_PLACENO" segment (pure oracle table):
SELECT when, sql, SUM(sx) executions, sum (sd) rows_processed
FROM (
SELECT to_char(begin_interval_time,'YYYY_MM_DD HH24') when,
dbms_lob.substr(sql_text,4000,1) sql,
dhss.instance_number inst_id,
dhss.sql_id,
sum(executions_delta) exec_delta,
sum(rows_processed_delta) rows_proc_delta
FROM dba_hist_sqlstat dhss,
dba_hist_snapshot dhs,
dba_hist_sqltext dhst
WHERE upper(dhst.sql_text) LIKE '%Z_PLACENO%'
AND ltrim(upper(dhst.sql_text)) NOT LIKE 'SELECT%'
AND dhss.snap_id=dhs.snap_id
AND dhss.instance_Number=dhs.instance_number
AND dhss.sql_id = dhst.sql_id
AND begin_interval_time BETWEEN to_date('11-01-25 14:00','YY-MM-DD HH24:MI')
AND to_date('11-01-25 15:00','YY-MM-DD HH24:MI')
GROUP BY to_char(begin_interval_time,'YYYY_MM_DD HH24'),
dbms_lob.substr(sql_text,4000,1),
dhss.instance_number,
dhss.sql_id
)
group by when, sql;
Result is like:
WHEN SQL exec_delta rows_proc_delta
------------- ---------------------------------------------------------------------- ---------- ---------------
2011_01_25 14 DELETE FROM Z_PLACENO 4 7250031
2011_01_25 14 INSERT INTO Z_PLACENO(OBP_ID,MT_SIFRA,A_TOT) 4 7250830
SELECT P.OBP_ID,P.MT_SIFRA,SUM(P.OSNOVICA)
FROM (SELECT OPI.OBP_ID,
OPO.MT_SIFRA,
SUM(OPO.IZNKN) OSNOVICA
WHERE OPI.OBP_ID = OPO.OPI_OBP_ID
AND OPI.RBR = OPO.OPI_RBR
AND NVL(OPI.S_PRETPOREZA,'O') IN ( 'O','N','A','Z','S')
GROUP BY OPI.OBP_ID,OPO.MT_SIFRA
)
Here you can see directly number executions and number of involved rows.
Query based on segment directly
Sometimes you do not want to focus on period, so your investigation may start with segment as starting point. For such a tasks I use next query. This is small variation of previous example where "USR_RACUNI_MV" segment is hard codded.
SELECT to_char(begin_interval_time,'YY-MM-DD HH24') snap_time,
sum(db_block_changes_delta)
FROM dba_hist_seg_stat dhss,
dba_hist_seg_stat_obj dhso,
dba_hist_snapshot dhs
WHERE dhs.snap_id = dhss.snap_id
AND dhs.instance_number = dhss.instance_number
AND dhss.obj# = dhso.obj#
AND dhss.dataobj# = dhso.dataobj#
AND dhso.object_name = 'USR_RACUNI_MV'
GROUP BY to_char(begin_interval_time,'YY-MM-DD HH24')
ORDER BY to_char(begin_interval_time,'YY-MM-DD HH24');
Reduced result is:
SNAP_TIME SUM(DB_BLOCK_CHANGES_DELTA)
----------- ---------------------------
...
11-01-28 11 1224240
11-01-28 12 702880
11-01-28 13 1410112
11-01-28 14 806416
11-01-28 15 2008912
11-01-28 16 1103648
...
No comments:
Post a Comment