Tuesday, 6 September 2016

Monitoring Multiple Oracle database tablespaces on multiple machines.

This post help you to monitor your multiple database's tablespaces on multiple servers by collecting information into a table from each database using a job and then use that table to report the tablespace status.


CREATE TABLE scripts.VERIFY_TABLESPACE
(
  TABLESPACE_NAME  VARCHAR2(30 BYTE),
  MEGS_ALLOC       NUMBER,
  MEGS_FREE        NUMBER,
  MEGS_USED        NUMBER,
  PCT_FREE         NUMBER,
  PCT_USED         NUMBER,
  MAX              NUMBER,
  USED_PCT_OF_MAX  NUMBER
)
TABLESPACE USERS
PCTUSED    0
PCTFREE    10
INITRANS   1
MAXTRANS   255
STORAGE    (
            INITIAL          64K
            MINEXTENTS       1
            MAXEXTENTS       UNLIMITED
            PCTINCREASE      0
            BUFFER_POOL      DEFAULT
           )
LOGGING
NOCOMPRESS
NOCACHE
NOPARALLEL
MONITORING
/

create or replace public synonym VERIFY_TABLESPACE for scripts.VERIFY_TABLESPACE
/
GRANT INSERT, SELECT ON scripts.VERIFY_TABLESPACE TO PUBLIC
/

CREATE PUBLIC DATABASE LINK monitor_db
CONNECT TO smbackup
IDENTIFIED BY smbackup
USING 'backuprep';
/

grant select any dictionary to scripts
/
create or replace force view scripts.v_verify_tablespace
as
select  a.tablespace_name,
       round(a.bytes_alloc / 1024 / 1024) megs_alloc,
       round(nvl(b.bytes_free, 0) / 1024 / 1024) megs_free,
       round((a.bytes_alloc - nvl(b.bytes_free, 0)) / 1024 / 1024) megs_used,
       round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_Free,
       100 - round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_used,
       round(maxbytes/1048576) Max,
       round(round((a.bytes_alloc - nvl(b.bytes_free, 0)) / 1024 / 1024) / round(maxbytes/1048576)*100) used_pct_of_max
from  ( select  f.tablespace_name,
               sum(f.bytes) bytes_alloc,
               sum(decode(f.autoextensible, 'YES',f.maxbytes,'NO', f.bytes)) maxbytes
        from dba_data_files f
        group by tablespace_name) a,
      ( select  f.tablespace_name,
               sum(f.bytes)  bytes_free
        from dba_free_space f
        group by tablespace_name) b
where a.tablespace_name = b.tablespace_name (+)
union all
select h.tablespace_name,
       round(sum(h.bytes_free + h.bytes_used) / 1048576) megs_alloc,
       round(sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) / 1048576) megs_free,
       round(sum(nvl(p.bytes_used, 0))/ 1048576) megs_used,
       round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) / sum(h.bytes_used + h.bytes_free)) * 100) Pct_Free,
       100 - round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) / sum(h.bytes_used + h.bytes_free)) * 100) pct_used,
       round(sum(f.maxbytes) / 1048576) max,
       round( round(sum(nvl(p.bytes_used, 0))/ 1048576)  / round(sum(f.maxbytes) / 1048576) *100) used_pct_of_max
from   sys.v_$TEMP_SPACE_HEADER h, sys.v_$Temp_extent_pool p, dba_temp_files f
where  p.file_id(+) = h.file_id
and    p.tablespace_name(+) = h.tablespace_name
and    f.file_id = h.file_id
and    f.tablespace_name = h.tablespace_name
group by h.tablespace_name
/

create or replace public synonym v_verify_tablespace for scripts.v_verify_tablespace
/


create or replace procedure scripts.p_log_tablespace
as
begin
insert into verify_tablespace(
TABLESPACE_NAME, MEGS_ALLOC, MEGS_FREE, MEGS_USED, PCT_FREE, PCT_USED, MAX, USED_PCT_OF_MAX
)
select
TABLESPACE_NAME, MEGS_ALLOC, MEGS_FREE, MEGS_USED, PCT_FREE, PCT_USED, MAX, USED_PCT_OF_MAX
from v_verify_tablespace;
delete from smbackup.verify_tablespace@monitor_db where client = 'ASPEN';
commit;
insert into smbackup.verify_tablespace@monitor_db(
CLIENT, TABLESPACE_NAME, MEGS_ALLOC, MEGS_FREE, MEGS_USED, PCT_FREE, PCT_USED, MAX, USED_PCT_OF_MAX
)
select
'ASPEN', TABLESPACE_NAME, MEGS_ALLOC, MEGS_FREE, MEGS_USED, PCT_FREE, PCT_USED, MAX, USED_PCT_OF_MAX
from verify_tablespace;
commit;
exception
when others then null;
end;
/
create or replace public synonym  p_log_tablespace for scripts.p_log_tablespace
/


DECLARE
  X NUMBER;
BEGIN
  SYS.DBMS_JOB.SUBMIT
  ( job       => X
   ,what      => 'scripts.p_log_tablespace;'
   ,next_date => to_date('19/07/2011 7:00:00','dd/mm/yyyy hh24:mi:ss')
   ,interval  => 'trunc(SYSDATE+1)+6/24'
   ,no_parse  => FALSE
  );
  SYS.DBMS_OUTPUT.PUT_LINE('Job Number is: ' || to_char(x));
COMMIT;
END;
/

Reporting_server Tns

BACKUPREP =
 (DESCRIPTION = 
   (ADDRESS_LIST =
     (ADDRESS = (PROTOCOL = TCP)(HOST = 10.11.20.23)(PORT = 1521))
   )
 (CONNECT_DATA =
   (SERVICE_NAME = ORA12)
 ) 
) 

 Step – 1:

add your reporting server tns entry on client machine in                        tnsnames.ora to create db link.
 Step – 2:

Replace client name in last procedure in attached script file 
 Step – 3:

Execute scripts in attached file one-by-one carefully on client                database. And also create database job at suitable time as in my                case is 6:45 AM 
 Step – 4:

Test result data on BACKUPREP {tns given above}



No comments:

Post a Comment