diff --git a/01-db-setup/create_audit_log_database.sql b/01-db-setup/create_audit_log_database.sql new file mode 100644 index 0000000..8bb0e1f --- /dev/null +++ b/01-db-setup/create_audit_log_database.sql @@ -0,0 +1,91 @@ +define SYSUSER_PWD='&1' +define AUDITLOG_TAB_LOC='&2' + +connect "SYS"/"&&SYSUSER_PWD" as SYSDBA +set echo on +spool $SCRIPTS/gpi_setup.log append + +--- Move Audit log tablespace + +CREATE SMALLFILE TABLESPACE "AUDITLOG" LOGGING DATAFILE '&&AUDITLOG_TAB_LOC' + SIZE 100M AUTOEXTEND ON NEXT 120M MAXSIZE 32000M EXTENT MANAGEMENT LOCAL SEGMENT SPACE MANAGEMENT AUTO +/ + +BEGIN +DBMS_AUDIT_MGMT.SET_AUDIT_TRAIL_LOCATION( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_DB_STD, + audit_trail_location_value => 'AUDITLOG'); +END; +/ + +--- recompile invalid objects -------------- + +@?/rdbms/admin/utlrp.sql + +-- Auditlog init --------------------------- + +-- see https://www.pipperr.de/dokuwiki/doku.php?id=dba:oracle_clean_audit_log_entries + +BEGIN + DBMS_AUDIT_MGMT.INIT_CLEANUP( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_ALL, + default_cleanup_interval => 24 /* hours */); +END; +/ + +-- Delete all after 180 Days + +BEGIN +-- Standard database audit records in the SYS.AUD$ table + DBMS_AUDIT_MGMT.set_last_archive_timestamp( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_AUD_STD + , last_archive_time => SYSTIMESTAMP-180); + +-- Unified audit trail. In unified auditing, all audit records are written to the unified audit trail and are made -- available through the unified audit trail views, such as UNIFIED_AUDIT_TRAIL. + DBMS_AUDIT_MGMT.set_last_archive_timestamp( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED + , last_archive_time => SYSTIMESTAMP-180); + +-- Operating system audit trail. This refers to the audit records stored in operating system files. + DBMS_AUDIT_MGMT.set_last_archive_timestamp( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_OS + , last_archive_time => SYSTIMESTAMP-180); + +END; +/ + +-- create the job to move the timeframe each day +BEGIN + + DBMS_SCHEDULER.CREATE_JOB ( + job_name => 'AUDIT_ARCHIVE_BEFORE_TIMESTAMP', + job_type => 'PLSQL_BLOCK', + job_action => 'begin + DBMS_AUDIT_MGMT.set_last_archive_timestamp( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_AUD_STD + , last_archive_time => SYSTIMESTAMP-180); + DBMS_AUDIT_MGMT.set_last_archive_timestamp( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED + , last_archive_time => SYSTIMESTAMP-180); + DBMS_AUDIT_MGMT.set_last_archive_timestamp( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_OS + , last_archive_time => SYSTIMESTAMP-180); + end;', + start_date => sysdate, + repeat_interval => 'FREQ=HOURLY;INTERVAL=24', + enabled => TRUE, + comments => 'Set the point in time before delete all audit log entries' + ); +END; +/ + + +-- Create Auditlog purge Job ------------------ +BEGIN + DBMS_AUDIT_MGMT.create_purge_job( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_ALL, + audit_trail_purge_interval => 24 /* hours */, + audit_trail_purge_name => 'PURGE_ALL_AUDIT_TRAILS', + use_last_arch_timestamp => TRUE); +END; +/ diff --git a/01-db-setup/create_awr_user_role.sql b/01-db-setup/create_awr_user_role.sql new file mode 100644 index 0000000..5139483 --- /dev/null +++ b/01-db-setup/create_awr_user_role.sql @@ -0,0 +1,16 @@ +--============================================================================== +-- create the role for the usage of the AWR repository for none DBA user +-- run as sys +--============================================================================== +set echo on + +create role call_awr_reports; + +grant select on sys.v_$database to call_awr_reports; +grant select on sys.v_$instance to call_awr_reports; +grant execute on sys.dbms_workload_repository to call_awr_reports; +grant select on sys.dba_hist_database_instance to call_awr_reports; +grant select on sys.dba_hist_snapshot to call_awr_reports; + +set echo off + diff --git a/01-db-setup/create_global_errorlog.sql b/01-db-setup/create_global_errorlog.sql new file mode 100644 index 0000000..5b87be3 --- /dev/null +++ b/01-db-setup/create_global_errorlog.sql @@ -0,0 +1,235 @@ +set serveroutput on size 1000000 + +prompt + +DOC +------------------------------------------------------------------------------- + + Creating Error Log Tab for SQL Errors over the complete DB + +------------------------------------------------------------------------------- +# + +prompt + + +DOC +------------------------------------------------------------------------------- + + Errorlog Table / Sequence and Trigger will be created + +------------------------------------------------------------------------------- +# + +prompt +prompt '-------------------------------------------------------------------------------' +prompt + +set serveroutput on size 1000000 + +exec DBMS_OUTPUT.put_line('start create_global_errorlog.sql'); + +prompt "Create Table SYSTEM.ora_errors and SEQUENCE SYSTEM.ora_errors_seq" + +CREATE TABLE SYSTEM.ora_errors +( + id NUMBER + ,log_date DATE + ,log_usr VARCHAR2 (30) + ,terminal VARCHAR2 (50) + ,err_nr NUMBER (10) + ,err_msg VARCHAR2 (4000) + ,stmt CLOB + ,inst_id number(2) +) tablespace sysaux +/ + +create unique index system.idx_ora_errors_pk on system.ora_errors(id) tablespace sysaux; +alter table system.ora_errors add constraint pk_ora_errpr primary key (id) enable validate; + +create index system.idx_ora_errors_date on system.ora_errors(log_date) tablespace sysaux; + +grant select on system.ora_errors to public; +grant delete on system.ora_errors to public; + + +----------- + +CREATE SEQUENCE SYSTEM.ora_errors_seq +/ + +----------- + +prompt "Create the trigger log_error" + +CREATE OR REPLACE TRIGGER log_error + AFTER SERVERERROR + ON DATABASE +DECLARE + PRAGMA AUTONOMOUS_TRANSACTION; + + v_id NUMBER; + v_sql_text ORA_NAME_LIST_T; + v_stmt CLOB; + v_count NUMBER; +BEGIN + v_count := ora_sql_txt (v_sql_text); + + IF v_count >= 1 + THEN + FOR i IN 1 .. v_count + LOOP + v_stmt := v_stmt || v_sql_text (i); + END LOOP; + END IF; + + FOR n IN 1 .. ora_server_error_depth + LOOP + IF ora_login_user in ('SYS','DBSNMP','SYSMAN') + THEN + -- do nothing + NULL; + ELSE + SELECT SYSTEM.ora_errors_seq.NEXTVAL INTO v_id FROM DUAL; + + INSERT INTO SYSTEM.ora_errors (id + ,log_date + ,log_usr + ,terminal + ,err_nr + ,err_msg + ,stmt + ,inst_id) + VALUES (v_id + ,SYSDATE + ,ora_login_user + ,ora_client_ip_address + ,ora_server_error (n) + ,ora_server_error_msg (n) + ,v_stmt + ,ora_instance_num); + END IF; + + COMMIT; + END LOOP; +END log_error; +/ + +------ Clean procedure + +CREATE or REPLACE PROCEDURE system.deleteOraErrorTrigTab (p_keepdays NUMBER) +IS +BEGIN + DELETE FROM SYSTEM.ora_errors WHERE log_date+p_keepdays < sysdate; + COMMIT; +END; +/ +show errors + + +------ Clean procedure job over DBMS Job --- +/* +DECLARE + X NUMBER; +BEGIN + SYS.DBMS_JOB.SUBMIT + ( + job => X + ,what => 'begin system.deleteOraErrorTrigTab (p_keepdays => 15); end;' + ,next_date => sysdate + ,interval => 'to_date(to_char(sysdate+1,''mm/dd/yyyy'')||'' 04:00:00'',''mm/dd/yyyy hh24:mi:ss'')' + ,no_parse => FALSE + ,instance => 0 + ,force => TRUE + ); +END; +/ +commit; +*/ + +------ Clean procedure job over DBMS Scheduler --- + +------------------------------------------------------------------------- +-- Create Oracle Scheduler Program +BEGIN + DBMS_SCHEDULER.create_program ( + program_name => 'CLEAN_SQL_ERROR_LOG_TABLE_PROG' + , program_type => 'STORED_PROCEDURE' + , program_action => 'system.deleteOraErrorTrigTab' + , number_of_arguments => 1 + , enabled => FALSE + , comments => 'Prog to clean all from SYSTEM.ora_errors ( Error Log Table in the system schema) older then xx days'); +END; +/ + +BEGIN + DBMS_SCHEDULER.define_program_argument ( + program_name => 'CLEAN_SQL_ERROR_LOG_TABLE_PROG' + , argument_name => 'p_keepdays' + , argument_position => 1 + , argument_type => 'NUMBER' + , default_value => '15'); +END; +/ +BEGIN + DBMS_SCHEDULER.enable (name => 'CLEAN_SQL_ERROR_LOG_TABLE_PROG'); +END; +/ +------------------------------------------------------------------------- +-- Create Oracle Scheduler Time Plan +BEGIN + DBMS_SCHEDULER.create_schedule ( + schedule_name => 'CLEAN_SQL_ERLOGTAB_TIMEPLAN' + , start_date => SYSTIMESTAMP + , repeat_interval => 'freq=daily; byhour=13; byminute=0' + , end_date => NULL + , comments => 'Job time plan to delete the SYSTEM.ora_errors ( Error Log Table in the system schema)'); +END; +/ +------------------------------------------------------------------------- +-- Create Scheduler Job +BEGIN + DBMS_SCHEDULER.create_job ( + job_name => 'CLEAN_SQL_ERROR_LOG_TABLE' + , program_name => 'CLEAN_SQL_ERROR_LOG_TABLE_PROG' + , schedule_name => 'CLEAN_SQL_ERLOGTAB_TIMEPLAN' + , comments => 'Job to clean all from SYSTEM.ora_errors ( Error Log Table in the system schema) older then xx days' + , enabled => true); +END; +/ + +-- +column job_name FORMAT a40 +select owner, job_name, enabled + from dba_scheduler_jobs + where job_name ='CLEAN_SQL_ERROR_LOG_TABLE' +/ + + +------ Analyse example: + +column anzahl format 9999999999 +column hour format A9 +column LOG_USR format A10 +column ERR_NR format 999999999 +column mesg format A30 + +SELECT COUNT (*) as anzahl + ,TO_CHAR (log_date, 'dd/mm hh24')||'h' as hour + ,nvl(LOG_USR,'n/a') as LOG_USR + ,ERR_NR + ,substr(ERR_MSG,1,200) mesg + FROM SYSTEM.ora_errors + where nvl(log_usr,'n/a') not in ('SYS','SYSMAN','DBSNMP') +GROUP BY TO_CHAR (log_date, 'dd/mm hh24')||'h' + ,nvl(LOG_USR,'n/a') + ,ERR_NR + ,substr(ERR_MSG,1,200) +order by 2,1 +; +------------------------------------------------------ + +prompt +exec DBMS_OUTPUT.put_line('end create_global_errorlog.sql'); +prompt + diff --git a/01-db-setup/delete_global_errorlog.sql b/01-db-setup/delete_global_errorlog.sql new file mode 100644 index 0000000..fbf9e8d --- /dev/null +++ b/01-db-setup/delete_global_errorlog.sql @@ -0,0 +1,104 @@ +prompt + +DOC +------------------------------------------------------------------------------- + + Remove Error Log for SQL Errors over the complete DB + +------------------------------------------------------------------------------- +# + +prompt +set echo on +set serveroutput on + +prompt "Info -- delete trigger" +drop TRIGGER log_error; + + +prompt "Info -- delete Delete Job" +declare + + v_job_id dba_jobs.job%type; + v_count pls_integer := 0; + + -- search the DBMS_JOB + cursor c_del_job is + select job + ,what + from dba_jobs + where upper(WHAT) like upper('%system.deleteOraErrorTrigTab%'); + + -- search the DBMS_SCHEDULER + cursor c_del_sheduler_job is + select job_name from dba_scheduler_jobs where job_name = 'CLEAN_SQL_ERROR_LOG_TABLE'; + + cursor c_del_sheduler_plan is + select schedule_name from dba_scheduler_schedules where schedule_name = 'CLEAN_SQL_ERLOGTAB_TIMEPLAN'; + + cursor c_del_sheduler_prog is + select program_name from dba_scheduler_programs where program_name = 'CLEAN_SQL_ERROR_LOG_TABLE_PROG'; + +begin + dbms_output.put_line('Info -- start remove the error table delete job'); + for rec in c_del_job + loop + dbms_output.put_line('Info -- remove JOB ::' || rec.what || ' with the id::' || to_char(rec.job)); + dbms_job.remove(rec.job); + commit; + v_count := v_count + 1; + end loop; + dbms_output.put_line('Info -- remove ' || to_char(v_count) || ' Jobs -- finish'); + v_count := 0; + ---------------- Scheduler ------------------------------------------------- + -- delete job + dbms_output.put_line('Info -- start remove the error table Scheduler Time Plan'); + for rec in c_del_sheduler_job + loop + dbms_output.put_line('Info -- remove Scheduler Time Plan ::' || rec.job_name); + DBMS_SCHEDULER.drop_job(job_name => rec.job_name); + commit; + v_count := v_count + 1; + end loop; + dbms_output.put_line('Info -- remove ' || to_char(v_count) || ' Scheduler Time Plan -- finish'); + v_count := 0; + -- + -- delete time plan + dbms_output.put_line('Info -- start remove the error table Scheduler Time Plan'); + for rec in c_del_sheduler_plan + loop + dbms_output.put_line('Info -- remove Scheduler Time Plan ::' || rec.schedule_name); + DBMS_SCHEDULER.drop_schedule(schedule_name => rec.schedule_name); + commit; + v_count := v_count + 1; + end loop; + dbms_output.put_line('Info -- remove ' || to_char(v_count) || ' Scheduler Time Plan -- finish'); + v_count := 0; + -- + --delete prog + dbms_output.put_line('Info -- start remove the error table Scheduler delete job'); + for rec in c_del_sheduler_prog + loop + dbms_output.put_line('Info -- remove Scheduler Programm ::' || rec.program_name); + DBMS_SCHEDULER.drop_program(program_name => rec.program_name); + commit; + v_count := v_count + 1; + end loop; + dbms_output.put_line('Info -- remove ' || to_char(v_count) || ' Scheduler Jobs -- finish'); + -- +end; +/ + + +prompt "Info -- delete Error Table" +drop table SYSTEM.ora_errors purge; + +prompt "Info -- delete Error Sequence" +drop SEQUENCE SYSTEM.ora_errors_seq; + +prompt "Info -- delete Error Sequence" +drop PROCEDURE system.deleteOraErrorTrigTab; + + + + \ No newline at end of file diff --git a/01-db-setup/monitor_user_sessions.sql b/01-db-setup/monitor_user_sessions.sql new file mode 100644 index 0000000..9f08031 --- /dev/null +++ b/01-db-setup/monitor_user_sessions.sql @@ -0,0 +1,183 @@ +-- create a log table to capture all connection to the database over v$session +-- benfit, capture also none active sessions +-- +-- Grant as SYS User grant select on sys.v_$session to like system +-- + + +spool create_log_session_table.log + + create table log_user_sessions ( + id number(10) not null + , username varchar(32) + , osuser varchar(48) + , machine varchar(64) + , program varchar2(64) + , action varchar(32) + , terminal varchar(64) + , logon_time date + , service_name varchar(64) + , module varchar(48) + , count_connects number(5) + , active_connects number(5) + , snaptime date not null + ) + tablespace SYSAUX + / + +-- add pk + +create unique index log_user_sessions_pk1 on log_user_sessions (id) logging tablespace SYSAUX; +alter table log_user_sessions add ( constraint log_user_sessions_pk1 primary key (id) using index tablespace SYSAUX ); + +-- + +comment on table log_user_sessions is 'Log the connected user to the database for connection statistic'; +comment on column log_user_sessions.module is 'Name of the currently executing module as set by the DBMS_APPLICATION_INFO.SET_MODULE procedure'; +comment on column log_user_sessions.username is 'Oracle User name'; +comment on column log_user_sessions.machine is 'Client operating system machine name'; +comment on column log_user_sessions.program is 'Name of the operating system program'; +comment on column log_user_sessions.count_connects is 'Count of actual connection at this time'; +comment on column log_user_sessions.active_connects is 'Count of connection at this time with active state'; +comment on column log_user_sessions.snaptime is 'Snaptime'; +comment on column log_user_sessions.service_name is 'Name of the DB Service'; +comment on column log_user_sessions.logon_time is 'Logon time of the usersession'; +comment on column log_user_sessions.terminal is 'Operating system terminal name'; +comment on column log_user_sessions.osuser is 'OS user name of the user client session'; +comment on column log_user_sessions.action is 'Name of the currently executing action as set by the DBMS_APPLICATION_INFO.SET_ACTION procedure'; + + +-- +create sequence log_user_sessions_seq minvalue 1 cache 20; + +-- +-- Create the log procedure +-- +create or replace procedure p_log_user_sessions +authid current_user +is +/****************************************************************************** + NAME: p_log_user_sessions + PURPOSE: Read the V$session and record the connect users infos for + statistic purpose and ot see who is working with the DB + + REVISIONS: + Ver Date Author Description + --------- ---------- --------------- ------------------------------------ + 1.0 24.09.2015 GPI 1. Created this procedure. + + NOTES: + +******************************************************************************/ + -- declae table for the resuls + type t_session_tab is table of log_user_sessions%rowtype; + -- define + v_sessiontab t_session_tab; + -- weak cursor + -- c_cur sys_refcursor; + -- hard cursor + cursor c_cur is select log_user_sessions_seq.nextval as id + , username + , osuser + , machine + , program + , action + , terminal + , logon_time + , service_name + , module + , count_connects + , active_connects + , snaptime + from ( select username + , osuser + , machine + , program + , terminal + , action + , module + , trunc(logon_time,'MI') as logon_time + , service_name + , count(*) as count_connects + , sum(decode(s.status,'ACTIVE', 1,0)) as active_connects + , sysdate as snaptime + from v$session s + where username is not null and username not in ('DBSNMP') + group by username + , osuser + , machine + , program + , terminal + , action + , module + , trunc(logon_time,'MI') + , service_name); +begin + -- Cursor get result set + open c_cur; + fetch c_cur + bulk collect into v_sessiontab; + close c_cur; + + dbms_output.put_line ('--Info :: Cursor fetch : ' || v_sessiontab.count); + + begin + -- execute immedate update + forall i in 1 .. v_sessiontab.count save exceptions + insert into log_user_sessions values v_sessiontab (i); + exception + when others + then + for idx in 1 .. sql%bulk_exceptions.count + loop + dbms_output.put_line ( '-- Error :: ' + || sql%bulk_exceptions (idx).error_index + || ': ' + || sql%bulk_exceptions (idx).error_code); + end loop; + end; + + commit; + + end; +/ + +show errors + +-- create the job to record the data every 10 Minutes +declare + jobno number; +begin + dbms_job.submit + (job => jobno + ,what => 'begin + p_log_user_sessions; /* Job to get statistic db connected users - GPI '||to_char(sysdate,'dd.mm.yyyy')||'*/ +end;' + ,next_date => trunc(sysdate,'HH24') + (1/24) --to_date('24.09.2015 09:10','dd.mm.yyyy hh24:mi') + ,interval => 'trunc(sysdate,''mi'') + (1/(24*60)) * 10'); + commit; + end; + / + + +spool off + +-- Query Examples + +select count (*) + , l.username + , l.osuser + , l.machine + , l.program + , l.module + , trunc (sysdate, 'HH24') + , min (l.logon_time) as first_login + , max (l.logon_time) as last_login + from log_user_sessions l +group by osuser, l.program, l.username, l.module, l.machine, trunc (sysdate, 'HH24') +order by l.osuser +/ +--- + + + diff --git a/01-db-setup/report_global_errorlog.sql b/01-db-setup/report_global_errorlog.sql new file mode 100644 index 0000000..ea875a7 --- /dev/null +++ b/01-db-setup/report_global_errorlog.sql @@ -0,0 +1,119 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: HTML Report for the entries in the audit log +-- see : https://www.pipperr.de/dokuwiki/doku.php?id=dba:oracle_sqlfehler_protokoll +-- Date: Juni 2019 +-- +--============================================================================== + + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_sql_error_log.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + +set verify off + +SET linesize 450 pagesize 2000 + +column anzahl format 999G999 heading "Count" +column first_log_entry format A18 heading "First Entry" +column last_log_entry format A18 heading "Last Entry" +column LOG_USR format A20 heading "DB Schema" +column ERR_NR format 99999 heading "Ora Err | Number" +column mesg format A100 heading "Ora Err | Message" +column HOUR format A16 heading "Hour" +column stmt format A250 heading "SQL Statemment" + + +spool &&SPOOL_NAME + +set markup html on + +ttitle left "SQL Error Total Log Summary" skip 2 + +SELECT COUNT (*) AS anzahl + ,to_char(min(log_date),'dd.mm.yyyy hh24:mi') first_log_entry + ,to_char(max(log_date),'dd.mm.yyyy hh24:mi') last_log_entry + ,nvl(LOG_USR,'n/a') AS LOG_USR + ,ERR_NR + ,substr(ERR_MSG,1,300) mesg + FROM SYSTEM.ora_errors + WHERE nvl(log_usr,'n/a') NOT IN ('SYS','SYSMAN','DBSNMP') +GROUP BY nvl(LOG_USR,'n/a') + ,ERR_NR + ,substr(ERR_MSG,1,300) +ORDER BY 2,1 +/ + + +ttitle left "SQL Error Hour Report" skip 2 + + +SELECT COUNT (*) AS anzahl + ,TO_CHAR (log_date, 'dd.mm.yyyy hh24')||'h' AS HOUR + ,nvl(LOG_USR,'n/a') AS LOG_USR + ,ERR_NR + ,substr(ERR_MSG,1,300) mesg + FROM SYSTEM.ora_errors + WHERE nvl(log_usr,'n/a') NOT IN ('SYS','SYSMAN','DBSNMP') +GROUP BY TO_CHAR (log_date, 'dd.mm.yyyy hh24')||'h' + ,nvl(LOG_USR,'n/a') + ,ERR_NR + ,substr(ERR_MSG,1,300) +ORDER BY 2 +/ + + +ttitle left "SQL Error Log All Entries " skip 2 + +set long 64000 + + + +with ErrorLog as + ( select stmt + , log_date + , LOG_USR + , ERR_NR + , substr(ERR_MSG,1,300) mesg + , dbms_lob.getlength(STMT) len + FROM SYSTEM.ora_errors + WHERE nvl(log_usr,'n/a') NOT IN ('SYS','SYSMAN','DBSNMP') + ) + select + COUNT (*) AS anzahl + , to_char(min(log_date),'dd.mm.yyyy hh24:mi') first_log_entry + , to_char(max(log_date),'dd.mm.yyyy hh24:mi') last_log_entry + , LOG_USR + , ERR_NR + , mesg + , dbms_lob.substr(stmt,4000,1) sql_part1 + , case when len > 4000 then dbms_lob.substr(stmt,4000,4001) end sql_part2 + , case when len > 8000 then dbms_lob.substr(stmt,4000,8001) end sql_part3 + , case when len > 12000 then dbms_lob.substr(stmt,4000,12001) end sql_part4 + , case when len > 16000 then dbms_lob.substr(stmt,4000,165001) end sql_part5 + FROM ErrorLog + GROUP BY LOG_USR + , ERR_NR + , mesg + , dbms_lob.substr(stmt,4000,1) + , case when len > 4000 then dbms_lob.substr(stmt,4000,4001) end + , case when len > 8000 then dbms_lob.substr(stmt,4000,8001) end + , case when len > 12000 then dbms_lob.substr(stmt,4000,12001) end + , case when len > 16000 then dbms_lob.substr(stmt,4000,165001) end +ORDER BY 1 +/ + +set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window +host &&SPOOL_NAME + diff --git a/01-db-setup/set_audit_minimal_settings.sql b/01-db-setup/set_audit_minimal_settings.sql new file mode 100644 index 0000000..ac170ae --- /dev/null +++ b/01-db-setup/set_audit_minimal_settings.sql @@ -0,0 +1,42 @@ +-- +audit connect; +audit create session by access; +audit create session whenever not successful; + +--- +audit alter any table by access; +audit create any table by access; +audit drop any table by access; +audit create any procedure by access; +audit drop any procedure by access; +audit alter any procedure by access; +audit grant any privilege by access; +audit grant any object privilege by access; +audit grant any role by access; +audit audit system by access; +audit create external job by access; +audit create any job by access; +audit create any library by access; +audit create public database link by access; +audit exempt access policy by access; +audit alter user by access; +audit create user by access; +audit role by access; +audit drop user by access; +audit alter database by access; +audit alter system by access; +audit alter profile by access; +audit drop profile by access; +audit database link by access; +audit system audit by access; +audit profile by access; +audit public synonym by access; +audit system grant by access; + + +-- Audit failed commands and connects +-- will audit all the commands listed for alter system, cluster, database link, procedure, rollback segment, sequence, synonym, table, tablespace, type, and view +audit resource whenever not successful; + +-- +audit insert, update, delete on sys.aud$ by access; diff --git a/README.md b/README.md index 71c7fd9..1500d6b 100644 --- a/README.md +++ b/README.md @@ -1,2 +1,378 @@ -# OraDBASQLScripts -Oracle SQL Scripts for the DBA +--============================================================================== +-- Author: Gunther Pippčrr +-- Desc: SQL Script Overview +--============================================================================== + +DOC +------------------------------------------------------------------------------- + +#The daily scripts for the DBA +=============================== + + - dict.sql - query the data dictionary - parameter 1 - part of the comments text + + - database.sql - name and age of the database + - status.sql - status of the instance/cluster + - date.sql - get the actual date and time of the DB + - instance.sql - status of the instance where the user is connected + - limit.sql - resource limits since last startup of the instances + - dbfiles.sql - list of all database data files + + - tablespace.sql - Information about the tablespaces + - tablespace_usage.sql - Information usage on a tablespace - Parameter 1 the name of the tablespace + - tablespace_ddl.sql - get the DDL of a tablespace, show default storage options! - Parameter name of the tablespace + - tablespace_space.sql - get a overview over the free and used space for a tablespace - parameter name of the tablespace + - awr_tablespace_history.sql - get the historical Size of a tablespace from the AWR + - tablespace_tab_storage.sql - show all tables on a tablespace + - tablespace_autoextend.sql - set all datafile of a tablespace to autoextend + - tablespace_set_size.sql - set all datafile of a tablespace to the same size + - tablespace_create.sql - print the ddl to create a uniform tablespace - Parameter Name of the tablespace + - tablespace_last_objects.sql - get the last 5 objects in a tablespace + + - sessions.sql - actual connections to the database + - session_history.sql - get a summary over the last active sessions + - session_long_active.sql - all session that are longer active + - session_longops.sql - get information about long running SQL statements + - session_killed.sql - get the process information for killed sessions + - ses_statistic.sql - get the statistic information of a session + - my_opt_settings.sql - Optimizer settings in my session + - my_ses_stat.sql - Satistic of my session + - session_opt_settings.sql - Optimizer settings in a session - parameter 1 username + - session_user_env.sql - show all sys context values in a user session + - session_user_nls_lang.sql - get the NLS Lang User session setting (only SYS !) + + - starttrace.sql - start a trace of my session + - stoptrace.sql - stop trace of my session + - trace_status.sql - show all traces in the database + + - service_session.sql - sessions per service over all instances + - trans.sql - running transactions in the database + - undo.sql - show activity on the undo segment + - undo_stat.sql - show statistic for the undo tablespace usage + - open_trans.sql - all longer open running transactions in the database - uncommitted transaction! + + - bgprocess.sql - Background processes in the database + - process.sql - actual processes in the database parameter 1 - name of the DB or OS User + Parameter 2 - if Y shows also internal processes + - process_get.sql - show the information about the session with this PID - parameter 1 PID + + - resource_manager.sql - show the information about the resource manager + - resource_manager_sessions.sql - Show the resource manager settings of the running sessions + - tempspace_usage.sql - show processes using the temp tablespace + - parallel.sql - parallel SQL informations + - parallel_dbms.sql - DBMS_PARALLEL chunks in work + + - tns.sql - show services and tns settings on services + - tns_history.sql - show services statistics for the last 12 hours (only services with some traffic) + - taf.sql - Check TAF settings of the connections + - connection_pool.sql - Show the Database Resident Connection Pooling (DRCP) Settings + - ssl.sql - check the sql*net connection if ssl or encryption is in use + + - locks.sql - locks in the database - mode 6 is the blocker! + - ddl_locks.sql - check for DDL Locks + + - wait.sql - waiting sessions + - wait_text.sql - text to a wait event - parameter 1 part of the event name + - wait_get_name.sql - search for a name of a wait event + + - latch.sql - get Information’s about the DB latch usage + - checkpoint.sql - get the actual status for the instance recovery + + - my_user.sql - who am I and over with service I connect to the database + - nls.sql - global and session NLS Settings + - version.sql - version of the database + - test_sqlnet_fw.sql - test the time-outs of SQL*Net + + - init.sql - init.ora entries + - init_rac.sql - show init.ora parameter in a RAC Environment to check if same parameters on each node + - db_events.sql - test if some events are set in the DB environment + - db_properties.sql - get the database properties + + - xmldb.sql - show configuration of the XML DB + - acl.sql - show the acls of the Database (for security) + - my_acl.sql - show my rights + + - java.sql - java access rights + - java_recomplie_invalid.sql - compile invalid (resolve) java classes in a user schema + + - invalid.sql - show all invalid objects + - invalid_synoyms.sql - delete Script for invalid synonym + - invalid_obj_report.sql - get report for development for invalid objects in the database + - invalid_constraints.sql - get all invalid constraints + + - user.sql - rights and roles of a user and object grants - parameter 1 - Name of the user + - users.sql - overview over the DB users - parameter 1 - Name of the user + - user_ddl.sql - get the script to create a user - parameter 1 - Name of the user + - user_history.sql - get some static information for the login behavior of this user - Parameter 1 - Name of the user + - user_objects.sql - show the counts of objects from none default users + - user_oracle_default.sql - define the list of the default oracle db schemas + + - vpd.sql - show the VPD - Virtual Private Database Settings + + - user_tab.sql - get all the tables and views of a user - parameter 1 - part of the table name + - ls.sql - gets all the tables and shows the size of the user tab + + - roles.sql - all roles in the database - parameter 1 part of the role name + - role.sql - get the rights on a role + - role_ddl.sql - get the dll of one role in the database - parameter 1 the role name + + - profile.sql - profiles for the user of this database + - proxy.sql - proxy settings in the database + - proxy_to.sql - All schemas that can be switch to this schema with proxy rights - parameter 1 name of the schema + - proxy_client.sql - from which user you can connect to this user - parameter 1 the user + + - comment.sql - search over all comments - parameter 1 - part of the comment text + + - desc.sql - describe a table - parameter 1 Table name - 2 - part of the column name + - tab.sql - search a table or views in the database - parameter 1 - part of the table + - tab_overview_report.sql - report over all none default tables in the database + - tab_cat.sql - get the tables and views of the current user + - tab_count.sql - count the entries in a table - parameter 1 - name of the table + - tab_space.sql - space usage of a table + - tab_stat.sql - get the statics of the table - parameter - Owner, Table name + - tab_desc.sql - describe the columns of the table - parameter 1 - part of the table + - tab_ddl.sql - get the create script of a table - parameter - Owner, Table name + - tab_last.sql - get the change date of a record in the table - parameter - Owner, Table name + - tab_mod.sql - get the last modifications of the table - parameter - Owner, Table name + - tab_data_changes.sql - get an overview over changes on the tables of a user - parameter - Owner + - tab_umlaut.sql - check for tables/views if umlauts are used for the naming of tables and columns + + - tab_usage.sql - check if the table is used in the last time - parameter - Owner, Table name + - tab_part.sql - get the partition information of a table - parameter - Owner, Table name + - partition.sql - Analyse the partitions of the tables of a user + + - tab_ext.sql - get information about external tables + - tab_iot.sql - show information about a index organized table - parameter - Owner, Table name + - tab_iot_all.sql - Show all IOT in the database + + - tab_mat.sql - Information about materialized views + - tab_mat_log.sql - Information about materialized views Logs + - refresh_group.sql - Get all refresh groups of the DB for the materialized views + - my_refresh_group.sql - Get all refresh groups of your Schema + + - tab_defekt_blocks.sql - check for corrupted blocks + - tab_defekt_blocks_bad_table.sql - create rowid table for all readable data for a table with a defect lob segment + + - tab_redef.sql - example for an online table redefinition + - tab_stat_overview.sql - statistic over all table of a user parameter 1 - schema name + - analyse_changed_rows.sql - analyses changed row for a table + - recreate_tables.sql - create the script to reorganise the smaller tables of a tablespace with alter table move + + - column_type.sql - get all columns in the database with this data-type parameter 1 - data type - owner + - column.sql - search all tables with this column name - parameter 1 - name of the column + + - synonym.sql - search all synonym of a user - parameter - Owner, data type + - synonym_detail.sql - get information over one synonym - parameter - Owner, synonym Name + + - lob.sql - show the lob settings of the tables of the user - parameter - Owner + - lob_detail.sql -Get the details for the lob data type for this table - parameter owner and table name + - dimension_ddl.sql - Get the DDL of a oracle dimension object in the database + + - sequence.sql - search a sequence in the database parameter 1 - name of the sequence + + - recycle.sql - show the content summary of the dba recyclebin + + - tab_tablespace.sql - get the tablespaces of the user - parameter - Owner + - tab_tablespace_all.sql - get the used tablespace overview of this database + + - index.sql - get the information’s over a index - parameter - Owner, Index name + - index_all.sql - get all indexes of a user - parameter - Owner + - index_mon.sql - check the result of index monitoring + - index_ddl.sql - get the DDL of an index + + - obj_dep.sql - get the dependencies of a object in the database - parameter - Owner, object name + - obj_deps_report.sql - get a overview of dependencies in a database as HTML Report + - obj_grants.sql - get the grants for this object in the database - parameter - Owner, object name + - obj_last_ddl.sql - get the last DDL for all objects of a user - parameter - Owner + + - plsql_info.sql - information about a pl/sql function/package + - plsql_search.sql - search for a pl/sql function/procedure also in packages - parameter Search String + - plsql_depend.sql - information about the dependencies of a package/procedure - parameter - Owner, object name + - plsql_depend_on.sql - Which objects depends on this pl/sql code + - plsql_errors.sql - show the errors of pl/sql objects + - plsql_dll.sql - information about a pl/sql function/package - parameter - Owner, object name + - my_plsql.sql - show all package of the current user + - plsql_usage.sql - which package are used in the last time and how often over the SGA Cache + - plsql_running.sql - actual running pl/sql in the database + + - select.sql - select first 3 records of the table as list - parameter 1 - name of the table + - view_count.sql - count entries in a view - parameter 1 - name of the view + - view_getsql.sql - get the real SQL statement behind the call of a view - parameter - Owner, view name + + - asm.sql - asm disk status and filling degree of the asm disks + + - asm_disk.sql - asm disk groups space + - asm_all_disks.sql - show the disk infos + - asm_balance.sql - asm disk disk balance - Parameter 1 - name of the disk group + - asm_partner.sql - Information about asm partner disk + - asm_files.sql - All files on an ASM disk group + + - asm_failgroup.sql - Show the failgroup information of a disk group - Parameter 1 - name of the disk group + - asm_offline_failgroup.sql - create the script to offline all disks in a failgroup - Parameter 1 over the nameing convention of the disk! + - asm_online_failgroup.sql - create the script to online all failgroup with offline disks + - asm_rebalance.sql - Show the rebalance information of a asm resync of disks + - asm_attribute.sql - Show the parameter of a ASM Diskgroup - parameter 1 Diskgroup Name - parameter 2 - parameter name + + - flash.sql - show the flash back information’s + - reco.sql - recovery area settings and size + - archive_log_status.sql - status of the archivelog files + + - redo.sql - redo log information (use redo10g.sql for 10g/9i) + - redo_change.sql - who create how much redo per day last 7 in the database + - scn.sql - scn in the archive log history + - sqn.sql - sequence log + + - ext/tsc.sql - table space size information + - directory.sql - show directories in the database + - my_directory.sql - show directories of the actual connect user in the database + - links.sql - show the DB Links in the database + - links_ddl.sql - get the DDL of all DB links in the database + - links_usage.sql - get the sourcecode that use the DB links + + - audit.sql - show the audit settings + - audit_sum.sql - audit log summary + - audit_login.sql - audit the logins of users + + - jobs.sql - jobs in the database job$ and scheduler tasks info + - jobs_dbms.sql - jobs declared with dbms_job - old style jobs + - jobs_sheduler.sql - jobs declared over the job scheduler + - jobs_errors.sql - jobs in the database job$ and scheduler tasks info with errors + - jobs_window_resource_class.sql - show the relation between job windows , job classes and resource plans + - jobs_logs.sql - Details of a job + + - sga.sql - show information about the oracle sga usage + - buffer.sql - show information about the buffer cache usage / must run as sys + - buffer_cache.sql - show information about objects in the buffer cache + - pga.sql - show information about the PGA usage + + - statistic.sql - show information over the statistics on the DB and stat age on tables and when the stats job runs + - statistic_backup.sql - save all statistics of the DB in backup tables + + - cursor.sql - show information about the cursor usage + + - sql_find.sql - find a SQL Statement in the Cache - parameter 1 part of the SQL statement + - sql_plan.sql - get the Execution Plan for one SQL ID from the cache + - sql_temp.sql - SQL that use the temp table space for sorting + - sql_show_bind.sql - Show the bind variables of the SQL statement from the cursor Cache - parameter 1 - SQL ID + - sql_parallel.sql - Show the parallel execution for this statement - parameter 1 - SQL ID + - sql_opt_settings.sql - Show the optimizer settings for this statement - parameter 1 - SQL ID + + - sql_kill_session.sql - create the command to kill all sessions running this SQL at the moment - parameter 1 - SQL ID + - sql_purge_cursor.sql - purge the cursor out of the cache - parameter 1 - SQL ID + + - sql_profile.sql - show all profiles in the database + - sql_profile_details.sql - get the details of a SQL profile - parameter 1 - Profile Name + - sql_baseline.sql - get the defined baseline + - sql_baseline_evolve.sql - evolve and get the details of one baseline - parameter 1 - the baseline sql_handle name + - sql_baseline_plan.sql - get the details of of a plan in a baseline - parameter 1 - the baseline sql_baseline_plan + - sql_session_stat.sql - get statistics from running session for this SQL - parameter 1 - SQL ID + + - get_plan.sql - get the plan of the last "explain plan for" + + - ash.sql - usage of the active session history ASH + + - awr.sql - usage of the AWR repository and of the SYSAUX table space + - awr_sql_find.sql - find a SQL Statement in the AWR History - parameter 1 part of the SQL statement + - awr_sql_find_report.sql - create overview report over the usage of a SQL statement or hint - parameter 1 part of the SQL statement + - awr_sql_stat.sql - get statistic of the SQL execution of one statement - parameter 1 - SQL ID + - awr_sql_hash.sql - get the different hashes if exits - parameter 1 - SQL ID + - awr_sql_plan.sql - get plan of the SQL execution of one statement - parameter 1 - SQL ID + - awr_sql_time_stat.sql - get all SQL statements from the awr for this time - parameter 1 - Start date - parameter 2 end date in DE format + - awr_temp_usage.sql - get the SQL that use temp tablespace from the awr for this time - parameter 1 - Start date - parameter 2 end date in DE format + - awr_pga_stat.sql - statistic of the pga usage + - awr_sys_stat.sql - statistic of system historical statistics information + + - awr_session_stat.sql - statistic of the sessions of a user + - awr_session_resource_plan_historie.sql - Show the consumer group of all history active sessions of a user + - awr_act_active_sessions.sql - get information about the act active Session in the last 90 minutes + - awr_ash_top_sql.sql - select the last top sql statements from the active session history + - awr_act_blocking_sessions.sql - get information about blocking sessions in the database + - awr_session_none_technical_user.sql - get information about none technical user sessions + - awr_changed_plans.sql - search for changed plans in a time period - parameter 1 - Start date - parameter 2 end date in DE format + - awr_resourcelimit.sql - display the resource limits of the last days + - awr_os_stat.sql - display the OS statistic of the last days + - awr_call_awr_report.sql - create AWR Report of the database + - awr_call_ash_report.sql - create ASH Report of the database + - awr_call_sqlmonitor_report.sql - call a sql Monitor Report + + - statspack_delete_job.sql - create a job to clean the statspack repository + + - calibrate_io.sql - Use I/O calibrate to analyses io of the database and set the internal I/O views + - system_stat.sql - get the DB internal system stat values like workload statistic and I/O calibrate values + + - ctx.sql - Oracle Text indexes for a user and ctx settings - parameter 1 - name of the user + + - rman.sql - rman settings of this database and summary information about the last backups for this database and the block change tracking feature + - rman_process.sql - get information over running rman processes for tracing + - rman_status.sql - get the status of the last backup in the database + + - datapump.sql - show datapump sessions + - datapump_filter.sql - show all possible filter values für the INCLUDE/EXCLUDE parameter of datapump + + - standby_status.sql - status of a standby / DG environment + + - streams_status.sql - status of streams replication + - streams_config.sql - streams configuration + - streams_logs.sql - show the streams archive logs - which can be deleted + - streams_print_error.sql - print the SQL Statements for all LCRS in a transaction if a streams error occurs + - streams_print_lcr.sql - print the LCR of one Message + - streams_logmnr.sql - information about the log miner process + + - db_alerts.sql - get the internal metric settings of the DB side monitoring + - db_alerts_set.sql - set the threshold of a metric + + - health_mon.sql - call the health monitoring in 11g - get the parameter + + - login.sql - set the login prompt + + - http_ftp_port.sql - get the port settings of the database + + - ords.sql - get the ORDS REST service definitions + + #Create Scripts + ================= + + - clean_user.sql - create the DDL to delete every object in the schema - parameter 1 - user name + + - space_tablespace.sql - create the DDL to shrink a table space - parameter 1 - Name of the table space (%) for all + - space_tablespace_auto.sql - shrink each possible tablespace without asking + + - recreate_index.sql - Script to create a index recreation script + - recreate_table.sql - Script to reorganize all small tables in a tablespace, off-line with !alter Table move! + + + - create_mon_index.sql - Script to create index enable or disable monitoring scripts for a user - parameter 1 - user name + + - create_all_statistic.sql - Recreate the statistic of the database + + #Reports + ================= + + - check_col_usage.sql - HTML Report - Table column used in SQL Statements but not indexed and all indexes with more than one column to check for duplicate indexing + + - top_sql.sql - HTML Report - Top SQL Statements in the database for Buffer / CPU / Sort Usage + - sql_user_report.sql - HTML Report - Show all SQL statements for this user in the SGA + + - audit_rep.sql - HTML Report - Audit Log entries + + - licence.sql - HTML Report - License Report Overview - Feature Usage + + #Setup + ================= + + - 01-db-setup/create_global_errorlog.sql - create a global error table and error trigger + maintain job + - 01-db-setup/delete_global_errorlog.sql - delete the global error trigger + error table + + - 01-db-setup/create_audit_log_database.sql - create own table space for auditlog, move audit log to this table pace - create clean job + - 01-db-setup/set_audit_minimal_settings.sql - set minimal audit parameter + + - 01-db-setup/monitor_user_sessions.sql - create a log table to monitor user connection over some time + - 01-db-setup/ create-logon-trigger-user-handling.sql - create logon trigger to restrict access to the database + + #The OEM Query Scripts + ================= + - get the the help of the OEM scripts use oem/help_oem.sql + +------------------------------------------------------------------------------- +# + diff --git a/acl.sql b/acl.sql new file mode 100644 index 0000000..fbbe3e0 --- /dev/null +++ b/acl.sql @@ -0,0 +1,122 @@ +--=============================================================================== +-- GPI - Gunther Pippèrr +--http://docs.oracle.com/cd/B28359_01/appdev.111/b28419/d_networkacl_adm.htm#CHDJFJFF +--http://www.oracle.com/webfolder/technetwork/de/community/dbadmin/tipps/acl/index.html +--http://www.oracleflash.com/36/Oracle-11g-Access-Control-List-for-External-Network-Services.html +--http://www.oracle-base.com/articles/11g/fine-grained-access-to-network-services-11gr1.php +--=============================================================================== + +set linesize 130 pagesize 300 + +column acl format a40 heading "ACL" +column host format a30 +column principal format a16 +column privilege format a10 +column is_grant format a8 +column lower_port format a12 heading "Lower Port" +column upper_port format a12 heading "Upper Port" + +set lines 1000 + +select acl + , host + , to_char (lower_port) lower_port + , to_char (upper_port) upper_port + from DBA_NETWORK_ACLS +/ + +select acl + , principal + , privilege + , is_grant + from DBA_NETWORK_ACL_PRIVILEGES +/ + + +-- from https://docs.oracle.com/database/121/ARPLS/d_networkacl_adm.htm#ARPLS67214 +select host + , lower_port + , upper_port + , ace_order + , principal + , principal_type + , grant_type + , inverted_principal + , privilege + , start_date + , end_date + from (select aces.*, +dbms_network_acl_utility.contains_host('*', + host) precedence + from dba_host_aces aces) + where precedence is not null + order by precedence desc, + lower_port nulls last, + upper_port nulls last, + ace_order; +/ +/* + test entry: + + BEGIN + DBMS_NETWORK_ACL_ADMIN.create_acl ( + acl => 'my_test_acl.xml', + description => 'A test of the ACL functionality', + principal => 'GPI', + is_grant => TRUE, + privilege => 'connect'); + + DBMS_NETWORK_ACL_ADMIN.ADD_PRIVILEGE( + acl => 'my_test_acl.xml', + principal => 'GPI', + is_grant => true, + privilege => 'resolve'); + + COMMIT; +END; +/ + +begin +-- the I can all + DBMS_NETWORK_ACL_ADMIN.assign_acl ( + acl => 'my_test_acl.xml', + host => '*', + lower_port => 1, + upper_port => 9999); + +-- ony one server + DBMS_NETWORK_ACL_ADMIN.ASSIGN_ACL( + acl => 'my_test_acl.xml', + host => 'www-proxy.us.oracle.com'); + +COMMIT; + +end; +/ + +-- delete one acl +begin + DBMS_NETWORK_ACL_ADMIN.UNASSIGN_ACL ( + acl => 'localhost-permissions.xml', + host => 'pbupcb1.pbprd.lprz.com', + lower_port => 9080, + upper_port => 9080) + ; +end; +/ + +declare + l_url varchar2 (50) + := 'http://www.goggle.de; + l_http_request UTL_HTTP.req; + l_http_response UTL_HTTP.resp; +BEGIN + -- Make a HTTP request and get the response. + l_http_request := UTL_HTTP.begin_request(l_url); + l_http_response := UTL_HTTP.get_response(l_http_request); + UTL_HTTP.end_response(l_http_response); +END; +/ + + +*/ \ No newline at end of file diff --git a/alert_log.sql b/alert_log.sql new file mode 100644 index 0000000..365a417 --- /dev/null +++ b/alert_log.sql @@ -0,0 +1,23 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: read the alert log of the database over the adrci alert.xml +--=============================================================================== +set linesize 130 pagesize 300 pages 0 + +define SEARCH_TEXT = '&1' + +prompt +prompt Parameter 1 = SEARCH_TEXT => &&SEARCH_TEXT. +prompt + +set serveroutput on; + +column log_date format a20 +column message_text format a95 + +select substr (originating_timestamp, 1, 15) as log_date, message_text + from x$dbgalertext + where originating_timestamp > ( sysdate + - 10) + and message_text like '%&&SEARCH_TEXT.%' +/ \ No newline at end of file diff --git a/analyse_changed_rows.sql b/analyse_changed_rows.sql new file mode 100644 index 0000000..ae96394 --- /dev/null +++ b/analyse_changed_rows.sql @@ -0,0 +1,85 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: analyse chained rows in the database +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== +-- http://docs.oracle.com/cd/B28359_01/server.111/b28286/statements_4005.htm#SQLRF01105 +-- http://blog.tanelpoder.com/2009/11/04/detect-chained-and-migrated-rows-in-oracle/ +--============================================================================== +set verify off +set linesize 130 pagesize 1000 + +define USER_NAME ='GPI' +define TABLE_NAME ='COL_T' +define TABLE_SPACE='USERS' + +set serveroutput on + +---------------------- +-- alternative use the utlchain.sql script in oracle_home/rdbms/admin +declare +v_count pls_integer; +begin + select count(*) into v_count + from DBA_TABLES + where owner=upper('&&USER_NAME.') + and table_name ='CHAINED_ROWS'; + if v_count < 1 then + dbms_output.put_line('-- Info : create chained row table'); + execute immediate 'create table &&USER_NAME..CHAINED_ROWS ( + owner_name varchar2(30), + table_name varchar2(30), + cluster_name varchar2(30), + partition_name varchar2(30), + subpartition_name varchar2(30), + head_rowid rowid, + analyze_timestamp date + ) tablespace &&TABLE_SPACE. + '; + else + dbms_output.put_line('-- Info : use existing chained row table'); + end if; +end; +/ + +select to_char(sysdate,'dd.mm.yyyy hh24:mi') as start_time from dual +/ + +declare + cursor c_tab is + select table_name,owner + from dba_tables + where owner=upper('&&USER_NAME.') + and table_name like '&&TABLE_NAME.%'; + + v_count pls_integer; + v_start number:=dbms_utility.get_time; + +begin + for rec in c_tab + loop + dbms_output.put_line('-- Info --------------------------------'); + dbms_output.put_line('-- Info : start to analyse the table '||rec.owner||'.'||rec.table_name||' at ::'||to_char(sysdate,'dd.mm.yyyy hh24:mi')); + --execute immediate 'analyse table '||rec.owner||'.'||rec.table_name||' list chained rows into '||rec.owner||'.chained_rows'; + dbms_output.put_line('-- Info : finish to analyse the table '||rec.owner||'.'||rec.table_name||' at ::'||to_char(sysdate,'dd.mm.yyyy hh24:mi')); + v_count:=v_count+1; + end loop; + dbms_output.put_line('-- Info --------------------------------'); + dbms_output.put_line('-- Info : finish to analyse '||v_count||' tables after '||to_char(dbms_utility.get_time-v_start)||'ms'); +end; +/ + +select to_char(sysdate,'dd.mm.yyyy hh24:mi') as end_time from dual +/ + + +select count(*),c.table_name + from &&USER_NAME..CHAINED_ROWS c + group by c.table_name +/ + +set verify on + diff --git a/any_rights.sql b/any_rights.sql new file mode 100644 index 0000000..f139316 --- /dev/null +++ b/any_rights.sql @@ -0,0 +1,52 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the user rights and grants +-- Date: September 2012 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + + +column grantee format a25 +column GRANTOR format a25 +column PRIVILEGE format a25 heading "Priv" +column table_name format a20 heading "Table|Name" +column ADMIN_OPTION format a3 heading "Adm|OPT" +column COMMON format a3 heading "Com" +column INHERITED format a7 heading "Inherit" + + +column table_name format a26 heading "User|Name" + + +ttitle left "ANY for &&USER_NAME" skip 2 + +select grantee, table_name, privilege + from dba_tab_privs + where privilege like '%PRIVILEGES%' + and table_name like upper('&&USER_NAME.') +order by table_name,PRIVILEGE + / + + +ttitle left "Any PRIVILEGES for &&USER_NAME" skip 2 + +select GRANTEE + , PRIVILEGE + , ADMIN_OPTION + , COMMON + , INHERITED + from dba_sys_privs + where privilege like '% ANY %' + and grantee like upper('&&USER_NAME.') +order by GRANTEE,PRIVILEGE +/ + +ttitle OFF + +column table_name format a20 heading "table_name" + +-------------- diff --git a/apex_version.sql b/apex_version.sql new file mode 100644 index 0000000..02b51e3 --- /dev/null +++ b/apex_version.sql @@ -0,0 +1,28 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: version of the database +-- Date: 30.05.2019 +--============================================================================== +set linesize 130 pagesize 300 + + +column VERSION_NO format a30 heading "APEX Version" + +select version_no + from apex_release +/ + +column VERSION format a30 heading "APEX Version DB Registry" +column comp_name format a40 +column status format a10 + +select version,comp_name,status + from dba_registry + where comp_name = 'Oracle Application Express' +/ + +column VERSION format a40 heading "ORDS Version" + +select VERSION + from ORDS_METADATA.ords_version +/ diff --git a/archive_log_status.sql b/archive_log_status.sql new file mode 100644 index 0000000..5ab82c1 --- /dev/null +++ b/archive_log_status.sql @@ -0,0 +1,31 @@ +-- ====================================================== +-- GPI - Gunther Pippèrr +-- Desc : Check the status of the archive logs +-- ====================================================== + +-- archive_log_status.sql +-- see https://blog.dbi-services.com/archivelog-deletion-policy-for-standby-database-in-oracle-data-guard/ + +set verify off +set linesize 130 pagesize 300 + +set serveroutput on size 1000000 + + +prompt ... Check if archivelogs are need for recovery or can be deleted + +select applied + , deleted + , decode(rectype,11,'YES','NO') as reclaimable + , count(*) + , min(sequence#) + , max(sequence#) + from v$archived_log left outer join sys.x$kccagf using(recid) +where is_recovery_dest_file='YES' and name is not null +group by applied,deleted,decode(rectype,11,'YES','NO') order by 5 +/ + +prompt ... +prompt ... reclaimable = YES means that this archivelog can be deleted and is not nesseary anymore for the recovery, maybe still backuped +prompt ... set with RMAN "CONFIGURE ARCHIVELOG DELETION POLICY TO APPLIED ON ALL STANDBY;" to trigger check of archivelogs +prompt ... \ No newline at end of file diff --git a/ash.sql b/ash.sql new file mode 100644 index 0000000..ac8b8de --- /dev/null +++ b/ash.sql @@ -0,0 +1,29 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +--============================================================================== +-- see Metalink Node Active Session History (ASH) Performed An Emergency Flush Messages In The Alert Log (Doc ID 1385872.1) +--============================================================================== +set linesize 130 pagesize 300 + +column total_size format 999G999G999 heading "Total|size" +column OLDEST_SAMPLE_TIME format a18 heading "Oldest|sample" +column LATEST_SAMPLE_TIME format a18 heading "Latest|sample" +column SAMPLE_COUNT format 999G999G999 heading "Sample|count" +column awr_flush_emergency_count format 999 heading "Emergency|flush" + +select total_size + , to_char(OLDEST_SAMPLE_TIME,'dd.mm.yyyy hh24 mi') as OLDEST_SAMPLE_TIME + , to_char(LATEST_SAMPLE_TIME,'dd.mm.yyyy hh24 mi') as LATEST_SAMPLE_TIME + , SAMPLE_COUNT + , awr_flush_emergency_count + from v$ash_info +/ + +prompt +@init _ash_size +prompt +prompt .... if you have a high count on awr_flush_emergency_count +prompt .... Check Metalink Node Doc ID 1385872.1 +prompt .... May be you increase the size with +prompt .... alter system set "_ash_size"= scope=both sid='*'; +prompt diff --git a/asm.sql b/asm.sql new file mode 100644 index 0000000..ac15b25 --- /dev/null +++ b/asm.sql @@ -0,0 +1,146 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: SQL Script ASM Disk Overview +-- Date: 2012 +--============================================================================== + +set linesize 130 pagesize 300 + +spool asm.log + +ttitle left "ASM Disk Status and Size" skip 2 + +define dnum = "format 999G999G999G999D99" +define lnum = "format 9G999G999" +define num = "format 99G999" +define snum = "format 9G999" + +column total_mb &&lnum +column group_number format 99 heading "Grp Nr." +column inst_id format 99 heading "Inst" +column status format A6 +column state format A7 +column type format A6 +column name format A20 +column free &&lnum +column used &&lnum + +column writes &&dnum +column reads &&dnum +column read_errs &&snum heading "R Er." +column write_errs &&snum heading "W Er." +column r_tim &&dnum heading "R Tim." +column w_tim &&dnum heading "W Tim." +column bytes_read &&num +column bytes_written &&num +column INSTANCE_NAME format A10 + +select group_number + ,name + ,state + ,type + ,total_mb Brutto + ,decode(type,'NORMAL',total_mb/2,total_mb) Netto + ,usable_file_mb as free_netto + --,total_mb - usable_file_mb as used + from v$asm_diskgroup +order by name +/ + +prompt ---------------------- + +ttitle left "ASM User" skip 2 + +column status format A10 +select inst_id + ,GROUP_NUMBER + ,INSTANCE_NAME + ,STATUS + from gv$ASM_CLIENT + order by inst_id + ,GROUP_NUMBER +/ + + +ttitle left "ASM Disks" +prompt ---------------------- + +column diskpath format A15 +column name format A12 + +select d.GROUP_NUMBER + , g.name + , d.name + , d.path as diskpath + , d.TOTAL_MB + , d.FREE_MB + , d.total_mb - d.free_mb as used + from v$asm_disk d + , v$asm_diskgroup g +where g.GROUP_NUMBER = d.GROUP_NUMBER +order by 1 +/ + +ttitle left "ASM Disk Extend distribution" +prompt ---------------------- + +select count(pxn_kffxp) as count_extents + , disk_kffxp as disk + , group_kffxp as diskgroup + from x$kffxp + group by disk_kffxp + ,group_kffxp +order by diskgroup,disk +/ + +prompt ---------------------- + +ttitle left "ASM Disk Performance" skip 2 + +column name format A7 +select inst_id + ,group_number + ,replace(name, '_0000', '') as name + ,reads + ,writes + ,read_errs +-- , write_errs +-- , bytes_read/read_time +-- , bytes_written/write_time +-- , bytes_read +-- , bytes_written + from gv$asm_disk_stat + where group_number > 0 + order by inst_id + ,group_number + ,disk_number; + +--prompt +--prompt R Er. : read Errors +--prompt w Er. : write Errors +--prompt r_tim : read time in cs +--prompt w_tim : write time in cs +prompt + +/* +ttitle left "ASM Files on Storage" skip 2 + +column name format a30 +select f.group_number + ,f.FILE_NUMBER + ,f.BYTES + ,a.name + from v$asm_file f + ,v$asm_alias a + where f.file_number = a.file_number + and f.group_number = a.group_number + order by f.file_number +/ + +*/ + +ttitle off + +spool off + + diff --git a/asm_all_disks.sql b/asm_all_disks.sql new file mode 100644 index 0000000..328c645 --- /dev/null +++ b/asm_all_disks.sql @@ -0,0 +1,52 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show asm candidate disks +-- Date: November 2013 +--============================================================================== +set linesize 130 pagesize 300 + +column OS_MB format 9G999G999 heading "OS|MB" + +column name format a16 heading "Disk|Name" +column path format a40 heading "Disk|Path" +column header_status format a10 heading "Header|status" +column mount_status format a10 heading "Mount|status" +column mode_status format a10 heading "Mode|status" +column state format a10 heading "State" +column GROUP_NUMBER format 999 heading "Grp|Nr" + +ttitle left "ASM Disk Candidates" skip 2 + + + +SELECT GROUP_NUMBER + , path + , name + , OS_MB + , header_status + , mount_status + , mode_status + , state + FROM v$asm_disk +ORDER BY GROUP_NUMBER +/ + + +prompt ---------------------- + +ttitle left "ASM Disks Size " + +select d.GROUP_NUMBER + , g.name + , d.name + --, d.path + , d.TOTAL_MB + , d.FREE_MB + , d.total_mb - d.free_mb as used + from v$asm_disk d + , v$asm_diskgroup g +where g.GROUP_NUMBER (+) = d.GROUP_NUMBER +order by 1 +/ + +ttitle off \ No newline at end of file diff --git a/asm_attribute.sql b/asm_attribute.sql new file mode 100644 index 0000000..689ee91 --- /dev/null +++ b/asm_attribute.sql @@ -0,0 +1,39 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script ASM Disk Overview +-- Date: 2016 +--============================================================================== +set linesize 130 pagesize 300 recsep off + +define DG_NAME = '&1' +define PRAM_NAME = '&2' + +prompt +prompt Parameter 1 = Data Group Name => &&DG_NAME. +prompt Parameter 2 = Parameter Name => &&PRAM_NAME. +prompt + +column GROUP_NAME format A10 heading "Group|name" +column NAME format A50 heading "Propertiy|name" +column value format A20 heading "Value" +column SYSTEM_CREATED format a7 heading "System|created" + +ttitle left "ASM Attributes" skip 2 + +select g.name as group_name + , a.name + , a.value + , a.SYSTEM_CREATED + from V$ASM_ATTRIBUTE a + inner join v$asm_diskgroup g on (g.group_number=a.group_number) +where g.name like upper ('&&DG_NAME') + and a.name like lower ('%&&PRAM_NAME%') +order by a.name + , g.name +/ + +ttitle off + +prompt ... to set a parameter +prompt ... like : ALTER DISKGROUP SET ATTRIBUTE 'compatible.asm'='11.2.0.0.0' +prompt ... \ No newline at end of file diff --git a/asm_balance.sql b/asm_balance.sql new file mode 100644 index 0000000..8cf2a71 --- /dev/null +++ b/asm_balance.sql @@ -0,0 +1,38 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show asm balance +-- Date: November 2013 +--============================================================================== +set linesize 130 pagesize 300 + + +define DG_NAME = '&1' + +prompt +prompt Parameter 1 = Data Group Name => &&DG_NAME. +prompt + +column bytes format 999G999G999G999 heading "Bytes|total" +column group_number format 999 heading "Grp|Nr" +column file_name format a50 heading "File|Name" +column doublecount format 99 heading "File|Count" +column GROUP_NAME format A20 heading "Group|name" + +ttitle left "ASM Disk Status and Size" skip 2 + +select g.name as GROUP_NAME + , a.name as file_name + , b.bytes + , count(*) over(partition by a.group_number, a.file_number, a.file_incarnation) doublecount + from v$asm_alias a + , v$asm_file b + , v$asm_diskgroup g +where g.name like upper ('&&DG_NAME') + and g.group_number = b.group_number + and a.group_number = b.group_number + and a.file_number = b.file_number + and a.file_incarnation = b.incarnation +/ + +ttitle off + diff --git a/asm_candidate.sql b/asm_candidate.sql new file mode 100644 index 0000000..171d654 --- /dev/null +++ b/asm_candidate.sql @@ -0,0 +1,45 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show asm candidate disks +-- Date: November 2013 +--============================================================================== +set linesize 130 pagesize 300 + + +column OS_MB format 9999999 heading "OS|MB" + +column name format a20 heading "Disk|Name" +column path format a30 heading "Disk|Path" +column header_status format a15 heading "header|status" +column mount_status format a15 heading "mount|status" +column mode_status format a15 heading "mode|status" +column state format a15 heading "state" + +ttitle left "ASM Disk Candidates" skip 2 + +SELECT OS_MB + , DISK_NUMBER + , path + , header_status + , mount_status + , mode_status + , state + FROM v$asm_disk +WHERE GROUP_NUMBER=0 +order by header_status; + +prompt ... +prompt ... Header status of the disk : +prompt ... +prompt ... UNKNOWN - Oracle ASM disk header has not been read +prompt ... CANDIDATE - Disk is not part of a disk group and may be added to a disk group with the ALTER DISKGROUP statement +prompt ... INCOMPATIBLE - Version number in the disk header is not compatible with the Oracle ASM software version +prompt ... PROVISIONED - Disk is not part of a disk group and may be added to a disk group with the ALTER DISKGROUP statement. +prompt ... MEMBER - Disk is a member of an existing disk group. No attempt should be made to add the disk to a different disk group. +prompt ... The ALTER DISKGROUP statement will reject such an addition unless overridden with the FORCE option. +prompt ... FORMER - Disk was once part of a disk group but has been dropped cleanly from the group. +prompt ... CONFLICT - Oracle ASM disk was not mounted due to a conflict +prompt ... FOREIGN - Disk contains data created by an Oracle product other than ASM + + +ttitle off diff --git a/asm_disk.sql b/asm_disk.sql new file mode 100644 index 0000000..bcd475f --- /dev/null +++ b/asm_disk.sql @@ -0,0 +1,184 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: SQL Script ASM Disk Overview +-- Date: 2012 +--============================================================================== +-- http://jarneil.wordpress.com/2008/04/10/keep-disks-in-your-diskgroup-the-same-size/ +-- http://docs.oracle.com/cd/E24628_01/em.121/e25160/asm_cluster.htm#EMDBM10000 +--============================================================================== +set linesize 130 pagesize 300 recsep off + +ttitle left "ASM Disk Status and Size" skip 2 + +define dnum = "format 999G999G999G999D99" +define lnum = "format 9G999G999" +define num = "format 99G999" +define snum = "format 9G999" + +column total_mb &&lnum +column group_number format 99 heading "Grp Nr." +column inst_id format 99 heading "Inst" +column status format A6 +column state format A10 heading "State" +column type format A6 heading "Type" +column name format A20 +column free &&lnum +column used &&lnum + +column writes &&dnum +column reads &&dnum +column read_errs &&snum heading "R Er." +column write_errs &&snum heading "W Er." +column r_tim &&dnum heading "R Tim." +column w_tim &&dnum heading "W Tim." +column bytes_read &&num +column bytes_written &&num +column INSTANCE_NAME format A10 +column free_percent format a6 heading "free|%" +column free_netto format 999G999G999 heading "Usable|netto" +column Netto format 999G999G999 heading "Usable|total" +column Brutto format 999G999G999 heading "Disk|total" +column disk_count format 999 heading "Disk|cnt" +column disk_count_vot format 999 heading "Vot|cnt" +column header_status format a14 heading "Header|Status" +column mount_status format a14 heading "Mount|Status" +column mode_status format a14 heading "Mode|Status" +column repair_timer &&lnum heading "Repair|Timer" + +ttitle left "Check Status of the ASM Disk over all groups" skip 2 + +SELECT count(*) + , header_status + , mount_status + , mode_status + , state + , repair_timer + FROM v$asm_disk + group by header_status + , mount_status + , mode_status + , state + , repair_timer + order by mode_status ; + + +-- prompt ... +-- prompt ... Mount status of the disk : +-- prompt ... +-- prompt ... MISSING - Oracle ASM metadata indicates that the disk is known to be part of the Oracle ASM disk group but no disk in the storage system was found with the indicated name +-- prompt ... CLOSED - Disk is present in the storage system but is not being accessed by Oracle ASM +-- prompt ... OPENED - Disk is present in the storage system and is being accessed by Oracle ASM. This is the normal state for disks in a database instance which are part of a Disk Group being actively used by the instance. +-- prompt ... CACHED - Disk is present in the storage system and is part of a disk group being accessed by the Oracle ASM instance. This is the normal state for disks in an Oracle ASM instance which are part of a mounted disk group. +-- prompt ... IGNORED - Disk is present in the system but is ignored by Oracle ASM because of one of the following: +-- prompt ... The disk is detected by the system library but is ignored because an Oracle ASM library discovered the same disk +-- prompt ... Oracle ASM has determined that the membership claimed by the disk header is no longer valid +-- prompt ... CLOSING - Oracle ASM is in the process of closing this disk +-- +-- +-- +-- prompt ... +-- prompt ... Header status of the disk : +-- prompt ... +-- prompt ... UNKNOWN - Oracle ASM disk header has not been read +-- prompt ... CANDIDATE - Disk is not part of a disk group and may be added to a disk group with the ALTER DISKGROUP statement +-- prompt ... INCOMPATIBLE - Version number in the disk header is not compatible with the Oracle ASM software version +-- prompt ... PROVISIONED - Disk is not part of a disk group and may be added to a disk group with the ALTER DISKGROUP statement. The PROVISIONED header status is different from the CANDIDATE header status in that PROVISIONED implies that an additional platform-specific action has been taken by an administrator to make the disk available for Oracle ASM. +-- prompt ... MEMBER - Disk is a member of an existing disk group. No attempt should be made to add the disk to a different disk group. The ALTER DISKGROUP statement will reject such an addition unless overridden with the FORCE option. +-- prompt ... FORMER - Disk was once part of a disk group but has been dropped cleanly from the group. It may be added to a new disk group with the ALTER DISKGROUP statement. +-- prompt ... CONFLICT - Oracle ASM disk was not mounted due to a conflict +-- prompt ... FOREIGN - Disk contains data created by an Oracle product other than ASM. This includes datafiles, logfiles, and OCR disks. + + +prompt ... +prompt ... State of the disk : +prompt ... +prompt ... UNKNOWN - Oracle ASM disk state is not known (typically the disk is not mounted) +prompt ... NORMAL - Disk is online and operating normally +prompt ... ADDING - Disk is being added to a disk group, +prompt ... and is pending validation by all instances that have the disk group mounted +prompt ... DROPPING - Disk has been manually taken offline and space allocation or data access for the disk halts. +prompt ... Rebalancing will commence to relocate data off the disks to other disks in the disk group. +prompt ... Upon completion of the rebalance, the disk is expelled from the group. +prompt ... HUNG - Disk drop operation cannot continue because there is insufficient space +prompt ... to relocate the data from the disk being dropped +prompt ... FORCING - Disk is being removed from the disk group without attempting to offload its data. +prompt ... The data will be recovered from redundant copies, where possible. +prompt ... DROPPED - Disk has been fully expelled from the disk group + + + +ttitle left "Size all groups" skip 2 + +column disk_count_online format 9999 heading "Disk|on" +column disk_count_offine format 9999 heading "Disk|off" + +select g.group_number + , g.name + , g.state + , g.type + , g.total_mb Brutto + , decode(g.type,'NORMAL',g.total_mb/2,g.total_mb) Netto + , g.usable_file_mb as free_netto + , case when g.state !='DISMOUNTED' then + to_char(round(g.usable_file_mb/(decode(type,'NORMAL',g.total_mb/2,g.total_mb)/100),2),'00D99') + else 'n/a' + end as free_percent + , (select count(*) from v$asm_disk i where i.group_number=g.group_number and VOTING_FILE='Y') as disk_count_vot + , (select count(*) from v$asm_disk i where i.group_number=g.group_number and i.mode_status='ONLINE') as disk_count_online + , (select count(*) from v$asm_disk i where i.group_number=g.group_number and i.mode_status!='ONLINE') as disk_count_offine + from v$asm_diskgroup g +order by g.name +/ + +-- + +prompt ... +prompt ... State of the disk group: +prompt ... +prompt ... CONNECTED - Disk group is in use by the database instance +prompt ... BROKEN - Database instance lost connectivity to the Automatic Storage Management instance that mounted the disk group +prompt ... UNKNOWN - Automatic Storage Management instance has never attempted to mount the disk group +prompt ... DISMOUNTED - Disk group was cleanly dismounted by the Automatic Storage Management instance following a successful mount +prompt ... MOUNTED - Instance is successfully serving the disk group to its database clients +prompt ... QUIESCING - CRSCTL utility attempted to dismount a disk group that contains the Oracle Cluster Registry (OCR). +prompt ... +-- + +ttitle left "Check ASM Disk Size and Usage over all groups" skip 2 + +column Brutto format 999G999G999 heading "Size per|Disk MB" +column d_cnt format 999 heading "Count|Disk" +column max_used format 999G999G999 heading "Max per Disk|Used MB" +column min_used format 999G999G999 heading "Min per Disk|Used MB" +column oem_metric_imblance format 90D00 heading "OEM Disk|Imbalance" + +select g.group_number + , g.name + , d.total_mb Brutto + , max(d.total_mb-d.free_mb + (128*g.allocation_unit_size/1048576)) max_used + , min(d.total_mb-d.free_mb + (128*g.allocation_unit_size/1048576)) min_used + , count(d.DISK_NUMBER ) as d_cnt + , round(100*(max((d.total_mb-d.free_mb + (128*g.allocation_unit_size/1048576))/(d.total_mb + (128*g.allocation_unit_size/1048576)))-min((d.total_mb-d.free_mb + (128*g.allocation_unit_size/1048576))/(d.total_mb + (128*g.allocation_unit_size/1048576))))/max((d.total_mb-d.free_mb + (128*g.allocation_unit_size/1048576))/(d.total_mb + (128*g.allocation_unit_size/1048576))),2) as oem_metric_imblance +from v$asm_disk_stat d + ,v$asm_diskgroup_stat g + ,v$asm_operation op +where d.group_number = g.group_number + and g.group_number = op.group_number(+) + and d.group_number <> 0 + and d.state = 'NORMAL' + and d.mount_status = 'CACHED' +group by g.group_number,g.name,d.total_mb +order by g.name,d.total_mb +/ + +prompt ... +prompt ... if Max per Disk|Used MB and Min per Disk|Used MB are very different you may be need a "alter diskgroup xxxx rebalance power 5" +prompt ... + +ttitle off + + + + + + diff --git a/asm_failgroup.sql b/asm_failgroup.sql new file mode 100644 index 0000000..b012a88 --- /dev/null +++ b/asm_failgroup.sql @@ -0,0 +1,38 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script ASM Disk Overview +-- Date: 2016 +--============================================================================== +set linesize 130 pagesize 300 recsep off + +define DG_NAME = '&1' + +prompt +prompt Parameter 1 = Data Group Name => &&DG_NAME. +prompt + +column GROUP_NAME format A20 heading "Group|name" +column DISK_NAME format A20 heading "Disk|name" +column FAILGROUP format A30 heading "Failgroup|name" +column path format A30 heading "Disk|path" + +ttitle left "ASM Failgroups of a Diskgroup" skip 2 + +select g.name as group_name + , d.failgroup + , d.name as disk_name + , d.path + --, d.header_status + --, d.mount_status + , d.mode_status + from v$asm_disk d + inner join v$asm_diskgroup g on (g.group_number=d.group_number) +where g.name like upper ('&&DG_NAME') +order by d.name,d.FAILGROUP +/ + +ttitle off + +prompt ... to online / offline all disks in a failgroup +prompt ... ALTER diskgroup &&DG_NAME. online|offline disks in failgroup ; +prompt ... \ No newline at end of file diff --git a/asm_files.sql b/asm_files.sql new file mode 100644 index 0000000..8a48bae --- /dev/null +++ b/asm_files.sql @@ -0,0 +1,43 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: all files on an ASM disk group +--============================================================================== +set linesize 130 pagesize 300 + +define DG_NAME = '&1' + +prompt +prompt Parameter 1 = Data Group Name => &&DG_NAME. +prompt + +ttitle left "ASM Files on Disk group &&DG_NAME. " skip 2 + +column file_name format a30 heading "File|Name" +column file_number format 99999 heading "File|Nr" +column mb_bytes format 999G999G999 heading "File|MB" + +column DUMMY noprint; +compute sum of MB_BYTES on DUMMY; +break on DUMMY; + +select null dummy + , f.group_number + , f.file_number + , round ( f.bytes / 1024 / 1024, 2) as mb_bytes + , a.name as file_name + from v$asm_file f, v$asm_alias a, v$asm_diskgroup dg + where f.file_number = a.file_number + and f.group_number = a.group_number + and dg.group_number = f.group_number + and dg.name like upper ('&&DG_NAME') +order by f.file_number +/ + +ttitle off + +prompt ... +prompt to see all files NOT Opened: +prompt "Script to report the list of files stored in ASM and CURRENTLY NOT OPENED [ID 552082.1]" +prompt ... + +clear break diff --git a/asm_offline_failgroup.sql b/asm_offline_failgroup.sql new file mode 100644 index 0000000..6eca81d --- /dev/null +++ b/asm_offline_failgroup.sql @@ -0,0 +1,47 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script ASM Disk Overview +-- Date: 2016 +--============================================================================== +set linesize 130 pagesize 300 recsep off + +define DISK_NAME = '&1' + +prompt +prompt Parameter 1 = Data Group Name => &&DISK_NAME. +prompt + +column GROUP_NAME format A20 heading "Group|name" +column DISK_NAME format A20 heading "Disk|name" +column FAILGROUP format A30 heading "Failgroup|name" +column path format A30 heading "Disk|path" +column command format a125 + +ttitle left "ASM Offline all Disks of this Failgroups" skip 2 + +select 'ALTER diskgroup '|| g.name + ||' offline disks IN failgroup ' + || d.FAILGROUP + ||';' as command +from v$asm_disk d + inner join v$asm_diskgroup g on (g.group_number=d.group_number) +where d.path like upper ('%-_&&DISK_NAME.') ESCAPE '-' +group by d.FAILGROUP,g.name +; + +ttitle left "ASM online all Disks of this Failgroups" skip 2 +select 'ALTER diskgroup '|| g.name + ||' online disks IN failgroup ' + || d.FAILGROUP + ||';' +from v$asm_disk d + inner join v$asm_diskgroup g on (g.group_number=d.group_number) +where d.path like upper ('%-_&&DISK_NAME.') ESCAPE '-' +group by d.FAILGROUP,g.name +; + +ttitle off + +prompt ... to online / offline all disks in a failgroup +prompt ... ALTER diskgroup online|offline disks in failgroup ; +prompt ... \ No newline at end of file diff --git a/asm_online_failgroup.sql b/asm_online_failgroup.sql new file mode 100644 index 0000000..3d96630 --- /dev/null +++ b/asm_online_failgroup.sql @@ -0,0 +1,29 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script ASM Disk Overview +-- Date: 2016 +--============================================================================== +set linesize 130 pagesize 300 recsep off + +column command format a125 + +ttitle left "ASM online all Disks of Failgroups if Path is null" skip 2 + + +select 'ALTER diskgroup '|| g.name + ||' online disks IN failgroup ' + || d.FAILGROUP + ||';' as command +from v$asm_disk d + inner join v$asm_diskgroup g on (g.group_number=d.group_number) +where d.path is null +group by d.FAILGROUP,g.name +; + +ttitle off + +prompt ... to online / offline all disks in a failgroup +prompt ... ALTER diskgroup online|offline disks in failgroup ; +prompt ... +prompt ... check with @asm_rebalance the rebalance jobs +prompt ... diff --git a/asm_partner.sql b/asm_partner.sql new file mode 100644 index 0000000..528aa65 --- /dev/null +++ b/asm_partner.sql @@ -0,0 +1,65 @@ +-- ==================================================================== +-- GPI - Gunther Pippčrr +-- get Information about the partner disk if redundancy is <> external +-- +-- ==================================================================== +-- see also: +-- http://asmsupportguy.blogspot.de/2011/07/how-many-partners.html +-- http://afatkulin.blogspot.de/2010/07/asm-mirroring-and-disk-partnership.html +-- Script to Report the Percentage of Imbalance in all Mounted Diskgroups (Doc ID 367445.1) +--============================================================================== + +set linesize 130 pagesize 300 +set verify off + +prompt +prompt Parameter 1 = DISK_GROUP_NR => '&1' +prompt + +define DISK_GROUP_NR = '&1' + +ttitle left "Check for Imbalance over all disks" skip 2 + +select min(cnt), max(cnt),grp + from (select number_kfdpartner disk_number + , count(*) cnt + , grp + from x$kfdpartner + group by number_kfdpartner,grp) +group by grp +/ + +-- from the OEM Metric for Imbalance + +ttitle left "Check for OEM Metric for Imbalance over all disks of the group &&DISK_GROUP_NR." skip 2 + +select x.grp grp + , x.disk disk + , sum (x.active) cnt + , greatest (sum ( x.total_mb / d.total_mb),0.0001) pspace + , x.total_mb + , d.total_mb + , d.failgroup fgrp + from v$asm_disk_stat d + , (select y.grp grp + , y.disk disk + , z.total_mb * y.active_kfdpartner total_mb + , y.active_kfdpartner active + from x$kfdpartner y, v$asm_disk_stat z + where y.number_kfdpartner = z.disk_number + and y.grp = z.group_number + and y.grp = &&DISK_GROUP_NR.) x + where d.group_number = x.grp + and d.disk_number = x.disk + and d.group_number <> 0 + and d.state = 'NORMAL' + and d.mount_status = 'CACHED' +group by x.grp + , x.disk + , d.failgroup + , x.total_mb + , d.total_mb +/ + + +ttitle off \ No newline at end of file diff --git a/asm_rebalance.sql b/asm_rebalance.sql new file mode 100644 index 0000000..186887f --- /dev/null +++ b/asm_rebalance.sql @@ -0,0 +1,43 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script ASM Disk rebalance overview +-- Date: 2016 +--============================================================================== +set linesize 130 pagesize 300 recsep off + +column GROUP_NUMBER format 9999 heading "Group|Nr" +column GROUP_NAME format A10 heading "Group|name" + +column OPERATION format a5 heading "Oper" +column PASS format a10 heading "Pass" +column STATE format a4 heading "State" +column POWER format 999 heading "Po|wer" +column ACTUAL format 99999 +column SOFAR format 99999 +column EST_WORK format 99999 +column EST_RATE format 99999 +column EST_MINUTES format 99999 +column ERROR_CODE format A10 heading "Error|code" +column CON_ID format 99 + +ttitle left "ASM actual rebalance operations" skip 2 + +SELECT g.name as GROUP_NAME + , o.PASS + , o.STATE + , o.POWER + , o.ACTUAL + , o.SOFAR + , o.EST_MINUTES + , o.ERROR_CODE + FROM v$asm_operation o + inner join v$asm_diskgroup g on (g.group_number=o.group_number) +order by g.name +/ + +ttitle off + +prompt .... if possible use more threads to resync +prompt .... ALTER diskgroup vot rebalance POWER 9 + +prompt diff --git a/audit.sql b/audit.sql new file mode 100644 index 0000000..b34f25e --- /dev/null +++ b/audit.sql @@ -0,0 +1,166 @@ +-- ============================================================================== +-- GPI - Gunther Pippèrr +-- Desc : Get the audit settings of the database +-- +-- Must be run with dba privileges +-- see also for the source of some of the commands +-- https://oracle-base.com/articles/11g/auditing-enhancements-11gr2#initializing_the_management_infrastructure +-- ============================================================================== + +set linesize 130 pagesize 300 + +ttitle left "Audit settings -- init.ora " skip 2 + +show parameter audit + +ttitle left "Audit Settings -- Parameters " skip 2 + +column parameter_name format a30 +column parameter_value format a20 +column audit_trail format a20 + +select parameter_name + , parameter_value + , audit_trail + from dba_audit_mgmt_config_params +order by 1 +/ + +ttitle left "Audit Settings -- Audit objects" skip 2 + +column audit_option format a30 +column success format a12 +column failure format a12 + +select audit_option + , success,failure + from dba_stmt_audit_opts + order by 1 +/ + + +---------------- +---------------- + +column PARAMETER_NAME format a40 +column PARAMETER_VALUE format a30 +column AUDIT_TRAIL format a20 + + +ttitle left "Audit Settings -- Parameter of the normal Auditing" skip 2 + +SELECT PARAMETER_NAME + , PARAMETER_VALUE + , AUDIT_TRAIL + FROM dba_audit_mgmt_config_params +order by 1 +/ + +ttitle left "Audit Settings -- Cleanup Jobs" skip 2 + + + +column JOB_NAME format a24 heading "JOB|NAME" +column JOB_STATUS format a10 heading "JOB|STATUS" +column AUDIT_TRAIL format a20 heading "AUDIT|TRAIL" +column JOB_FREQUENCY format a30 heading "JOB|FREQUENCY" +column USE_LAST_ARCHIVE_TIMESTAMP format a10 heading "LAST | TIMESTAMP" +column JOB_CONTAINER format a20 heading "JOB|CONTAINER" + +select JOB_NAME + , JOB_STATUS + , AUDIT_TRAIL + , JOB_FREQUENCY + , USE_LAST_ARCHIVE_TIMESTAMP + , JOB_CONTAINER + from DBA_AUDIT_MGMT_CLEANUP_JOBS +/ + + +ttitle left "Audit Settings -- delete older Audits then " skip 2 + +COLUMN RAC_INSTANCE format 999 heading "RAC|Inst" +COLUMN audit_trail FORMAT A20 heading "Audit|Trail" +COLUMN last_archive_ts FORMAT A40 heading "Last Archive|TS" + +SELECT RAC_INSTANCE + , AUDIT_TRAIL + , LAST_ARCHIVE_TS + FROM dba_audit_mgmt_last_arch_ts +order by 1,2 +/ + +prompt -- AUDIT_TRAIL_TYPE: The audit trail whose timestamp is to be set (Constants) +prompt -- LAST_ARCHIVE_TIME: Records or files older than this time will be deleted. +prompt -- if empty not set! +prompt -- to set use + +DOC +------------------------------- + +BEGIN + DBMS_AUDIT_MGMT.set_last_archive_timestamp( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_AUD_STD + , last_archive_time => SYSTIMESTAMP-15); +END; +/ + +------------------------------- +# + + +ttitle off + +set serveroutput on + +BEGIN + DBMS_OUTPUT.put_line(' -------------------------------------------- '); + DBMS_OUTPUT.put_line('-- Info - Check if the clean job for the audit Log is enabled'); + + IF DBMS_AUDIT_MGMT.is_cleanup_initialized(DBMS_AUDIT_MGMT.AUDIT_TRAIL_AUD_STD) THEN + DBMS_OUTPUT.put_line('-- Info - Cleaning job is enabled => !!! YES !!!'); + ELSE + DBMS_OUTPUT.put_line('-- Info - Cleaning job is not enabled => !!! NO !!!'); + END IF; + + DBMS_OUTPUT.put_line(' -------------------------------------------- '); +END; +/ + +------ +DOC +------------------------------------------------------------------------------- +-- to enable the delete of the logs use: + +BEGIN + DBMS_AUDIT_MGMT.init_cleanup( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_ALL + , default_cleanup_interval => 24 /* hours */); +END; +/ + +to disable use + +BEGIN + DBMS_AUDIT_MGMT.deinit_cleanup( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_ALL); +END; +/ + +-- create Job for this Task +BEGIN +DBMS_AUDIT_MGMT.create_purge_job( + audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_ALL + , audit_trail_purge_interval => 12 /* hours */ + , audit_trail_purge_name => 'CLEANUP_AUDIT_TRAIL_ALL' + , use_last_arch_timestamp => TRUE); +END; +/ + + +------------------------------------------------------------------------------- +# + +--DBA_AUDIT_OBJECT + + diff --git a/audit_failed_login.sql b/audit_failed_login.sql new file mode 100644 index 0000000..db0f974 --- /dev/null +++ b/audit_failed_login.sql @@ -0,0 +1,38 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Query the audit log entries for failed logins in the last 24 hours +-- +-- Must be run with dba privileges +--============================================================================== +set linesize 130 pagesize 300 + + +column username format a20 heading "DB User|name" +column os_username format a16 heading "User |Name" +column userhost format a20 heading "User |Host" +column terminal format a20 heading "User |Terminal" +column timestamp format a18 heading "User |Login at" +column returncode format 9999 heading "Ora |Error" + +ttitle left "Failed Logins to this DB in last 24h hours" skip 2 + +select os_username + , username + , terminal + , userhost + , returncode + , to_char(timestamp,'dd.mm.yyyy hh24:mi') as timestamp +from dba_audit_trail + where ( returncode=1017 OR returncode=28000) + and timestamp > sysdate-1 +order by timestamp +/ + +prompt -- ---------------------------------- + +prompt Ora-Error 1017 - Wrong Password +prompt Ora-Error 28000 - Account was locked + +prompt -- ---------------------------------- + +ttitle off \ No newline at end of file diff --git a/audit_login.sql b/audit_login.sql new file mode 100644 index 0000000..a34ed3e --- /dev/null +++ b/audit_login.sql @@ -0,0 +1,94 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Query the audit log entries for logins +-- +-- Must be run with dba privileges +--============================================================================== +set linesize 130 pagesize 300 + +define DB_USER_NAME = &1 + + +prompt +prompt Parameter 1 = DB_USER_NAME => &&DB_USER_NAME. +prompt + + +column username format a20 heading "DB User|name" +column action_name format a25 heading "Action|name" +column first_log format a25 heading "First|entry" +column last_log format a25 heading "Last|entry" +column entries format 999G999G999 heading "Audit|entries" +column action_count format 999G9999 heading "Action|Count" +column os_username format a16 heading "User|Name" +column userhost format a20 heading "User |Host" +column timestamp format a18 heading "Time" +column CLIENT_ID format a18 heading "DB User|Client Id" + + +ttitle left "Audit log summary Logins last 12 hours " skip 2 + + select -- to_char(extended_timestamp,'dd.mm hh24') + to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' as timestamp + , instance_number + , count (*) as action_count + --, username + , action_name + , userhost + , CLIENT_ID + from dba_audit_trail + where extended_timestamp between sysdate - ( 1 / 4) and sysdate + and action_name like 'LOGOFF%' +-- and username like '&&DB_USER_NAME.' +-- and USERHOST='xxxxxx' +-- and extended_timestamp between to_date('14.11.2014 08:00','dd.mm.yyyy hh24:mi') and to_date('14.11.2014 09:00','dd.mm.yyyy hh24:mi') +group by -- username + --, + -- to_char(extended_timestamp,'dd.mm hh24') + to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' + , action_name + , userhost + , instance_number + , CLIENT_ID +order by to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' + +-- to_char(extended_timestamp,'dd.mm hh24') --,username +/ + + +break on instance_number +compute sum of action_count on instance_number + +ttitle left "Audit log summary Logins last 12 hours over 10 minutes " skip 2 + + select to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' as timestamp + , instance_number + , count (*) as action_count + , username + , os_username + , action_name + from dba_audit_trail + where extended_timestamp between sysdate - ( 1/ 4) and sysdate + and action_name like 'LOGOFF%' +-- and username like '&&DB_USER_NAME.' +-- and USERHOST='srvgpidb01' +-- and instance_number=2 +-- and extended_timestamp between to_date('14.11.2014 08:00','dd.mm.yyyy hh24:mi') and to_date('14.11.2014 09:00','dd.mm.yyyy hh24:mi') +group by to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' + , instance_number + , username + , os_username + , action_name +order by to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0', username +/ + + + +clear break +clear computes + + +prompt +prompt + +ttitle off \ No newline at end of file diff --git a/audit_logoff_cleanup.sql b/audit_logoff_cleanup.sql new file mode 100644 index 0000000..fcd31a8 --- /dev/null +++ b/audit_logoff_cleanup.sql @@ -0,0 +1,43 @@ +--====== ======================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Query the audit log entries for LOGOFF BY CLEANUP events +-- +-- Must be run with dba privileges +--============================================================================== +set linesize 130 pagesize 300 + + +column username format a20 heading "DB User|name" +column action_name format a25 heading "Action|name" +column first_log format a25 heading "First|entry" +column last_log format a25 heading "Last|entry" +column entries format 999G999G999 heading "Audit|entries" +column action_count format 999G9999 heading "Action|Count" +column os_username format a16 heading "User|Name" +column userhost format a20 heading "User |Host" +column timestamp format a23 heading "Time" +column CLIENT_ID format a18 heading "DB User|Client Id" + + +ttitle left "Audit log Clean Up Entries order by time desc" skip 2 + + select + to_char (extended_timestamp, 'dd.mm hh24:mi:ss') as timestamp + , instance_number + , username + , action_name + , userhost + , CLIENT_ID + from dba_audit_trail + where extended_timestamp between sysdate - ( 1 / 4) and sysdate + and action_name like 'LOGOFF BY CLEANUP' +order by extended_timestamp desc +/ + + + +prompt +prompt + +ttitle off + diff --git a/audit_rep.sql b/audit_rep.sql new file mode 100644 index 0000000..2e29d1f --- /dev/null +++ b/audit_rep.sql @@ -0,0 +1,148 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: HTML Report for the entries in the audit log +-- see : http://www.pipperr.de/dokuwiki/doku.php?id=dba:index_column_usage +-- Date: September 2013 +-- +--============================================================================== +/* +Timeformat differences between audit$ and audit trail! +select + ntimestamp#, + from_tz(ntimestamp#,'UTC') at local, + from_tz(ntimestamp#,'UTC') at time zone 'Europe/Berlin' +from sys.aud$; +*/ + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_audit_log.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + +set verify off +SET linesize 250 pagesize 2000 + +spool &&SPOOL_NAME + + +set markup html on + +ttitle left "Audit Log entries " skip 2 + +column username format a10 heading "DB User|name" +column action_name format a25 heading "Action|name" +column first_log format a25 heading "First|entry" +column last_log format a25 heading "Last|entry" + + +select os_username + , username + , userhost + , terminal + , to_char(timestamp,'dd.mm.yyyy hh24:mi:ss') as timestamp + , owner + , obj_name + ,action_name + ,new_owner + ,new_name +--,ses_actions + ,comment_text + ,sessionid +--,entryid +--,statementid +--,returncode +--,priv_used +--,client_id +-- ,econtext_id +-- ,session_cpu +-- ,extended_timestamp +-- ,proxy_sessionid + --,global_uid + --,instance_number + --,os_process + --,transactionid + --,scn +-- ,sql_bind + ,sql_text +-- ,obj_edition_name + from dba_audit_object +where timestamp between sysdate- 1 and sysdate +order by timestamp +/ +ttitle left "Audit log summary Login/Logoff last 12 hours " skip 2 + +select to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' + , instance_number + , count (*) as action_count + , username + , action_name + , userhost + , CLIENT_ID + from dba_audit_trail + where extended_timestamp between sysdate - ( 1 / 4) and sysdate + and action_name like 'LOG%' +group by -- username + to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' + , username + , action_name + , userhost + , instance_number + , CLIENT_ID +order by to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' +/ + + +break on instance_number +compute sum of action_count on instance_number + +ttitle left "Audit log summary Login/Logoff last 12 hours over 10 minutes " skip 2 + + select to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' + , instance_number + , count (*) as action_count + , username + , os_username + , action_name + from dba_audit_trail + where extended_timestamp between sysdate - ( 1/ 4) and sysdate + and action_name like 'LOG%' +group by to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' + , instance_number + , username + , os_username + , action_name +order by to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0', username +/ + + + +clear break +clear computes + + + +ttitle left "Audit log summary last 12 hours " skip 2 + select -- to_char(extended_timestamp,'dd.mm hh24') + to_char (extended_timestamp, 'dd.mm hh24') || ':' || substr (to_char (extended_timestamp, 'mi'), 1, 1) || '0' + , instance_number + , username + , action_name + , userhost + , CLIENT_ID + , action_name + from dba_audit_trail + where extended_timestamp between sysdate - ( 1 / 2) and sysdate + order by extended_timestamp +/ + +set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window +host &&SPOOL_NAME diff --git a/audit_sum.sql b/audit_sum.sql new file mode 100644 index 0000000..252e927 --- /dev/null +++ b/audit_sum.sql @@ -0,0 +1,86 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Query the audit log entries +-- +-- Must be run with dba privileges +-- +--============================================================================== +set linesize 130 pagesize 300 + +column username format a20 heading "DB User|name" +column action_name format a25 heading "Action|name" +column first_log format a25 heading "First|entry" +column last_log format a25 heading "Last|entry" +column entries format 999G999G999 heading "Audit|entries" + +ttitle left "Audit Trail from time until time" skip 2 + +select to_char(min(timestamp),'dd.mm.yyyy hh24:mi:ss') as first_log + , to_char(max(timestamp),'dd.mm.yyyy hh24:mi:ss') as last_log + , count(*) as entries + from dba_audit_trail +order by 1 +/ + + +ttitle left "Audit Object Log entries " skip 2 + +select username + , action_name + , count(*) as entries + , to_char(min(timestamp),'dd.mm.yyyy hh24:mi:ss') as first_log + , to_char(max(timestamp),'dd.mm.yyyy hh24:mi:ss') as last_log + from dba_audit_object +group by username,action_name +order by 1 +/ + + +--------------------- Details ---------------------------- + +column action_count format 9G999G999 heading "Action|Count" +column os_username format a16 heading "User|Name" +column username format a15 heading "DB User|name" +column action_name format a20 heading "Action|name" +column instance_number format 99 heading "In|st" +column user_host format a11 heading "User|Host" +column first_log format a15 heading "First|entry" +column last_log format a15 heading "Last|entry" + +break on instance_number +--COMPUTE SUM OF action_count ON first_log + + +ttitle left "Audit log summary overview " skip 2 + +select count(*) as action_count + , os_username + , (case when length(USERHOST) > 10 then '...'||substr(USERHOST,-8,10) else USERHOST end) as user_host + , username + , instance_number + , to_char(min(extended_timestamp),'dd.mm hh24:mi') as first_log + , to_char(max(extended_timestamp),'dd.mm hh24:mi') as last_log + , action_name + from dba_audit_trail + where extended_timestamp between sysdate -(1/4) and sysdate + -- username='GPI' + -- extended_timestamp between to_date('13.11.2014 12:19','dd.mm.yyyy hh24:mi') and to_date('13.11.2014 12:21','dd.mm.yyyy hh24:mi') + -- and USERHOST='---' + group by os_username + , (case when length(USERHOST) > 10 then '...'||substr(USERHOST,-8,10) else USERHOST end) + , username + , action_name + , instance_number +order by instance_number,username,action_name + / + + +clear break +clear computes + +prompt +prompt ... for detail information call: "audit_rep.sql" +prompt ... for the space usage of the audit$ table call: "tab_space.sql aud$" +prompt + +ttitle off diff --git a/awr.sql b/awr.sql new file mode 100644 index 0000000..4c2b792 --- /dev/null +++ b/awr.sql @@ -0,0 +1,73 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: Analyse the SYSAUX Table space and AWR Repository +-- Date: 08.2013 +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +set linesize 130 pagesize 300 + +--- +@space_tablespace.sql SYSAUX +-- + + +ttitle left "AWR Snapshots count" skip 2 +column snapshot_count format 999999 heading "Snapshot Count" + +select count(*) as snapshot_count from sys.wrm$_snapshot +/ + +ttitle left "AWR Snapshots time frame" skip 2 +column snap_id format 999999 heading "Snap|Id" +column start_time format a21 heading "Start|time" +column end_time format a21 heading "End|time" + + +select snap_id + , to_char(begin_interval_time,'dd.mm.yyyy hh24:mi:ss') as start_time + , to_char(end_interval_time ,'dd.mm.yyyy hh24:mi:ss') as end_time + from sys.wrm$_snapshot +where ( + snap_id = ( select min (snap_id) from sys.wrm$_snapshot) + or snap_id = ( select max(snap_id) from sys.wrm$_snapshot) + ) +order by snap_id asc +/ + + +ttitle left "AWR Usage Overview" skip 2 + +column occupant_name format a25 +column schema_name format a18 +column move_procedure format a40 +column space_usage format 9G999G999 heading "Space | Usage (M)" + +select occupant_name + , round( space_usage_kbytes/1024) as space_usage + , schema_name + , move_procedure + from v$sysaux_occupants + where space_usage_kbytes > 1 +order by 2 desc +/ + + +DOC +------------------------------------------------------------------------------- + to drop some snapshots from the repostitory you can use this command: + begin + dbms_workload_repository.drop_snapshot_range( low_snap_id => + , high_snap_id => ); + end; + / + + To get more Information you can use also @?/rdbms/admin/awrinfo.sql + +------------------------------------------------------------------------------- +# + +ttitle off diff --git a/awr_act_active_sessions.sql b/awr_act_active_sessions.sql new file mode 100644 index 0000000..3263d68 --- /dev/null +++ b/awr_act_active_sessions.sql @@ -0,0 +1,125 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the statistic information over a the active sessions of a DB user +-- +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +set linesize 130 pagesize 300 + +define DB_USER_NAME='&1' +define SERVICE_NAME='%' + +prompt +prompt Parameter 1 = DB_USER_NAME => &&DB_USER_NAME. +prompt Parameter 2 = SERVICE_NAME => &&SERVICE_NAME. +prompt + + + +column username format a10 +column user_id format 9999999 +column SESSION_ID format 9999999 +column inst_id format 99 +column SQL_ID format a15 +column last_sample_id format 99999999999 +column SAMPLE_TIME format a18 +column serial format 999999 +column SQL_EXEC_START format a18 +column SQL_EXEC_ID format 9999999999 + + +ttitle "SQL Summary" skip 2 + +select count(*) + ,u.username + ,ah.user_id + ,ah.SESSION_ID + ,ah.inst_id + ,ah.SQL_ID + ,max(SAMPLE_ID) as last_sample_id + ,to_char(max(SAMPLE_TIME),'dd.mm.yyyy hh24:mi') as SAMPLE_TIME + ,ah.SESSION_SERIAL# as serial + ,ah.SQL_EXEC_START + from GV$ACTIVE_SESSION_HISTORY ah + ,GV$ACTIVE_SERVICES ass + ,dba_users u + where ass.inst_id = ah.inst_id + and ass.NAME_HASH = ah.SERVICE_HASH + --and ass.name like '%&&SERVICE_NAME.%' + and u.username like '%&&DB_USER_NAME.%' + and u.user_id = ah.user_id + and ah.SAMPLE_TIME > (sysdate - ((1 / (24 * 60)) * 60)) + group by u.username + ,ah.user_id + ,ah.SESSION_ID + ,ah.inst_id + ,ah.SQL_ID + ,ah.SESSION_SERIAL# + ,ah.SQL_EXEC_ID + ,ah.SQL_EXEC_START +--having count(*) > 25 * 60 + order by max(SAMPLE_ID) desc +/ + +ttitle "Summary" skip 2 + + +select count(*) + ,u.username + ,ah.inst_id + ,ah.SESSION_ID + ,ah.WAIT_CLASS + ,max(SAMPLE_ID) as last_sample_id + ,to_char(SAMPLE_TIME,'dd.mm.yyyy hh24:mi') as SAMPLE_TIME + from GV$ACTIVE_SESSION_HISTORY ah + ,GV$ACTIVE_SERVICES ass + ,dba_users u + where ass.inst_id = ah.inst_id + and ass.NAME_HASH = ah.SERVICE_HASH + --and ass.name like '%&&SERVICE_NAME.%' + and u.username like '%&&DB_USER_NAME.%' + and u.user_id = ah.user_id + and ah.SAMPLE_TIME > (sysdate - ((1 / (24 * 60)) * 60)) + group by u.username + ,ah.inst_id + ,ah.SESSION_ID + ,ah.WAIT_CLASS + , to_char(SAMPLE_TIME,'dd.mm.yyyy hh24:mi') +--having count(*) > 25 * 60 + order by max(SAMPLE_ID) desc +/ + +ttitle "Summary only sessions" skip 2 + +select count(*), username,SAMPLE_TIME from ( +select count(*) + ,u.username + ,ah.inst_id + ,ah.SESSION_ID + ,max(SAMPLE_ID) as last_sample_id + ,to_char(SAMPLE_TIME,'dd.mm.yyyy hh24:mi') as SAMPLE_TIME + from GV$ACTIVE_SESSION_HISTORY ah + ,GV$ACTIVE_SERVICES ass + ,dba_users u + where ass.inst_id = ah.inst_id + and ass.NAME_HASH = ah.SERVICE_HASH + --and ass.name like '%&&SERVICE_NAME.%' + and u.username like '%&&DB_USER_NAME.%' + and u.user_id = ah.user_id + and ah.SAMPLE_TIME > (sysdate - ((1 / (24 * 60)) * 60)) + group by u.username + ,ah.inst_id + ,ah.SESSION_ID + , to_char(SAMPLE_TIME,'dd.mm.yyyy hh24:mi') +--having count(*) > 25 * 60 + order by max(SAMPLE_ID) desc +) +group by username,SAMPLE_TIME +order by SAMPLE_TIME +/ + +ttitle off \ No newline at end of file diff --git a/awr_act_blocking_sessions.sql b/awr_act_blocking_sessions.sql new file mode 100644 index 0000000..5802f50 --- /dev/null +++ b/awr_act_blocking_sessions.sql @@ -0,0 +1,128 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get Information about the last blocking sessions +-- +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +set linesize 130 pagesize 300 +define SNAPTIME=10 + +prompt +prompt Snaptime => &&SNAPTIME. +prompt + + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_blocking_sessions_last_&&SNAPTIME._minutes.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + +spool &&SPOOL_NAME + +set markup html on + +column username format a10 +column user_id format 9999999 +column SESSION_ID format 9999999 +column inst_id format 99 +column SQL_ID format a15 +column last_sample_id format 99999999999 +column SAMPLE_TIME format a18 +column serial format 999999 +column SQL_EXEC_START format a18 heading "SQL|Start at" +column BLOCKING_SESSION_STATUS format a10 heading "Block Se|Status" +column BLOCKING_SESSION format 999999 heading "Block|Session" +column BLOCKING_INST_ID format 999 heading "Block|Inst" + + +ttitle "Get all sessions blocked by this Sessions" skip 2 + +set verify off +SET linesize 130 pagesize 4000 + +select count(*) + ,u.username + ,ah.user_id + ,ah.SESSION_ID + ,ah.inst_id + ,ah.SQL_ID + ,max(SAMPLE_ID) as last_sample_id + ,min(SAMPLE_ID) as frist_sample_id + ,to_char(max(SAMPLE_TIME),'dd.mm.yyyy hh24:mi') as MAX_SAMPLE_TIME + ,to_char(min(SAMPLE_TIME),'dd.mm.yyyy hh24:mi') as MIN_SAMPLE_TIME + ,ah.SESSION_SERIAL# as serial + ,ah.SQL_EXEC_START + ,ah.BLOCKING_SESSION_STATUS + ,ah.BLOCKING_SESSION + ,ah.BLOCKING_INST_ID + from GV$ACTIVE_SESSION_HISTORY ah + ,GV$ACTIVE_SERVICES ass + ,dba_users u + where ass.inst_id = ah.inst_id + and ass.NAME_HASH = ah.SERVICE_HASH + and ah.BLOCKING_SESSION is not null + and u.user_id = ah.user_id + and ah.SAMPLE_TIME > (sysdate - ((1 / (24 * 60)) * &SNAPTIME.)) + group by u.username + ,ah.user_id + ,ah.SESSION_ID + ,ah.inst_id + ,ah.SQL_ID + ,ah.SESSION_SERIAL# + ,ah.SQL_EXEC_START + ,ah.BLOCKING_SESSION_STATUS + ,ah.BLOCKING_SESSION + ,ah.BLOCKING_INST_ID +order by max(SAMPLE_ID) desc +/ + + +---------- Join with the sample id to the get the blocking session + +ttitle "Get all sessions for this BLOCK_SESSION ID'd in the blocking time period" skip 2 + +select u.username + ,ah.user_id + ,ah.SESSION_ID Blocker_Session + ,ah.inst_id + ,blocker.SESSION_ID blocked_Session + ,blocker.SESSION_ID blocked_Session_instance + ,blocker.SQL_ID blocked_sql + ,ah.PROGRAM + ,ah.SQL_ID + ,ah.SAMPLE_ID as sample_id + ,to_char(ah.SAMPLE_TIME,'dd.mm.yyyy hh24:mi') as SAMPLE_TIME + ,ah.SESSION_SERIAL# as serial + ,ah.SQL_EXEC_START + from GV$ACTIVE_SESSION_HISTORY ah + ,GV$ACTIVE_SERVICES ass + ,GV$ACTIVE_SESSION_HISTORY blocker + ,dba_users u + where ass.inst_id = ah.inst_id + and ass.NAME_HASH = ah.SERVICE_HASH + and ah.SAMPLE_ID =blocker.SAMPLE_ID + and ah.SESSION_ID =blocker.BLOCKING_SESSION + and u.user_id = ah.user_id + and ah.inst_id=blocker.inst_id + and ah.SAMPLE_TIME=blocker.SAMPLE_TIME + and ah.SAMPLE_TIME > (sysdate - ((1 / (24 * 60)) * &SNAPTIME.)) + order by ah.SAMPLE_ID desc +/ + +ttitle off + +set markup html off +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window + +host &&SPOOL_NAME \ No newline at end of file diff --git a/awr_ash_top_sql.sql b/awr_ash_top_sql.sql new file mode 100644 index 0000000..7e061e9 --- /dev/null +++ b/awr_ash_top_sql.sql @@ -0,0 +1,57 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the statistic information over a the active sessions of a DB user +-- see +-- http://www.oracle.com/technetwork/database/manageability/ppt-active-session-history-129612.pdf +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +set linesize 130 pagesize 300 + +define MINUTES_SINCE="( 1/24/60 * 120)" + +-- top sql +select sql_id + , count(*) + , round(count(*)/sum(count(*)) over (), 2) pctload + from v$active_session_history + where sample_time > sysdate - &&MINUTES_SINCE + and session_type <> 'BACKGROUND' + group by sql_id +order by count(*) desc +/ + +-- top io sql + +select ash.sql_id + , count(*) + from v$active_session_history ash + , v$event_name evt +where ash.sample_time > sysdate - &&MINUTES_SINCE + and ash.session_state = 'WAITING' + and ash.event_id = evt.event_id + and evt.wait_class = 'User I/O' +group by sql_id +order by count(*) desc +/ + + +-- top cpu sql + +select ash.sql_id + , count(*) + ,evt.wait_class + from v$active_session_history ash + , v$event_name evt +where ash.sample_time > sysdate - &&MINUTES_SINCE + --and ash.session_state = 'WAITING' + and ash.event_id = evt.event_id + --and evt.wait_class like '%CPU%' +group by sql_id,evt.wait_class +order by count(*) desc +/ + + diff --git a/awr_call_ash_report.sql b/awr_call_ash_report.sql new file mode 100644 index 0000000..65facbb --- /dev/null +++ b/awr_call_ash_report.sql @@ -0,0 +1,96 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: create ASH report from sql*Plus +-- Date: 10.2015 +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +-- ===== +-- get the spoolfile name and instance_number + DB ID +-- ===== +set feedback off +set heading off +set termout off + +column spool_name_col new_val spool_name +column instance_number new_val inst_nr +column aktdbid new_val databaseid + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_ash_report.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL + ,SYS_CONTEXT('USERENV','INSTANCE') as instance_number + FROM dual +/ + +select dbid as aktdbid + from v$database +/ + +set feedback on +set heading on +set termout on + +-- ===== +-- ask for the Start and endtime of the report +-- ===== +set verify off + +SET linesize 120 pagesize 300 + +define TIME_FORMAT='dd.mm.yyyy hh24:mi' + +column min_start_time format a18 heading "Early Start|Date" +column max_start_time format a18 heading "Latest Start|Date" + +ttitle left "Overview over the possible timeframe to get an ash report " skip 2 + +select to_char(min(s.sample_time),'&&TIME_FORMAT') as min_start_time + , to_char(max(s.sample_time),'&&TIME_FORMAT') as max_start_time + from dba_hist_active_sess_history s + where dbid = &&databaseid + and instance_number = &&inst_nr +/ + +-- +-- fix and snap_id in (... ) like seelect min(snap_id), max(snap_id) from dba_hist_snapshot where dbid = s.dbid and instance_number = s.inst_num ) +-- +ttitle off + +accept l_btime date prompt 'Enter start time (format &&TIME_FORMAT): ' +accept l_etime date prompt 'Enter end time (format &&TIME_FORMAT): ' + + +-- ===== +-- create the ASH Report +-- ===== + + +SET linesize 500 pagesize 9000 +set long 64000 +set feedback off +set heading off + +spool &&SPOOL_NAME + +select * + from table(sys.dbms_workload_repository.ash_report_html( &&databaseid + , &&inst_nr + , to_date('&&l_btime','&&TIME_FORMAT') + , to_date('&&l_etime','&&TIME_FORMAT') + ) + ) +/ + +spool off +set heading on +set feedback on + +prompt ... check the created report &&SPOOL_NAME + +host &&SPOOL_NAME + +set linesize 130 pagesize 300 \ No newline at end of file diff --git a/awr_call_awr_report.sql b/awr_call_awr_report.sql new file mode 100644 index 0000000..6acb141 --- /dev/null +++ b/awr_call_awr_report.sql @@ -0,0 +1,72 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: create AWR report from sql*Plus +-- Date: 10.2015 +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +column end_interval_time format a18 heading "End Interval|Time" +break on dbid + +ttitle left "Overview over the snapshots in the last days" skip 2 + +select dbid + , instance_number + , snap_id + , to_char(end_interval_time,'hh24:mi dd.mm.yyyy') as end_interval_time + from dba_hist_snapshot + where end_interval_time > trunc(sysdate-1) +order by snap_id, instance_number +/ + +clear break +ttitle off + + +set feedback off +set heading off +set termout off + +column spool_name_col new_val spool_name +column instance_number new_val inst_nr +column aktdbid new_val databaseid + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_awr_report.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL + ,SYS_CONTEXT('USERENV','INSTANCE') as instance_number + FROM dual +/ + +select dbid as aktdbid + from v$database +/ + +set feedback on +set heading on +set termout on + +set verify off +SET linesize 500 pagesize 9000 +set long 64000 + +accept snapshot_id_begin number prompt 'Enter Frist Snapshot Begin ID : ' +accept snapshot_id_end number prompt 'Enter Snapshot End Id to compare : ' + +set heading off +set feedback off +spool &&SPOOL_NAME + +select * from table(sys.dbms_workload_repository.awr_report_html(&&databaseid,&&inst_nr,&&snapshot_id_begin,&&snapshot_id_end)); + +spool off +set heading on +set feedback on + +prompt ... check the created report &&SPOOL_NAME + +host &&SPOOL_NAME + +set linesize 130 pagesize 300 \ No newline at end of file diff --git a/awr_call_sqlmonitor_report.sql b/awr_call_sqlmonitor_report.sql new file mode 100644 index 0000000..71b3c23 --- /dev/null +++ b/awr_call_sqlmonitor_report.sql @@ -0,0 +1,44 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: create AWR report from sql*Plus +-- Date: 10.2015 +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +set feedback off +set heading off +set termout off + +column spool_name_col new_val spool_name +column instance_number new_val inst_nr + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_sqlmonitor_report.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL + ,SYS_CONTEXT('USERENV','INSTANCE') as instance_number +FROM dual +/ + +set feedback on +set heading on +set termout on + +set trimspool on +set trim on +set pages 0 +set linesize 1000 +set long 1000000 +set longchunksize 1000000 +spool &&SPOOL_NAME + +--11g! + +select dbms_sqltune.report_sql_monitor(type=> 'active') from dual +/ + +spool off + +prompt ... check the created report &&SPOOL_NAME diff --git a/awr_changed_plans.sql b/awr_changed_plans.sql new file mode 100644 index 0000000..387f2c5 --- /dev/null +++ b/awr_changed_plans.sql @@ -0,0 +1,79 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc : search for changed plans in a time period - parameter 1 - Startdate - parameter 2 end date in DE format +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 300 + +define START_SNAP='&1' +define END_SNAP ='&2' + +prompt +prompt ... time format must be "dd.mm.yyyy hh24:mi" +prompt +prompt Parameter 1 = START_SNAP => &&START_SNAP. +prompt Parameter 2 = END_SNAP => &&END_SNAP. +prompt + + +set pagesize 1000 +set linesize 250 +set verify off + +column end_interval_time format a18 heading "Snap | End" +column begin_interval_time format a18 heading "Snap | Begin" +column plan_hash_value format 9999999999 heading "Plan | Hash" +column execution_time_max format 999G999G999G999D99 heading "Max Execution Time|per SQL" +column execution_time_min format 999G999G999G999D99 heading "Min Execution Time|per SQL" +column snapshot_count format 999999 heading "Snap|Cnt" +column instance_number format 99 heading "In|st" +column parsing_schema_name format a20 heading "Parsing|Schema" +column hash_list format a60 +column user_list format a40 + +select * + from ( select --instance_number + --, + -- parsing_schema_name + -- , + sql_id + , listagg (to_char (plan_hash_value), ':') within group (order by sql_id) as hash_list + , listagg (to_char (parsing_schema_name), ':') within group (order by sql_id) as user_list + , sum (sqlrang) as sqlrang + from ( select --ss.instance_number + -- , + ss.sql_id + , ss.plan_hash_value + -- , to_char(min(s.begin_interval_time),'dd.mm.yyyy hh24:mi') as begin_interval_time + -- , to_char(max(s.begin_interval_time),'dd.mm.yyyy hh24:mi') as end_interval_time + -- , min(case when ss.executions_delta = 0 then -1 else ss.elapsed_time_delta/ss.executions_delta end ) as execution_time_min + -- , max(case when ss.executions_delta = 0 then -1 else ss.elapsed_time_delta/ss.executions_delta end ) as execution_time_max + -- , count(*) snapshot_count + , row_number () over (partition by sql_id order by plan_hash_value) sqlrang + , ss.parsing_schema_name + from dba_hist_sqlstat ss, dba_hist_snapshot s + where s.snap_id = ss.snap_id + and ss.instance_number = s.instance_number + and s.begin_interval_time between to_date ('&&START_SNAP', 'dd.mm.yyyy hh24:mi') + and to_date ('&&END_SNAP', 'dd.mm.yyyy hh24:mi') + and ss.parsing_schema_name not in ('SYS', 'DBSNMP') + group by -- ss.instance_number + --, + ss.sql_id, ss.plan_hash_value, ss.parsing_schema_name) + group by --instance_number + --, + --parsing_schema_name + --, + sql_id + order by sql_id) + where sqlrang > 1 +/ + + +prompt +prompt ... time = microseconds! +prompt +prompt \ No newline at end of file diff --git a/awr_os_stat.sql b/awr_os_stat.sql new file mode 100644 index 0000000..1449033 --- /dev/null +++ b/awr_os_stat.sql @@ -0,0 +1,25 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc - display the OS statistic of the last days +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 300 + +select ss.instance_number + , to_char (s.begin_interval_time, 'dd.mm.yyyy hh24:mi') as begin_interval_time + , 'LOAD =>' as param + , round (ss.value, 3) as load_value + from dba_hist_snapshot s, DBA_HIST_OSSTAT ss, DBA_HIST_OSSTAT_NAME ssn + where s.snap_id = ss.snap_id + and ss.instance_number = s.instance_number + and s.snap_id > (select max (i.snap_id) + - 10 + from dba_hist_snapshot i + where i.instance_number = ss.instance_number) + and ssn.stat_id = ss.stat_id + and ssn.stat_name = 'LOAD' +order by 1 +/ diff --git a/awr_pga_stat.sql b/awr_pga_stat.sql new file mode 100644 index 0000000..a9b8c91 --- /dev/null +++ b/awr_pga_stat.sql @@ -0,0 +1,44 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get more information over the pga usage +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 300 + + + +define START_SNAP='&1' +define END_SNAP='&2' + +prompt +prompt ... time format must be dd.mm.yyyy hh24:mi +prompt +prompt Parameter 1 = START_SNAP => &&START_SNAP. +prompt Parameter 2 = END_SNAP => &&END_SNAP. +prompt + + +column begin_interval_time format a18 heading "Snap | Begin" +column instance_number format 99 heading "In|st" +column name format a50 heading "PGA Pool" +column value format 999G999G999G999 heading "Size Value" + +select p.instance_number + , to_char(s.begin_interval_time,'dd.mm.yyyy hh24:mi') as begin_interval_time + , p.NAME + , p.VALUE + from dba_hist_pgastat p + , dba_hist_snapshot s +where s.snap_id = p.snap_id + and p.instance_number = s.instance_number + --and s.snap_id > (select max(i.snap_id)-1000 from dba_hist_snapshot i where i.instance_number=p.instance_number) + and s.begin_interval_time between to_date('&&START_SNAP','dd.mm.yyyy hh24:mi') and to_date('&&END_SNAP','dd.mm.yyyy hh24:mi') + and p.name like '%PGA%' + and p.instance_number=4 +order by p.instance_number,s.snap_id,p.name +/ + +prompt diff --git a/awr_resourcelimit.sql b/awr_resourcelimit.sql new file mode 100644 index 0000000..0bf52f8 --- /dev/null +++ b/awr_resourcelimit.sql @@ -0,0 +1,42 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: display the OS statistic of the last days +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 300 + +/* +CURRENT_UTILIZATION NUMBER Number of (resources, locks, or processes) currently being used +MAX_UTILIZATION NUMBER Maximum consumption of the resource since the last instance start up +INITIAL_ALLOCATION VARCHAR2(10) Initial allocation. This will be equal to the value specified for the resource in the initialization parameter file (UNLIMITED for infinite allocation). +LIMIT_VALUE VARCHAR2(10) Unlimited for resources and locks. This can be greater than the initial allocation value (UNLIMITED for infinite limit). +*/ + +SELECT * + FROM ( +SELECT ss.instance_number + , to_char(s.begin_interval_time,'dd.mm.yyyy hh24:mi') AS begin_interval_time + , ss.RESOURCE_NAME + , ss.CURRENT_UTILIZATION + ,ss.MAX_UTILIZATION + --, ss.INITIAL_ALLOCATION + , ss.LIMIT_VALUE +FROM dba_hist_snapshot s + , DBA_HIST_RESOURCE_LIMIT ss +WHERE s.snap_id = ss.snap_id + AND ss.instance_number = s.instance_number + AND s.snap_id > (SELECT MAX(i.snap_id)-10 FROM dba_hist_snapshot i WHERE i.instance_number=ss.instance_number) + AND ss.RESOURCE_NAME IN ('processes','sessions') + AND ss.instance_number=3 + ) +pivot ( + MAX (CURRENT_UTILIZATION) AS CUR_UTL , MAX (MAX_UTILIZATION) AS MAX_UTL, MAX(LIMIT_VALUE) AS MAX_LIMIT + FOR RESOURCE_NAME + IN ( 'processes' AS proc + ,'sessions' AS sess + ) +) +/ \ No newline at end of file diff --git a/awr_session_none_technical_user.sql b/awr_session_none_technical_user.sql new file mode 100644 index 0000000..670313b --- /dev/null +++ b/awr_session_none_technical_user.sql @@ -0,0 +1,56 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get a report over the user activities ( for example sqlplus.exe or toad.exe ) of the last day +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 300 + +define timing= 1800 + + +column username format a10 +column sample_time format a18 +column program format a16 +column module format a16 +column action format a16 +column client_id format a16 +column machine format a16 +column service_name format a16 + +ttitle "Summary of all user sessions from none technical users " skip 2 + +select count(*) + , u.username + , ah.PROGRAM + , ah.MODULE + , ah.ACTION + , ah.CLIENT_ID + , ah.MACHINE + , ass.name as service_name + from GV$ACTIVE_SESSION_HISTORY ah + , GV$ACTIVE_SERVICES ass + , dba_users u + where ass.inst_id = ah.inst_id + and ass.NAME_HASH = ah.SERVICE_HASH + and u.user_id = ah.user_id + and ah.SAMPLE_TIME > (sysdate - ((1 / (24 * 60)) * &&timing. )) + -- filter for all none prod program like *.exe + and ( ah.program like '%.exe' or ah.program like '%plus%' ) + -- + and u.username not in ('DBSNMP') + group by u.username + ,ah.PROGRAM + ,ah.MODULE + ,ah.ACTION + ,ah.CLIENT_ID + ,ah.MACHINE + ,ass.name + --having count(*) > 25 * 60 + order by username desc +/ + +ttitle off + diff --git a/awr_session_resource_plan_historie.sql b/awr_session_resource_plan_historie.sql new file mode 100644 index 0000000..2390883 --- /dev/null +++ b/awr_session_resource_plan_historie.sql @@ -0,0 +1,54 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the consumer group of all history active sessions of a user +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +set linesize 130 pagesize 300 +set verify off + + +define USER_NAME = &1 +prompt +prompt Parameter 1 = USER_NAME => &&USER_NAME. +prompt + + +column sample_time format a18 heading "Sample|Time" +column session_state format a10 heading "Session|state" +column event format a35 heading "Event" +column consumer_group format a18 heading "Consumer|Group" +column service_name format a20 heading "DB|Service" +column snaps format 999 heading "CNT" +column inst_id format 99 heading "IN|ST" + + select to_char (sh.sample_time, 'dd.mm.yyyy hh24:mi') as sample_time + , count (*) as snaps + , sh.session_state + , sh.event + , cg.consumer_group + , sv.name as service_name + , sh.INSTANCE_NUMBER as inst_id + from DBA_HIST_ACTIVE_SESS_HISTORY sh + , dba_users du + , DBA_RSRC_CONSUMER_GROUPS cg + , dba_SERVICES sv + where sh.user_id = du.user_id + and sh.consumer_group_id = cg.consumer_group_id + and sv.NAME_HASH = sh.SERVICE_HASH + and du.username like upper ('&&USER_NAME.') + and sh.sample_time between sysdate - 31 and sysdate + --and cg.consumer_group != 'OTHER_GROUPS' + and sv.name != 'SYS$USERS' +group by to_char (sh.sample_time, 'dd.mm.yyyy hh24:mi') + , sh.session_state + , sh.event + , cg.consumer_group + , sv.name + , sh.INSTANCE_NUMBER +order by 1 +/ + \ No newline at end of file diff --git a/awr_session_stat.sql b/awr_session_stat.sql new file mode 100644 index 0000000..8c7db87 --- /dev/null +++ b/awr_session_stat.sql @@ -0,0 +1,74 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the statistic information over a the active sessions of a DB user +-- +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 300 + + +define DB_USER_NAME='&1' + +prompt +prompt Parameter 1 = DB_USER_NAME => &&DB_USER_NAME. +prompt + + +column begin_interval_time format a18 heading "Snap | Begin" +column instance_number format 99 heading "In|st" +column value format a20 heading "Value" +column stat_name format a18 heading "Stat|Name" +column diff format a20 heading "Dif |before" +column program_a format a20 heading "One|Prog" +column program_b format a20 heading "Other|Prog" +column sql_id_a format a20 heading "One|SQL" +column sql_id_b format a20 heading "Other|SQL" +column username format a14 heading "User|Name" +column snap_count format 999 heading "Snap|Cnt" +column SESSION_ID format 99999 heading "Sess|ID" +column SESSION_SERIAL# format 99999 heading "Ser|ial" +column event_a format a20 heading "One|Event" +column event_b format a20 heading "Other|Event" + + +break on instance_number skip 2 +--COMPUTE SUM OF instance_number ON begin_interval_time + +select ss.instance_number + , to_char (s.begin_interval_time, 'dd.mm.yyyy hh24:mi') as begin_interval_time + , ss.SESSION_ID + , ss.SESSION_SERIAL# + , count (s.snap_id) as snap_count + , u.username + , ss.CLIENT_ID + , ss.MACHINE + , min (ss.PROGRAM) as program_a + , min (SQL_ID) as sql_id_a + , min (EVENT) as event_a + , max (EVENT) as event_b + from dba_hist_active_sess_history ss, dba_hist_snapshot s, dba_users u + where u.user_id = ss.user_id + and s.snap_id = ss.snap_id + and ss.instance_number = s.instance_number + and s.snap_id > (select max (i.snap_id)- 50 + from dba_hist_snapshot i + where i.instance_number = ss.instance_number) +-- and ss.SESSION_ID = 4382 +-- and u.username like upper('&&DB_USER_NAME.') +-- and ss.instance_number = 3 +-- and s.begin_interval_time between to_date('14.11.2014 08:19','dd.mm.yyyy hh24:mi') and to_date('14.11.2014 08:31','dd.mm.yyyy hh24:mi') +group by ss.SESSION_ID + , ss.SESSION_SERIAL# + , ss.instance_number + , to_char (s.begin_interval_time, 'dd.mm.yyyy hh24:mi') + , u.username + , ss.CLIENT_ID + , ss.MACHINE +--, ss.PROGRAM +order by ss.instance_number, to_char (s.begin_interval_time, 'dd.mm.yyyy hh24:mi') +/ + +clear breaks \ No newline at end of file diff --git a/awr_sql_find.sql b/awr_sql_find.sql new file mode 100644 index 0000000..1506265 --- /dev/null +++ b/awr_sql_find.sql @@ -0,0 +1,46 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: find the sql statement in the sql cache +-- Date: September 2013 +--=============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 300 + +define SQL_STATEMENT = &1 + + +prompt +prompt Parameter 1 = SQL_STATEMENT => &&SQL_STATEMENT. +prompt + + +set verify off +SET linesize 130 pagesize 800 + +ttitle left "Search SQL from AWR Repository this text string : &SQL_STATEMENT." skip 2 + +column sql_text format a2000 heading "SQL|Text" +column sql_id format a13 heading "SQL|ID" +column DBID format 99999999999 heading "DB|Id" +column COMMAND_TYPE format 99 heading "CMD|Typ" + + +set long 100 + +select DBID + , SQL_ID + , SQL_TEXT + , COMMAND_TYPE + /* GPI SQL Analyse */ + from dba_hist_sqltext +where upper(sql_text) like upper('%&&SQL_STATEMENT.%') + and sql_text not like '%GPI SQL Analyse%' +order by DBID,SQL_ID +/ + +prompt ... to get the execution plan call awr_sql.sql with the sql_id + +ttitle off diff --git a/awr_sql_find_report.sql b/awr_sql_find_report.sql new file mode 100644 index 0000000..dce31a3 --- /dev/null +++ b/awr_sql_find_report.sql @@ -0,0 +1,91 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: find the sql statement in the awr repository +-- Date: Oktober 2014 +--=============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +define SQL_STATEMENT = &1 + +prompt +prompt Parameter 1 = SQL_STATEMENT => &&SQL_STATEMENT. +prompt + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_sql_usage.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + + +SET MARKUP HTML ON SPOOL ON PREFORMAT OFF ENTMAP ON - +HEAD "SQL Usage Report - +" - +TABLE "WIDTH='90%' BORDER='1'" + +spool &&SPOOL_NAME + +set verify off +SET linesize 180 pagesize 4000 + +ttitle left "Search SQL from AWR Repository this text string : &SQL_STATEMENT." skip 2 + +column sql_text format a150 heading "SQL|Text" WORD_WRAPPED ENTMAP OFF +column sql_id format a13 heading "SQL|ID" +column parsing_schema_name format a20 heading "Parsing|Schema" +column plan_hash_value format 9999999999 heading "Plan | Hash" +column first_usage format a18 heading "First Usage" +column last_usage format a18 heading "Last Usage" +column count_statements format 99999999 heading "Count Snapshots" +column EXECUTIONS_TOTAL format 99999999 heading "SQL Executions Total" +column PX_SERVERS_EXECS_TOTAL format 99999999 heading "Parallel Server Usage Total" + + +select ss.parsing_schema_name + , t.SQL_ID + , ss.plan_hash_value + , replace( DBMS_LOB.SUBSTR(t.SQL_TEXT,1000,1),'&SQL_STATEMENT.','&SQL_STATEMENT.') as SQL_TEXT + , count(t.SQL_ID) as count_statements + , sum(ss.EXECUTIONS_TOTAL) as EXECUTIONS_TOTAL + , sum(ss.PX_SERVERS_EXECS_TOTAL ) as PX_SERVERS_EXECS_TOTAL + , to_char(min(s.begin_interval_time),'dd.mm.yyyy hh24:mi') as first_usage + , to_char(max(s.begin_interval_time),'dd.mm.yyyy hh24:mi') as last_usage + /* GPI SQL Analyse */ + from dba_hist_sqltext t + , dba_hist_sqlstat ss + , dba_hist_snapshot s +where s.snap_id = ss.snap_id + and ss.instance_number = s.instance_number + and ss.sql_id = t.sql_id + and upper(t.sql_text) like upper('%&&SQL_STATEMENT.%') + -- not show internal SQL from statistic process and so on + and t.sql_text not like '%GPI SQL Analyse%' + and t.sql_text not like '%SQL Analyze%' + and t.sql_text not like '%dynamic_sampling(0) no_sql_tune no_monitoring optimizer_features_enable%' + and t.sql_text not like '% NO_PARALLEL%' + and t.sql_text not like '%NOPARALLEL%' + and ss.PARSING_SCHEMA_NAME not in ('SYS','DBSNMP','SYSTEM') +group by ss.parsing_schema_name + , t.SQL_ID + , ss.plan_hash_value + , DBMS_LOB.SUBSTR(t.SQL_TEXT,1000,1) +order by 1,2 +/ + +set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window +host &&SPOOL_NAME + diff --git a/awr_sql_hash.sql b/awr_sql_hash.sql new file mode 100644 index 0000000..f648951 --- /dev/null +++ b/awr_sql_hash.sql @@ -0,0 +1,62 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get more information about one sql statement from the awr +-- +--============================================================================== +-- see +-- http://oracleprof.blogspot.de/2011/06/how-to-color-mark-sql-for-awr-snapshots.html +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 300 + +define SQL_ID='&1' + +prompt +prompt Parameter 1 = SQL ID => &&SQL_ID. +prompt + + + +column end_interval_time format a18 heading "Snap | End" +column begin_interval_time format a18 heading "Snap | Begin" +column plan_hash_value format 9999999999 heading "Plan | Hash" +column execution_time_max format 999G999G999G999D99 heading "Max Execution Time|per SQL" +column execution_time_min format 999G999G999G999D99 heading "Min Execution Time|per SQL" +column snapshot_count format 999999 heading "Snap|Cnt" +column instance_number format 99 heading "In|st" +column parsing_schema_name format a20 heading "Parsing|Schema" + +select ss.instance_number + , ss.sql_id + , ss.plan_hash_value + , to_char(min(s.begin_interval_time),'dd.mm.yyyy hh24:mi') as begin_interval_time + , to_char(max(s.begin_interval_time),'dd.mm.yyyy hh24:mi') as end_interval_time + , min(case when ss.executions_delta = 0 then -1 else ss.elapsed_time_delta/ss.executions_delta end ) as execution_time_min + , max(case when ss.executions_delta = 0 then -1 else ss.elapsed_time_delta/ss.executions_delta end ) as execution_time_max + , count(*) snapshot_count + , ss.parsing_schema_name + from dba_hist_sqlstat ss + , dba_hist_snapshot s +where s.snap_id = ss.snap_id + and ss.instance_number = s.instance_number + and ss.sql_id = '&&sql_id.' +group by ss.instance_number + , ss.sql_id + , ss.plan_hash_value + , ss.parsing_schema_name +order by 4 +/ + +prompt +prompt ... time = microseconds! +prompt +prompt +prompt ... +prompt ... to mark a sql statment use this function : exec dbms_workload_repository.add_colored_sql('&&SQL_ID.') +prompt ... check with : select * from DBA_HIST_COLORED_SQL; +prompt ... do not forget to uncolor the statement : exec dbms_workload_repository.remove_colored_sql('&&SQL_ID.') +prompt +prompt \ No newline at end of file diff --git a/awr_sql_plan.sql b/awr_sql_plan.sql new file mode 100644 index 0000000..fda74ed --- /dev/null +++ b/awr_sql_plan.sql @@ -0,0 +1,26 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the sql execution plan for this sql id from the AWR Repository +-- You need the Tuning Pack Licence to use the AWR! +-- Only 11g SQL Syntax! +-- Date: September 2013 +-- +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 0 +set verify off + +define SQL_ID = &1 + +ttitle left "SQL Plan from AWR ID: &SQL_ID." skip 2 + +--11g +select * from TABLE(dbms_xplan.display_awr(sql_id=> '&SQL_ID.', format => 'TYPICAL')); + +--10g +--select * from TABLE(dbms_xplan.display_awr('&SQL_ID.')); + +ttitle off diff --git a/awr_sql_stat.sql b/awr_sql_stat.sql new file mode 100644 index 0000000..29baf0f --- /dev/null +++ b/awr_sql_stat.sql @@ -0,0 +1,65 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get more information about one sql statement from the awr +-- +--============================================================================== +-- see +-- http://oracleprof.blogspot.de/2011/06/how-to-color-mark-sql-for-awr-snapshots.html +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +set linesize 130 pagesize 300 + +define SQL_ID='&1' + +prompt +prompt Parameter 1 = SQL ID => &&SQL_ID. +prompt + + + +column begin_interval_time format a18 heading "Snap| Begin" +column plan_hash_value format 9999999999 heading "Plan| Hash" +column execution_time format 999G999G999G999D99 heading "Execution Time|per SQL" +column executions_delta format 99G999G999 heading "Executions|delta" +column cpu_time_delta format 999G999G999G999 heading "Cpu time|delta" +column elapsed_time_delta format 999G999G999G999 heading "Elapsed time|delta" +column disk_reads_delta format 999G999G999 heading "Disk Read|Delta" +column instance_number format 99 heading "In|st" +column PARSING_SCHEMA_NAME format a20 heading "Parsing|User" + + +select ss.instance_number + , ss.sql_id + , to_char(s.begin_interval_time,'dd.mm.yyyy hh24:mi') as begin_interval_time + , ss.plan_hash_value + , case when ss.executions_delta = 0 then -1 else ss.elapsed_time_delta/ss.executions_delta end as execution_time + , ss.executions_delta + , ss.cpu_time_delta + , ss.elapsed_time_delta + , ss.disk_reads_delta + , ss.PARSING_SCHEMA_NAME + from dba_hist_sqlstat ss + , dba_hist_snapshot s +where s.snap_id = ss.snap_id + and ss.instance_number = s.instance_number + and ss.sql_id = '&&sql_id.' + and s.snap_id > (select max(i.snap_id)-1000 from dba_hist_snapshot i where i.instance_number=ss.instance_number) +order by s.snap_id, ss.instance_number, ss.sql_id +/ + + +prompt +prompt ... time = microseconds! +prompt +prompt +prompt ... +prompt ... to mark a sql statment use this function : exec dbms_workload_repository.add_colored_sql('&&SQL_ID.') +prompt ... check with : select * from DBA_HIST_COLORED_SQL; +prompt ... do not forget to uncolor the statement : exec dbms_workload_repository.remove_colored_sql('&&SQL_ID.') +prompt +prompt + diff --git a/awr_sql_time_stat.sql b/awr_sql_time_stat.sql new file mode 100644 index 0000000..277a6d0 --- /dev/null +++ b/awr_sql_time_stat.sql @@ -0,0 +1,70 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get information about the last sql in the database over a time period +-- +--============================================================================== +-- see +-- http://oracleprof.blogspot.de/2011/06/how-to-color-mark-sql-for-awr-snapshots.html +-- http://mwidlake.wordpress.com/2010/01/08/more-on-command_type-values/ +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set linesize 130 pagesize 300 + +define START_SNAP='&1' +define END_SNAP='&2' + +prompt +prompt ... time format must be dd.mm.yyyy hh24:mi +prompt +prompt Parameter 1 = START_SNAP => &&START_SNAP. +prompt Parameter 2 = END_SNAP => &&END_SNAP. +prompt + + + +column begin_interval_time format a18 heading "Snap | Begin" +column plan_hash_value format 9999999999 heading "Plan | Hash" +column execution_time format 9G999G999G999D99 heading "Execution Time|per SQL" +column executions_delta format 99G999G999 heading "Executions|delta" +column cpu_time_delta format 99G999G999 heading "Cpu time|delta" +column elapsed_time_delta format 999G999G999G999 heading "Elapsed time|delta" +column disk_reads_delta format 99G999G999 heading "Disk Read|Delta" +column instance_number format 99 heading "In|st" +column COMMAND_TYPE format 999 heading "C|typ" +column sql_id format a15 heading "SQL|ID" +column USERNAME format a18 heading "Schema|Name" + +select ss.instance_number + , to_char(s.begin_interval_time,'dd.mm.yyyy hh24:mi') as begin_interval_time + , ss.PARSING_SCHEMA_NAME as USERNAME + , ss.sql_id + , st.COMMAND_TYPE + -- , ss.plan_hash_value + , case when ss.executions_delta = 0 then -1 else ss.elapsed_time_delta/ss.executions_delta end as execution_time + , ss.executions_delta + , ss.cpu_time_delta + , ss.elapsed_time_delta + , ss.disk_reads_delta + from dba_hist_sqlstat ss + , dba_hist_snapshot s + , DBA_HIST_SQLTEXT st +where s.snap_id = ss.snap_id + and ss.instance_number = s.instance_number + and st.sql_id=ss.sql_id + and ss.PX_SERVERS_EXECS_TOTAL > 0 + -- + and s.begin_interval_time between to_date('&&START_SNAP','dd.mm.yyyy hh24:mi') and to_date('&&END_SNAP','dd.mm.yyyy hh24:mi') + -- update or delete + -- and st.COMMAND_TYPE in (6,7) + and ss.PARSING_SCHEMA_NAME not in ('SYS','SYSTEM','DBSNMP') +order by ss.sql_id ,s.snap_id, ss.instance_number,ss.PARSING_SCHEMA_NAME, ss.elapsed_time_delta desc +/ + +prompt +prompt ... time = microseconds! +prompt +prompt ... to see command type Numbers use select * from audit_actions order by action +prompt diff --git a/awr_sys_stat.sql b/awr_sys_stat.sql new file mode 100644 index 0000000..0a06a01 --- /dev/null +++ b/awr_sys_stat.sql @@ -0,0 +1,44 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the statistic information over a system statistic +-- +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +set linesize 130 pagesize 300 + + +define SYSSTAT_NAME='&1' + +prompt +prompt Parameter 1 = SYSSTAT_NAME => &&SYSSTAT_NAME. +prompt + + +column begin_interval_time format a18 heading "Snap | Begin" +column instance_number format 99 heading "In|st" +column value format a20 heading "Value" +column stat_name format a18 heading "Stat|Name" +column diff format a20 heading "Dif |before" + +break on instance_number skip 2 +--COMPUTE SUM OF instance_number ON begin_interval_time + +select ss.instance_number + , ss.STAT_NAME + , to_char(s.begin_interval_time,'dd.mm.yyyy hh24:mi') as begin_interval_time + , to_char(round(ss.value,2),'999G999G999G990D99') as value + , to_char(round((ss.value -lag (ss.value, 1, ss.value) OVER (ORDER BY ss.STAT_NAME,ss.instance_number, s.snap_id)) / 600 ,2),'999G999G999G990D99') AS diff +from dba_hist_sysstat ss + , dba_hist_snapshot s +where s.snap_id = ss.snap_id + and ss.instance_number = s.instance_number + and s.snap_id > (select max(i.snap_id)-25 from dba_hist_snapshot i where i.instance_number=ss.instance_number) + and ss.STAT_NAME like lower('&&SYSSTAT_NAME.%') +order by ss.STAT_NAME,ss.instance_number, s.snap_id +/ + +clear break \ No newline at end of file diff --git a/awr_tablespace_history.sql b/awr_tablespace_history.sql new file mode 100644 index 0000000..1921bc2 --- /dev/null +++ b/awr_tablespace_history.sql @@ -0,0 +1,28 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the historical Size of a tablespace from the AWR +-- Date: November 2013 +-- +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set verify off +set linesize 130 pagesize 300 + +select to_char (sp.begin_interval_time, 'dd.mm.yyyy') "tag" + , tbstat.tsname tsname + , max (round ( ( tbus.tablespace_usedsize * tbs.block_size) / ( 1024 * 1024) , 1)) belegt_mb + , max (round ( ( tbus.tablespace_size * tbs.block_size) / ( 1024 * 1024) , 1)) groesse_mb + from dba_hist_snapshot sp + , dba_tablespaces tbs + , dba_hist_tbspc_space_usage tbus + , dba_hist_tablespace_stat tbstat + where tbus.tablespace_id = tbstat.ts# + and tbus.snap_id = sp.snap_id + and tbstat.tsname = tbs.tablespace_name +group by to_char (sp.begin_interval_time, 'dd.mm.yyyy'), tbstat.tsname +order by tbstat.tsname, "tag" +/ + diff --git a/awr_temp_usage.sql b/awr_temp_usage.sql new file mode 100644 index 0000000..f2ddabf --- /dev/null +++ b/awr_temp_usage.sql @@ -0,0 +1,69 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get information about the temp Usage in the DB history +-- +--============================================================================== +-- see +-- http://coskan.wordpress.com/2011/01/24/analysing-temp-usage-on-11gr2-temp-space-is-not-released/ +-- alternative from v$active_session_history +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + + +set linesize 130 pagesize 300 + +define START_SNAP='&1' +define END_SNAP='&2' + +prompt +prompt ... time format must be dd.mm.yyyy hh24:mi +prompt +prompt Parameter 1 = START_SNAP => &&START_SNAP. +prompt Parameter 2 = END_SNAP => &&END_SNAP. +prompt + +column begin_interval_time format a18 heading "Snap | Begin" +column plan_hash_value format 9999999999 heading "Plan | Hash" +column instance_number format 99 heading "In|st" +column COMMAND_TYPE format 999 heading "C|typ" +column sql_id format a15 heading "SQL|ID" +column temp_mb format 99G999G999 heading "Temp Usage|MB" +column temp_diff format 99G999G999 heading "Temp Usage Dif|MB" +column USERNAME format a18 heading "Schema|Name" +column SAMPLE_Time format a10 heading "Sample|Minute" + +select ss.instance_number + , to_char(s.begin_interval_time,'dd.mm.yyyy hh24:mi') as begin_interval_time + , to_char(ss.SAMPLE_time,'hh24:mi:ss') as SAMPLE_Time + , u.USERNAME + , ss.sql_id + , st.COMMAND_TYPE + , ss.temp_space_allocated/1024/1024 temp_mb + , ss.temp_space_allocated/1024/1024- lag(temp_space_allocated/1024/1024,1,0) over (order by sample_time) as temp_diff + from dba_hist_active_sess_history ss + , dba_hist_snapshot s + , DBA_HIST_SQLTEXT st + , DBA_users u +where ss.snap_id = s.snap_id + and ss.instance_number = s.instance_number + -- st + and st.sql_id=ss.sql_id + -- u + and u.USER_ID=ss.USER_ID + -- + and s.begin_interval_time between to_date('&&START_SNAP','dd.mm.yyyy hh24:mi') and to_date('&&END_SNAP','dd.mm.yyyy hh24:mi') + and ss.temp_space_allocated > 0 + -- +order by s.snap_id + , ss.instance_number + , ss.sql_id +/ + +prompt +prompt ... time = microseconds! +prompt +prompt ... to see command type Numbers use select * from audit_actions order by action +prompt + diff --git a/bgprocess.sql b/bgprocess.sql new file mode 100644 index 0000000..4a482d6 --- /dev/null +++ b/bgprocess.sql @@ -0,0 +1,164 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- +--============================================================================== +set linesize 130 pagesize 300 +set verify off + + +ttitle left "Process List of the Oracle BG Processes" skip 2 + + +/* +-- https://docs.oracle.com/cd/E18283_01/server.112/e17110/bgprocesses.htm#BBBDIIHC +ABMR Auto BMR Background Process +ACFS ASM Cluster File System CSS Process +ACMS Atomic Control File to Memory Service Process +APnn Logical Standby / Streams Apply Process Coordinator Process +ARBn ASM Rebalance Process +ARCn Archiver Process +ASMB ASM Background Process +ASnn Logical Standby / Streams Apply Process Reader Server or Apply Server +BMRn Automatic Block Media Recovery Slave Pool Process +Bnnn ASM Blocking Slave Process for GMON +CJQ0 Job Queue Coordinator Process +CKPT Checkpoint Process +CPnn Streams Capture Process +CSnn Streams Propagation Sender Process +CSnn I/O Calibration Process +CTWR Change Tracking Writer Process +DBRM Database Resource Manager Process +DBWn Database Writer Process +DIA0 Diagnostic Process +DIAG Diagnostic Capture Process +DMnn Data Pump Master Process +DMON Data Guard Broker Monitor Process +Dnnn Dispatcher Process +DRnn ASM Disk Resynchronization Slave Process +DSKM Slave Diskmon Process +DWnn Data Pump Worker Process +EMNC EMON Coordinator Process +Ennn EMON Slave Process +FBDA Flashback Data Archiver Process +FMON File Mapping Monitor Process +FSFP Data Guard Broker Fast Start Failover Pinger Process +GCRnFoot 1  Global Conflict Resolution Slave Process +GEN0 General Task Execution Process +GMON ASM Disk Group Monitor Process +GTXn Global Transaction Process +Innn Disk and Tape I/O Slave Process +INSV Data Guard Broker Instance Slave Process +Jnnn Job Queue Slave Process +LCK0 Instance Enqueue Background Process +LGWR Log Writer Process +LMD0 Global Enqueue Service Daemon 0 Process +LMHB Global Cache/Enqueue Service Heartbeat Monitor +LMON Global Enqueue Service Monitor Process +LMSn Global Cache Service Process +LSP0 Logical Standby Coordinator Process +LSP1 Logical Standby Dictionary Build Process +LSP2 Logical Standby Set Guard Process +Lnnn Pooled Server Process +MARK Mark AU for Resynchronization Coordinator Process +MMAN Memory Manager Process +MMNL Manageability Monitor Lite Process +MMON Manageability Monitor Process +Mnnn MMON Slave Process +MRP0 Managed Standby Recovery Process +MSnn LogMiner Worker Process +Nnnn Connection Broker Process +NSAn Redo Transport NSA1 Process +NSSn Redo Transport NSS1 Process +NSVn Data Guard Broker NetSlave Process +OCFn ASM CF Connection Pool Process +Onnn ASM Connection Pool Process +PING Interconnect Latency Measurement Process +PMON Process Monitor +Pnnn Parallel Query Slave Process +PRnn Parallel Recovery Process +PSP0 Process Spawner Process +QMNC AQ Coordinator Process +Qnnn AQ Server Class Process +RBAL ASM Rebalance Master Process +RCBG Result Cache Background Process +RECO Recoverer Process +RMSn Oracle RAC Management Process +Rnnn ASM Block Remap Slave Process +RPnn Capture Processing Worker Process +RSM0 Data Guard Broker Worker Process +RSMN Remote Slave Monitor Process +RVWR Recovery Writer Process +SMCO Space Management Coordinator Process +SMON System Monitor Process +Snnn Shared Server Process +TEMn ASM disk Test Error Emulation Process +VBGn Volume Background Process +VDBG Volume Driver Process +VKRM Virtual Scheduler for Resource Manager Process +VKTM Virtual Keeper of Time Process +VMB0 Volume Membership Process +Vnnn ASM Volume I/O Slave Process +Wnnn Space Management Slave Process +XDMG Exadata Automation Manager +XDWK Exadata Automation Manager +Xnnn ASM Disk Expel Slave Process +*/ + + +column process_id format a8 heading "Process|ID" +column inst_id format 99 heading "IN|ID" +column username format a8 heading "DB User|name" +column osusername format a8 heading "OS User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column machine format a14 heading "Server|Name" +column terminal format a14 heading "Remote|terminal" +column program format a28 heading "BG|Program" +column module format a15 heading "Remote|module" +column client_info format a15 heading "Client|info" +column pname format a8 heading "Process|name" +column tracefile format a20 heading "Trace|File" +column error format 999999 heading "Error|Number" +column DESCRIPTION format a35 heading "Description" word_wrapped + + + select p.inst_id + , to_char (p.spid) as process_id + , vs.sid + , vs.serial# + , p.username as osusername + , pb.name + , pb.DESCRIPTION + , pb.error + , vs.machine + , nvl (vs.module, ' - ') as module + , vs.program + --, substr(p.tracefile,length(p.tracefile)-REGEXP_INSTR(reverse(p.tracefile),'[\/|\]')+2,1000) as tracefile + --, p.tracefile + from gv$session vs, gv$process p, gv$bgprocess pb + where vs.paddr = p.addr + and vs.inst_id = p.inst_id + and pb.PADDR = p.addr + and pb.INST_ID = p.inst_id + and vs.username is null +order by pb.name, p.inst_id +/ + +ttitle left "Trace File Locations" skip 2 + +column full_trace_file_loc format a100 heading "Trace|File" + + select p.inst_id + , pb.name + , to_char (p.spid) as process_id + , p.tracefile as full_trace_file_loc + from gv$session vs, gv$process p, gv$bgprocess pb + where vs.paddr = p.addr + and vs.inst_id = p.inst_id + and pb.PADDR = p.addr + and pb.INST_ID = p.inst_id + and vs.username is null +order by pb.name, p.inst_id +/ + +ttitle off \ No newline at end of file diff --git a/buffer.sql b/buffer.sql new file mode 100644 index 0000000..1065d4d --- /dev/null +++ b/buffer.sql @@ -0,0 +1,118 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Get buffer cache information +-- Date: September 2013 +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Buffer Cache Information" SKIP 1 + +@select v$buffer_pool + +ttitle "Buffer Cache Block Count" SKIP 2 + +select count(*) as "Total Count of Blocks" + from v$bh +/ + +ttitle "Buffer Cache Block Status" SKIP 2 + +SELECT status + , dirty + , COUNT(*) +FROM v$bh +GROUP BY STATUS + , dirty +/ +prompt +prompt ***************************************************** +prompt dirty => N :: Block can be overwitten +prompt ***************************************************** +prompt status => free :: The block is free and was never used +prompt status => xcur :: Exclusive +prompt status => scur :: Shared current +prompt status => cr :: Consistent read +prompt status => read :: Being read from disk +prompt status => mrec :: In media recovery mode +prompt status => irec :: In instance recovery mode +prompt ***************************************************** +prompt + +ttitle "Get the 10 top blocks in the cache" SKIP 2 + +column tch format 999G999G999 heading "Touch|Count" +column segment_name format a30 heading "Segment|Name" +column owner format a20 heading "Owner" +column tch_rank format 999999 heading "R" + +select tch_rank + , b.tch + , o.owner + , o.segment_name + from (select tch + , file# + , dbablk + , rank() over (order by tch desc) as tch_rank + from x$bh order by tch + ) b + , dba_extents o + where b.tch_rank <= 25 + and o.file_id = b.file# + and o.block_id = b.dbablk + --and o.owner not in ('SYS','SYSTEM') + order by b.tch_rank asc +/ + +prompt + +ttitle "LRU Status " SKIP 2 + +select lru_flag + , count(*) + from sys.x$bh +group by lru_flag +/ + +prompt *********************************** +prompt 0 = flag not set +prompt 2 = buffer moved to tail of LRU +prompt 4 = buffer on auxiliary list +prompt 8 = buffer moved to MRU +prompt *********************************** +prompt + +ttitle "Cache Usage - Hot Block Candidates " SKIP 2 + +column buffer format 999999 +column avg_to format 999999 +column object_name format a30 heading "Object|Name" + +select nvl(o.owner,'-') as owner + , nvl(o.object_name,'-') as object_name + , count(1) buffer + , avg(x.tch) avg_to + from sys.x$bh x + , dba_objects o + where x.lru_flag = 8 + and x.obj = o.object_id (+) + group by nvl(o.owner,'-') + , nvl(o.object_name,'-') +having avg(x.tch) > 5 and count(1) > 20 +/ + +ttitle "Cache Usage " SKIP 2 + +select obj object + , count(1) buffers + , round(100*(count(1)/totsize),3) pct_cache + from sys.x$bh + , (select BLOCK_SIZE totsize from v$buffer_pool) + where tch= 1 + or ( tch= 0 and lru_flag < 8 ) + group by obj + , totsize +having 100*(count(1)/totsize) > 5 +/ + + +ttitle off diff --git a/buffer_cache.sql b/buffer_cache.sql new file mode 100644 index 0000000..c0c9ae4 --- /dev/null +++ b/buffer_cache.sql @@ -0,0 +1,44 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Informations about buffer block Cache usage in the database +-- Date: 02.2017 +-- +-- see orignal script => http://www.morganslibrary.org/reference/buffer_pools.html +-- +--============================================================================== +set linesize 130 pagesize 300 + +column owner format a15 +column object_name format a20 +column object_type format a15 +column status format a15 +column buffer_pool format a15 + + +SELECT b.inst_id + , do.owner + , do.object_name + , do.object_type + , COUNT(b.block#) as "Cached Blocks" + , ds.buffer_pool + , b.status +FROM gv$bh b + , dba_objects_ae do + , dba_segments ds +WHERE b.OBJD = do.data_object_id + AND do.object_name = ds.segment_name + AND do.owner not like 'SYS%' +GROUP BY b.inst_id, do.owner, do.object_name, do.object_type, ds.buffer_pool, b.status +ORDER BY 1, 2, 3 +/ + +prompt .... -------------------------- +prompt .... +prompt .... Status Description +prompt .... cr Consistent read +prompt .... free Not currently in use +prompt .... irec In instance recovery mode +prompt .... mrec In media recovery mode +prompt .... read Being read from disk +prompt .... scur Shared current +prompt .... xcur Exclusive \ No newline at end of file diff --git a/calibrate_io.sql b/calibrate_io.sql new file mode 100644 index 0000000..cc704a5 --- /dev/null +++ b/calibrate_io.sql @@ -0,0 +1,128 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script to check io of the database +-- Date: 08.2013 +--============================================================================== +-- Doku: http://www.oracle.com/webfolder/technetwork/de/community/dbadmin/tipps/io_calibration/index.html +-- http://docs.oracle.com/cd/E11882_01/appdev.112/e25788/d_resmgr.htm#CJGHGFEA +-- https://support.oracle.com/epmos/main/downloadattachmentprocessor?attachid=727062.1:CALIBRATEIO&clickstream=yes +-- http://docs.oracle.com/cd/E11882_01/appdev.112/e40758/d_resmgr.htm#ARPLS050 +-- +-- num_physical_disks Approximate number of physical disks in the database storage +-- max_latency Maximum tolerable latency in milliseconds for database-block-sized IO requests +-- max_iops Maximum number of I/O requests per second that can be sustained. The I/O requests are randomly-distributed, database-block-sized reads. +-- max_mbps Maximum throughput of I/O that can be sustained, expressed in megabytes per second. The I/O requests are randomly-distributed, 1 megabyte reads. +-- actual_latency Average latency of database-block-sized I/O requests at max_iops rate, expressed in milliseconds +-- +--============================================================================== +-- +-- Must run as SYS! +-- +-- +--============================================================================== +set linesize 130 pagesize 300 + +column name format a35 +column start_time format a25 +column end_time format a25 + +select * + from sys.RESOURCE_IO_CALIBRATE$ +/ + +select * + from GV$IO_CALIBRATION_STATUS +/ + +prompt ... +prompt ... Check that all disks are on async IO! +prompt ... + +SELECT count(*) + , i.asynch_io + FROM v$datafile f + , v$iostat_file i + WHERE f.file# = i.file_no + AND i.filetype_name = 'Data File' + group by i.asynch_io + / + +prompt ... +prompt ... Check that all disks are on async IO! +prompt ... + + +set serveroutput on +set timing on +set time on + +-- set the Count of Disk on the count of luns behind the ASM disks +-- +declare + lat integer; + iops integer; + mbps integer; +begin + dbms_resource_manager.calibrate_io ( + num_physical_disks => 36 + , max_latency => 10 + , max_iops => iops + , max_mbps => mbps + , actual_latency => lat + ); + + dbms_output.put_line('max_iops = ' || iops); + dbms_output.put_line('latency = ' || lat); + dbms_output.put_line('max_mbps = ' || mbps); +end; +/ + + +set timing off +set time off + + + +column start_time format a21 heading "Start|time" +column end_time format a21 heading "End|time" +column max_iops format 9999999 heading "Block/s|data block" +column max_mbps format 9999999 heading "MB/s|maximum-sized read" +column max_pmbps format 9999999 heading "MB/s|largeI/0" +column latency format 9999999 heading "Latency|data block read" +column num_physical_disks format 999 heading "Disk|Cnt" + +select to_char(START_TIME,'dd.mm.yyyy hh24:mi') as START_TIME + ,to_char(END_TIME,'dd.mm.yyyy hh24:mi') as END_TIME + ,MAX_IOPS + ,MAX_MBPS + ,MAX_PMBPS + ,LATENCY + ,NUM_PHYSICAL_DISKS + from dba_rsrc_io_calibrate +/ + +-- START_TIME Start time of the most recent I/O calibration +-- END_TIME End time of the most recent I/O calibration +-- MAX_IOPS Maximum number of data block read requests that can be sustained per second +-- MAX_MBPS Maximum megabytes per second of maximum-sized read requests that can be sustained +-- MAX_PMBPS Maximum megabytes per second of large I/O requests that can be sustained by a single process +-- LATENCY Latency for data block read requests +-- NUM_PHYSICAL_DISKS Number of physical disks in the storage subsystem (as specified by the user) + +select * + from GV$IO_CALIBRATION_STATUS +/ + +prompt ... You should see that your IO Calibrate is READY and therefore Auto DOP is ready. + +select + d.name + , f.file_no + , f.small_read_megabytes + , f.small_read_reqs + , f.large_read_megabytes + , f.large_read_reqs +from + v$iostat_file f + inner join v$datafile d on f.file_no = d.file# +/ diff --git a/cdb.sql b/cdb.sql new file mode 100644 index 0000000..a03eaa7 --- /dev/null +++ b/cdb.sql @@ -0,0 +1,39 @@ +-- GPI - Gunther Pippèrr +-- Desc: overview over a container database +-- Date: 25.October 2018 +-- => https://docs.oracle.com/database/121/ADMIN/cdb_mon.htm#ADMIN13939 +--============================================================================== +set linesize 130 pagesize 300 + + +SHOW CON_NAME + + +-- check if CDB +SELECT CDB FROM V$DATABASE; + +-- get all pugbale databases +SELECT NAME, CON_ID, DBID, CON_UID, GUID FROM V$CONTAINERS ORDER BY CON_ID; + +COLUMN PDB_NAME FORMAT A15 + +SELECT PDB_ID, PDB_NAME, STATUS FROM DBA_PDBS ORDER BY PDB_ID; + +-- open MODE +COLUMN NAME FORMAT A15 +COLUMN RESTRICTED FORMAT A10 +COLUMN OPEN_TIME FORMAT A30 + +SELECT NAME, OPEN_MODE, RESTRICTED, OPEN_TIME FROM V$PDBS; + +--Showing the Data Files for Each PDB in a CDB +COLUMN PDB_ID FORMAT 999 +COLUMN PDB_NAME FORMAT A8 +COLUMN FILE_ID FORMAT 9999 +COLUMN TABLESPACE_NAME FORMAT A10 +COLUMN FILE_NAME FORMAT A45 + +SELECT p.PDB_ID, p.PDB_NAME, d.FILE_ID, d.TABLESPACE_NAME, d.FILE_NAME + FROM DBA_PDBS p, CDB_DATA_FILES d + WHERE p.PDB_ID = d.CON_ID + ORDER BY p.PDB_ID; \ No newline at end of file diff --git a/check_col_usage.sql b/check_col_usage.sql new file mode 100644 index 0000000..51bcc17 --- /dev/null +++ b/check_col_usage.sql @@ -0,0 +1,116 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: HTML Report column usage for SQL queries and indexes +-- +-- HTML Report - Table column used in SQL Statements but not indexed and +-- all indexes with more than one column to check for duplicate indexing +-- +--============================================================================== + +define OWNER = '&1' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt + +variable own varchar2(20); +exec :own := upper('&&OWNER'); + + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_col_usage.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + +spool &&SPOOL_NAME + +set markup html on + +ttitle center "Columns usesd in SQL Queries but not indexed" SKIP 2 + +set verify off +SET linesize 130 pagesize 2000 + +column owner format a20 +column object_name format a30 +column column_name format a25 + +column equality_preds format 99999 heading "equ" +column equijoin_preds format 99999 heading "Jequ" +column nonequijoin_preds format 99999 heading "Jnoe" +column range_preds format 99999 heading "ran" +column like_preds format 99999 heading "lik" +column null_preds format 99999 heading "nul" + +select o.owner + ,o.object_name + ,c.name as column_name + ,u.equality_preds + ,u.range_preds + ,u.like_preds + ,u.null_preds + ,u.equijoin_preds + ,u.nonequijoin_preds + from sys.col_usage$ u + ,dba_objects o + ,sys.col$ c + where u.obj# = o.OBJECT_ID + and u.obj# = c.obj# + and u.intcol# = c.col# + and o.owner like :own + and not exists (select 1 + from dba_ind_columns i + where i.table_owner = o.owner + and i.table_name = o.object_name + and i.column_name = c.name) + order by o.owner + ,o.object_name + ,c.name +/ + + +ttitle center "Index with more then one Columns" SKIP 2 + +SET linesize 130 pagesize 2000 + +column index_owner format a25 +column index_name format a25 +column table_name format a25 +column column_name format a25 +column pos1 format a25 +column pos2 format a25 +column pos3 format a25 +column pos4 format a25 +column pos5 format a25 +column pos6 format a25 +column pos7 format a25 +column pos8 format a25 +column pos9 format a25 + +select * + from (select * + from (select index_owner + ,table_name + ,index_name + ,column_name + ,column_position + from dba_ind_columns + where index_owner like :own + order by index_owner + ,table_name) pivot(min(column_name) for column_position in('1' as pos1, '2' as pos2, + '3' as pos3, '4' as pos4, '5' as pos5, + '6' as pos6, '7' as pos7, '8' as pos8, + '9' as pos9))) + where pos2 is not null +/ + +set markup html off +spool off +ttitle off + +-- works only in a ms windows enviroment +-- autostart of the result in a browser window +host &&SPOOL_NAME diff --git a/checkpoint.sql b/checkpoint.sql new file mode 100644 index 0000000..f97cdaa --- /dev/null +++ b/checkpoint.sql @@ -0,0 +1,16 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +--============================================================================== +set linesize 130 pagesize 300 + +@select v$instance_recovery; + + +prompt RECOVERY_ESTIMATED_IOS => geschaetzte Anzahl von Bloecken fuer das aktuelle Recovery beim Einsatz des FAST_START_IO_TARGET Parameters +prompt ACTUAL_REDO_BLKS => Anzahl von Bloecken fuer das Recovery +prompt TARGET_REDO_BLKS => Ziel fuer die minimale Anzahl, der zu lesenden Bloecke beim Recovery (Minium der unteren Spalten) (Checkpoint Ausloeser!) +prompt LOG_FILE_SIZE_REDO_BLKS => Maximale Anzahl Redos, die sicherstellen, das ein Log Switch nicht stattfindet bevor ein Checkpoint komplett erfolgt ist +prompt LOG_CHKPT_TIMEOUT_REDO_BLKS => Anzahl der Bloecke um den Parameter LOG_CHECKPOINT_TIMEOUT zu erfuellen +prompt LOG_CHKPT_INTERVAL_REDO_BLKS => Anzahl der Bloecke um den Parameter LOG_CHECKPOINT_INTERVALL zu erfuellen +prompt FAST_START_IO_TARGET_REDO_BLKS => Anzahl der Bloecke um den Parameter FAST_START_IO_TARGET zu erfuellen + diff --git a/clean_user.sql b/clean_user.sql new file mode 100644 index 0000000..52af8b6 --- /dev/null +++ b/clean_user.sql @@ -0,0 +1,211 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: Script to create a sql script to clean Oracle schema from the all user objects +-- Parameter 1: Name of the User +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== + + +set verify off +set linesize 100 pagesize 4000 + +define USER_NAME = &1 + +col SPOOL_NAME_COL new_val SPOOL_NAME + +prompt ==================== SQL Script Name ========================= +column SPOOL_NAME_COL format a60 + +select replace(ora_database_name || '_' || SYS_CONTEXT('USERENV', 'HOST') || '_' || + to_char(sysdate, 'dd_mm_yyyy_hh24_mi') || '_drop_&&USER_NAME..sql', '\', '_') + --' resolve syntax highlight bug FROM my editor .-( + as SPOOL_NAME_COL + from dual +/ + +prompt +prompt ==================== User Objects Overview =================== +prompt +select owner + ,obj_type + ,obj_count + from (select count(*) as obj_count + ,object_type as obj_type + ,owner + from dba_objects + group by object_type + ,owner) + where upper(owner) in (upper('&&USER_NAME.')) + group by owner + ,obj_type + ,obj_count + order by owner + ,obj_type +/ + +prompt +prompt ==================== Create Delete Script ==================== +prompt + +set feedback off +set heading off + +spool &&SPOOL_NAME + +prompt set echo on +prompt spool &&SPOOL_NAME.log + + +-- drop all queue of the user + +select 'EXECUTE DBMS_AQADM.STOP_QUEUE ( queue_name => ''' || q.owner || '.' || q.name || ''');' + from DBA_QUEUES q + where upper(q.owner) in (upper('&&USER_NAME.')) +/ + +select 'EXECUTE DBMS_AQADM.DROP_QUEUE ( queue_name => ''' || q.owner || '.' || q.name || ''');' + from DBA_QUEUES q + where upper(q.owner) in (upper('&&USER_NAME.')) +/ + +select 'EXECUTE DBMS_AQADM.DROP_QUEUE_TABLE ( queue_table => ''' || q.owner || '.' || q.QUEUE_TABLE || + ''', force => true);' + from DBA_QUEUES q + where upper(q.owner) in (upper('&&USER_NAME.')) +/ + +-- drop XML Schema definitions from this user + XML Tables +-- not tested yet! +-- some time DBA_XML_SCHEMAS not exits in the database +-- +-- select 'begin ' +-- || chr(10) +-- ||'DBMS_XMLSCHEMA.deleteSchema(SCHEMAURL => ''' || x.SCHEMA_URL ||'''' +-- || chr(10) +-- ||',DELETE_OPTION => dbms_xmlschema.DELETE_CASCADE_FORCE); ' +-- || chr(10) +-- || 'end; ' +-- || chr(10) +-- || '/ ' +-- || chr(10) +-- from DBA_XML_SCHEMAS x +-- where upper(x.owner) in (upper('&&USER_NAME.')) +-- / + + +-- drop table constraints +-- to avoid FK Contraint Errors! +select 'alter table ' || c.OWNER || '."' || c.TABLE_NAME || '" drop CONSTRAINT "' || c.CONSTRAINT_NAME || '";' + from DBA_CONSTRAINTS c + where c.CONSTRAINT_TYPE in ('R', 'U') + and not exists (select 1 + from DBA_CONSTRAINTS i + where i.OWNER = c.owner + and i.TABLE_NAME = c.TABLE_NAME + and i.CONSTRAINT_NAME = c.CONSTRAINT_NAME + and c.CONSTRAINT_TYPE = 'P') + and upper(c.owner) in (upper('&&USER_NAME.')) +/ + +-- drop all indexes not primary key will be dropped with the table +-- May be unnecessary - will be dropped also with the table + +select 'drop index ' || i.owner || '."' || i.index_name || '";' + from dba_indexes i + where i.index_type not in ('LOB') + and i.table_name not in (select q.QUEUE_TABLE from DBA_QUEUES q where q.owner = i.owner) + and i.index_name not in (select ii.index_name + from DBA_CONSTRAINTS ii + where ii.OWNER = i.owner + and ii.TABLE_NAME = i.TABLE_NAME + and ii.CONSTRAINT_TYPE not in ('P')) + and upper(i.owner) in (upper('&&USER_NAME.')) +/ + + +--- drop materialised views +select 'drop MATERIALIZED VIEW ' || m.owner || '."' || m.MVIEW_NAME || '" ' || ';' as command +from dba_mviews m +where upper(m.owner) in (upper('&&USER_NAME.')) +/ + +-- drop all other objects in the right order +select 'drop ' || o.object_type || ' ' || o.owner || '."' || o.object_name || '" ' || + decode(o.object_type, 'TABLE', 'CASCADE CONSTRAINTS PURGE', '') || ';' as command + from dba_objects o +where o.object_type in + ('SEQUENCE', 'JAVA DATA', 'PROCEDURE', 'PACKAGE', 'PACKAGE BODY', 'TYPE BODY', 'JAVA RESOURCE', 'DIRECTORY', + 'TABLE', 'SYNONYM', 'VIEW', 'FUNCTION', 'JAVA CLASS', 'JAVA SOURCE', 'TYPE') + and upper(o.owner) in (upper('&&USER_NAME.')) + and o.object_name not in (select oi.MVIEW_NAME from dba_mviews oi where oi.owner = o.owner) + and o.object_name not in (select q.QUEUE_TABLE from DBA_QUEUES q where q.owner = o.owner) +order by decode (o.object_type + ,'SEQUENCE',20 + ,'JAVA DATA',10 + ,'PROCEDURE',21 + ,'PACKAGE',24 + ,'PACKAGE BODY',23 + ,'TYPE BODY',41 + ,'JAVA RESOURCE',11 + ,'DIRECTORY',80 + ,'TABLE',35 + ,'SYNONYM',40 + ,'VIEW',20 + ,'FUNCTION',22 + ,'JAVA CLASS',11 + ,'JAVA SOURCE',12 + ,'TYPE',42 + ,99) +/ + + +prompt -- !Attention +prompt -- delete the ALL RECYCLEBIN's in the database +prompt -- please comment if you don't like it as DBA +--prompt PURGE DBA_RECYCLEBIN +prompt PURGE RECYCLEBIN +prompt / +-- + +prompt prompt +prompt prompt ==================== User Objects Overview after the delete =================== +prompt prompt +prompt select owner +prompt ,obj_type +prompt ,obj_count +prompt from (select count(*) as obj_count +prompt ,object_type as obj_type +prompt ,owner +prompt from dba_objects +prompt group by object_type +prompt ,owner) +prompt where upper(owner) in (upper('&&USER_NAME.')) +prompt group by owner +prompt ,obj_type +prompt ,obj_count +prompt order by owner +prompt ,obj_type +prompt / +prompt prompt ==================== User Objects Overview after the delete =================== + +prompt spool off +prompt exit + +spool off +set heading on +set verify on + +prompt +prompt ==================== Finish Delete Script ==================== +prompt == +prompt == to drop the objects of the user &&USER_NAME. +prompt == call the script: +prompt == &&SPOOL_NAME +prompt == and check the log file for the results +prompt == &&SPOOL_NAME.log +prompt == +prompt ============================================================== + diff --git a/column.sql b/column.sql new file mode 100644 index 0000000..36259a1 --- /dev/null +++ b/column.sql @@ -0,0 +1,53 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: search a column in the database +-- Parameter 1: Name of the column +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== + + +set verify off +set linesize 130 pagesize 300 + +define COL_NAME = '&1' + +prompt +prompt Parameter 1 = Column Name => &&COL_NAME. +prompt + + +column owner format a10 heading "Owner" +column table_name format a22 heading "Table|Name" +column COLUMN_NAME format a30 heading "Column|Name" +column comments format a25 heading "Comment on |this column" +column data_type format a23 heading "Data type" +column data_default format a10 heading "Column default" +column nullable format a4 heading "Null ?" +column char_length format a4 heading "Char Count" + + +select t.OWNER + , t.TABLE_NAME + , t.COLUMN_NAME + , case t.data_type + when 'VARCHAR2' then 'varchar2('||lpad(data_length,5)||' '|| decode(t.char_used,'B','Byte','C','Char',t.char_used)||')' + when 'NUMBER' then 'number ('||lpad(data_length,5)|| nvl(t.data_precision,'') ||' '|| nvl(t.DATA_SCALE,'') ||')' + when 'DATE' then 'date' + when 'LONG' then 'long' + else rpad(lower(t.data_type),8) ||'('||lpad(t.data_length,5)||nvl(t.data_precision,'') ||')' + end as data_type + , case when char_length > 0 then to_char(t.char_length) else '-' end as char_length + , decode(nullable,'Y','YES','NO') as nullable + , data_default + , c.comments + from dba_tab_columns t + , DBA_COL_COMMENTS c + where t.COLUMN_NAME like upper('&&COL_NAME.') + and t.OWNER=c.OWNER (+) + and t.TABLE_NAME = c.TABLE_NAME (+) + and t.COLUMN_NAME = c.COLUMN_NAME (+) +order by OWNER,TABLE_NAME,COLUMN_NAME +/ diff --git a/column_type.sql b/column_type.sql new file mode 100644 index 0000000..52b1e62 --- /dev/null +++ b/column_type.sql @@ -0,0 +1,38 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: search all columns with this type in the database +-- Parameter 1: Type of the column +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define COL_TYPE = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Column Type => &&COL_TYPE. +prompt + +column owner format a15 heading "Qwner" +column table_name format a25 heading "Table|Name" +column column_name format a20 heading "Column|Name" +column comments format a50 heading "Comment on this table/view" + +select t.OWNER + , t.TABLE_NAME + , t.COLUMN_NAME + , c.comments + from dba_tab_columns t + , dba_col_comments c + where DATA_TYPE like upper ('&&COL_TYPE.') + and t.OWNER = c.OWNER(+) + and t.TABLE_NAME = c.TABLE_NAME(+) + and t.COLUMN_NAME = c.COLUMN_NAME(+) + and t.owner = upper ('&&OWNER.') +order by OWNER, TABLE_NAME, COLUMN_NAME +/ diff --git a/comment.sql b/comment.sql new file mode 100644 index 0000000..1ae9cbc --- /dev/null +++ b/comment.sql @@ -0,0 +1,44 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: search the table in the database +-- Parameter 1: Name of the table +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define COMMENTTXT = '&1' + +prompt +prompt Parameter 1 = Part of Comment => &&COMMENTTXT. +prompt + +column owner format a15 heading "Qwner" +column table_name format a30 heading "Table/View Name" +column otype format a5 heading "Type" +column comments format a60 heading "Comment on this table/view" + +select t.owner + , t.table_name + , 'table' as otype + , nvl(c.comments,'n/a') as comments +from all_tables t + ,all_tab_comments c + where upper(c.comments) like upper('%&&COMMENTTXT.%') + and c.table_name = t.table_name + and c.owner = t.owner + and c.table_type = 'TABLE' +union + select v.owner + , v.view_name + , 'view' as otype + , nvl(c.comments,'n/a') as comments + from all_views v + ,all_tab_comments c + where upper(c.comments) like upper('%&&COMMENTTXT.%') + and c.table_name = v.view_name + and c.owner = v.owner + and c.table_type = 'VIEW' +order by 1,2 +/ + + diff --git a/connection_pool.sql b/connection_pool.sql new file mode 100644 index 0000000..df1b0c6 --- /dev/null +++ b/connection_pool.sql @@ -0,0 +1,133 @@ +-- ====================================== +-- GPI - Gunther Pippèrr +-- Database Resident Connection Pooling (DRCP) +-- ======================================= +-- Master Note: Overview of Database Resident Connection Pooling (DRCP) (Doc ID 1501987.1) +-- ======================================= +set linesize 130 pagesize 300 + +column CONNECTION_POOL format a30 heading "CONNECTION|POOL" +column STATUS format a10 heading "STATUS" +column MINSIZE format 99 heading "MINSIZE" +column MAXSIZE format 999 heading "MAXSIZE" +column INCRSIZE format 99 heading "INCRSIZE" +column SESSION_CACHED_CURSORS format 999 heading "SESSION|CACHED_CURSORS" +column INACTIVITY_TIMEOUT format 999 heading "INACTIVITY|TIMEOUT" +column MAX_THINK_TIME format 999 heading "MAX_THINK_TIME" +column MAX_USE_SESSION format 999999 heading "MAX_USE|SESSION" +column MAX_LIFETIME_SESSION format 999999 heading "MAX_LIFETIME|SESSION" +column NUM_CBROK format 99 heading "NUM|CBROK" +column MAXCONN_CBROK format 999999 heading "MAXCONN|CBROK" + +ttitle "Settings of the connection pool" skip 2 + +select CONNECTION_POOL + , STATUS + , MINSIZE + , MAXSIZE + , INCRSIZE + , SESSION_CACHED_CURSORS + , INACTIVITY_TIMEOUT + , MAX_THINK_TIME + , MAX_USE_SESSION + , MAX_LIFETIME_SESSION + , NUM_CBROK + , MAXCONN_CBROK +from DBA_CPOOL_INFO +order by 1 +/ + +----------------------------------------------------------- + + +column POOL_NAME format a30 heading "POOL|NAME" +column NUM_OPEN_SERVERS format 9999 heading "NUM_OPEN|SERVERS" +column NUM_BUSY_SERVERS format 9999 heading "NUM_BUSY|SERVERS" +column NUM_AUTH_SERVERS format 9999 heading "NUM_AUTH|SERVERS" +column NUM_REQUESTS format 9999 heading "NUM|REQUESTS" +column NUM_HITS format 9999 heading "NUM|HITS" +column NUM_MISSES format 9999 heading "NUM|MISSES" +column NUM_WAITS format 9999 heading "NUM|WAITS" +column WAIT_TIME format 9999 heading "WAIT|TIME" +column CLIENT_REQ_TIMEOUTS format 9999 heading "CLIENT_REQ|TIMEOUTS" +column NUM_AUTHENTICATIONS format 9999 heading "NUM|AUTHENTICATIONS" +column NUM_PURGED format 9999 heading "NUM|PURGED" +column HISTORIC_MAX format 9999 heading "HISTORIC|MAX" + +ttitle "Statistics of the connection pool usage" skip 2 + +select POOL_NAME + ,NUM_OPEN_SERVERS + ,NUM_BUSY_SERVERS + ,NUM_AUTH_SERVERS + ,NUM_REQUESTS + ,NUM_HITS + ,NUM_MISSES + ,NUM_WAITS + ,WAIT_TIME + ,CLIENT_REQ_TIMEOUTS + ,NUM_AUTHENTICATIONS + ,NUM_PURGED + ,HISTORIC_MAX +from V$CPOOL_STATS + order by 1 +/ + + +ttitle "Statistics about the connection class level statistics for the pool per instance" skip 2 + +column CCLASS_NAME format a20 heading "CCLASS|NAME" +column NUM_REQUESTS format 999 heading "NUM|REQUESTS" +column NUM_HITS format 999 heading "NUM|HITS" +column NUM_MISSES format 999 heading "NUM|MISSES" +column NUM_WAITS format 999 heading "NUM|WAITS" +column WAIT_TIME format 999 heading "WAIT|TIME" +column CLIENT_REQ_TIMEOUTS format 999 heading "CLIENT|REQ_TIMEOUTS" +column NUM_AUTHENTICATIONS format 999 heading "NUM|AUTHENTICATIONS" + + +select CCLASS_NAME + , NUM_REQUESTS + , NUM_HITS + , NUM_MISSES + , NUM_WAITS + , WAIT_TIME + , CLIENT_REQ_TIMEOUTS + , NUM_AUTHENTICATIONS +from V$CPOOL_CC_STATS +/ + +ttitle "Session using DRCP" skip 2 + +column USERNAME format a20 heading "USERNAME" +column PROXY_USER format a10 heading "PROXY|USER" +column CCLASS_NAME format a15 heading "CCLASS|NAME" +column PURITY format a10 heading "PURITY" +column TAG format a10 heading "TAG" +column SERVICE format a10 heading "SERVICE" +column PROGRAM format a15 heading "PROGRAM" +column MACHINE format a15 heading "MACHINE" +column TERMINAL format a15 heading "TERMINAL" +column CONNECTION_MODE format a10 heading "CONN|MODE" +column CONNECTION_STATUS format a10 heading "CONN|STATUS" +column CLIENT_REGID format 9999 heading "CLIENT|REGID" + +select USERNAME + , PROXY_USER + , CCLASS_NAME + , PURITY + --, TAG + , SERVICE + , PROGRAM + --, MACHINE + , TERMINAL + , CONNECTION_MODE + , CONNECTION_STATUS + , CLIENT_REGID +from V$CPOOL_CONN_INFO +order by 1 +/ + + +ttitle off + diff --git a/create_all_statistic.sql b/create_all_statistic.sql new file mode 100644 index 0000000..a55c8d2 --- /dev/null +++ b/create_all_statistic.sql @@ -0,0 +1,145 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: recreate the statistic of a database +-- Date: 01.2013 +-- Doku: http://www.pipperr.de/dokuwiki/doku.php?id=dba:statistiken +-- +-- Src: +-- http://psoug.org/reference/system_stats.html +-- http://docs.oracle.com/cd/E11882_01/server.112/e40402/initparams040.htm#REFRN10023 +-- http://docs.oracle.com/cd/E18283_01/server.112/e16638/stats.htm +--============================================================================== + + +----------------------------------------------- +set timing on +set serveroutput on +set linesize 256 +set pagesize 200 +set echo on +set serveroutput on + +define degree = "1" +----------------------------------------------- + +column last format a14 +column owner format a20 +column table_name format a30 + +spool recreate_stat.log + + + +select count (*), owner, to_char (LAST_ANALYZED, 'dd.mm.yyyy') as last + from dba_tables +group by owner, to_char (LAST_ANALYZED, 'dd.mm.yyyy'), to_char (LAST_ANALYZED, 'YYYYDDMM') +order by owner, to_char (LAST_ANALYZED, 'YYYYDDMM') desc +/ + + +----------------------------------------------- +-- delete all old statistics if necessary +-- +--exec DBMS_STATS.DELETE_DATABASE_STATS; +--exec DBMS_STATS.DELETE_DICTIONARY_STATS; +--exec DBMS_STATS.DELETE_FIXED_OBJECTS_STATS; +----------------------------------------------- + +----------------------------------------------- +-- gather first system stats over the io of the creation of the system statistic +exec DBMS_STATS.gather_system_stats('Start'); + +----------------------------------------------- +-- +exec DBMS_STATS.gather_fixed_objects_stats; + + +----------------------------------------------- +-- +exec DBMS_STATS.GATHER_DICTIONARY_STATS (estimate_percent => 100, degree => &°ree ,options => 'GATHER') + + +----------------------------------------------- +-- + +declare + cursor c_owner + is + select owner + from dba_tables + where owner not in ('SYS', 'SYSTEM', 'XDB') + -- System User statitiken anlegen? + -- and owner not in ('MDSYS','SI_INFORMTN_SCHEMA','ORDPLUGINS','ORDDATA','ORDSYS','EXFSYS','XS$NULL','CTXSYS','WMSYS','APPQOSSYS','DBSNMP','ORACLE_OCM','DIP','OUTLN','FLOWS_FILES','OLAPSYS','OWBSYS','OWBSYS_AUDIT') + group by owner; + + v_parallel number := &°ree; +begin + dbms_output.put_line ( + '-- Info Start Anlegen der neuen Statisiken für die DB User um ::' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + dbms_output.put_line ('-----------------------'); + + for rec in c_owner + loop + dbms_output.put_line ( + '-- Info Starte das Anlegen der Statisik für den User ::' + || rec.owner + || ' um ::' + || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + + if rec.owner not in ('MAIN_USER') + then + -- keine histogramme + dbms_stats.gather_schema_stats (ownname => rec.owner + , options => 'GATHER' + , estimate_percent => dbms_stats.auto_sample_size + , cascade => true + , degree => v_parallel); + else + -- Mit Histogrammen + dbms_stats.gather_schema_stats (ownname => rec.owner + , cascade => true + , estimate_percent => dbms_stats.AUTO_SAMPLE_SIZE + , Block_Sample => false + , degree => v_parallel + , no_invalidate => true + , granularity => 'ALL' + , method_opt => 'FOR ALL COLUMNS SIZE AUTO'); + end if; + + dbms_output.put_line ( + '-- Info Anlegen der Statisik für den User ::' + || rec.owner + || ' beendet um ::' + || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + + dbms_output.put_line ('-----------------------'); + end loop; + + dbms_output.put_line ('-----------------------'); + dbms_output.put_line ( + '-- Info Anlegen der neuen Statisiken für die DB User um ::' || to_char (sysdate, 'dd.mm.yyyy hh24:mi') || ' beendet'); +end; +/ + +----------------------------------------- +-- Falls etwas fehlt +exec DBMS_STATS.GATHER_DATABASE_STATS (degree=>&°ree,options=>'GATHER AUTO' ); + +----------------------------------------- +-- end system statistic +execute DBMS_STATS.gather_system_stats('Stop'); + +------------------------------------------ + + select count (*), owner, to_char (LAST_ANALYZED, 'dd.mm.yyyy') as last + from dba_tables +group by owner, to_char (LAST_ANALYZED, 'dd.mm.yyyy'), to_char (LAST_ANALYZED, 'YYYYDDMM') +order by owner, to_char (LAST_ANALYZED, 'YYYYDDMM') desc +/ + +spool off; + + +set echo off +set timing off + diff --git a/create_mon_index.sql b/create_mon_index.sql new file mode 100644 index 0000000..8b3c47e --- /dev/null +++ b/create_mon_index.sql @@ -0,0 +1,130 @@ +-- ================================================= +-- GPI - Gunther Pippèrr +-- Desc: create the scripts to enable and disable +-- ================================================= +set verify off +set linesize 130 pagesize 4000 + +define OWNER = '&1' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt + +variable own varchar2(20); +exec :own := upper('&&OWNER'); + +set heading off + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_enable_monitoring','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + + +----------------------------------------------------------------- +-- on +----------------------------------------------------------------- + +spool &&SPOOL_NAME._on.sql + +prompt +prompt spool recreate_&&SPOOL_NAME._on.log +prompt + +prompt prompt ============ Start ================ +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as start_date from dual +prompt / +prompt prompt =================================== +prompt +prompt + +prompt set heading on +prompt set echo on +prompt set feedback on +prompt set define off +prompt ALTER SESSION SET ddl_lock_timeout=5; + +select 'alter index '||owner||'.'||index_name||' monitoring usage;' + from all_indexes +where owner=:own + and table_owner=:own +order by table_name, index_name +/ + +prompt +prompt prompt ============ Finish ================ +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as finish_date from dual +prompt / +prompt prompt =================================== +prompt +prompt prompt to check the log see recreate_&&SPOOL_NAME._on.log + +prompt set heading on +prompt set feedback off +prompt set define on +prompt spool off + +spool off; + +----------------------------------------------------------------- +-- off +----------------------------------------------------------------- + +spool &&SPOOL_NAME._off.sql + +prompt +prompt spool recreate_&&SPOOL_NAME._off.log +prompt +prompt prompt ============ Start ================ +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as start_date from dual +prompt / +prompt prompt =================================== +prompt +prompt + +prompt set heading on +prompt set echo on +prompt set feedback on +prompt set define off +prompt ALTER SESSION SET ddl_lock_timeout=5; + +select 'alter index '||owner||'.'||index_name||' nomonitoring usage;' + from all_indexes +where owner=:own + and table_owner=:own +order by table_name, index_name +/ + +prompt +prompt prompt ============ Finish ================ +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as finish_date from dual +prompt / +prompt prompt =================================== +prompt +prompt prompt to check the log see recreate_&&SPOOL_NAME._off.log + +prompt set heading on +prompt set feedback off +prompt set define on +prompt spool off + +spool off + +----------------------------------------------------------------- + +prompt ......... +prompt to enable index monitoring for all indexes of this user use: +prompt &&SPOOL_NAME._on.sql +prompt + +prompt ......... +prompt to disable index monitoring for all indexes of this user use: +prompt &&SPOOL_NAME._off.sql +prompt + +set heading on + diff --git a/ctx.sql b/ctx.sql new file mode 100644 index 0000000..4e4ebdf --- /dev/null +++ b/ctx.sql @@ -0,0 +1,155 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the oracle text parameters of one schema user +-- Parameter 1: Name of the User +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +-- may be later helpfull for indexed tables? +--select * +-- from dba_lobs +--where upper(owner) in (upper('&&USER_NAME.')) +--/ + +ttitle left "Oracle Text Indexes for the user &&USER_NAME." skip 2 + +column idx_owner format a15 heading "Qwner" +column table_name format a35 heading "Table/View Name" +column idx_name format a25 heading "Name" +column idx_status format a8 heading "Status" +column idx_type format a12 heading "Index Type" + +select idx_owner + ,idx_name + ,idx_table_owner||'.'||idx_table as table_name + ,idx_status + ,idx_type + from ctxsys.ctx_indexes + where upper(idx_owner) in (upper('&&USER_NAME.')) +/ + +-- +-- create the CTX_REPORT.DESCRIBE_INDEX sql's +-- + +set long 64000 +set pages 0 +set heading off +set feedback off +spool get_ctx_desc_report.sql +prompt set long 64000 +prompt set longchunksize 64000 +prompt set head off +prompt set echo on +prompt spool ctx_desc_report.txt +select 'select ctx_report.describe_index('''||idx_owner||'.'||idx_name||''') from dual;' + from ctxsys.ctx_indexes + where upper(idx_owner) in (upper('&&USER_NAME.')) +/ +prompt spool off +prompt exit +spool off + +-- create the anlyse script +spool get_ctx_stat_report.sql +prompt set echo on +prompt set serveroutput on +prompt create table ctx_report_output (ctx_name varchar2(40), result CLOB) +prompt / +prompt +prompt declare +prompt x clob := null;; +prompt begin +prompt ctx_output.start_log('ix_search_stats.log');; +select ' ctx_report.INDEX_STATS('''||idx_owner||'.'||idx_name||''',x);' + ||chr(10) + ||' insert into ctx_report_output values ('''||idx_name||''',x);' + ||chr(10) + ||' commit;' + from ctxsys.ctx_indexes + where upper(idx_owner) in (upper('&&USER_NAME.')) +/ +prompt ctx_output.end_log;; +prompt dbms_lob.freetemporary(x);; +prompt end;; +prompt / +prompt +prompt set long 64000 +prompt set longchunksize 64000 +prompt set head off +prompt set pagesize 10000 +prompt spool ctx_stat_report.txt +prompt select result +prompt from ctx_report_output +prompt / +prompt spool off +prompt exit +spool off + +set pages 100 +set heading on +set feedback on + +prompt ... to get the full informations over the indexes call the generated +prompt ... sql report @get_ctx_desc_report.sql +prompt +prompt ... to get the statistic informations over the indexes call the generated +prompt ... sql report @get_ctx_stat_report.sql +prompt ... +prompt ... check for the run if the log directory ORACLE_HOME/ctx/log exits! +prompt ... + +ttitle left "Oracle Text Parameters" skip 2 + +column par_name format a25 heading "Parameter" +column par_value format a30 heading "Value" + +select par_name + , par_value + from ctxsys.ctx_parameters +order by 1 +/ + +ttitle left "Oracle Text Preferences" skip 2 + + +column pre_owner format a15 heading "Owner" +column pre_name format a35 heading "Parameter" +column pre_class format a15 heading "Class" +column pre_object format a35 heading "Object" + +select pre_owner + , pre_name + , pre_class + , pre_object + from ctxsys.ctx_preferences + where upper(pre_owner) in (upper('&&USER_NAME.')) +order by 1,2,3 +/ + +ttitle left "Oracle Text Attributes" skip 2 + +column prv_owner format a15 heading "Owner" +column prv_preference format a30 heading "Perference" +column prv_attribute format a20 heading "Attribute" +column prv_value format a50 heading "Value" + +select prv_owner + , prv_preference + , prv_attribute + , prv_value + from ctxsys.ctx_preference_values + where upper(prv_owner) in (upper('&&USER_NAME.')) +order by 1,2,3,4 +/ + +ttitle off + diff --git a/cursor.sql b/cursor.sql new file mode 100644 index 0000000..f2777fc --- /dev/null +++ b/cursor.sql @@ -0,0 +1,135 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Informations about cursor usage in the database +-- Date: 08.2013 +--============================================================================== + +set linesize 130 pagesize 300 + +column user_name format a25 + +ttitle left "Open Cursor used summary" skip 2 + +select inst_id + , user_name + , count(*) + from gv$open_cursor +where user_name is not null -- and user_name not in ( 'SYS' ) +group by rollup (inst_id,user_name) +/ + +ttitle left "Open Cursor used by session" skip 2 +select inst_id + , sid + , user_name + , count(*) + from gv$open_cursor +where user_name is not null -- and user_name not in ( 'SYS' ) +group by inst_id,user_name,sid +order by 4,1,3 +/ + +column name format a30 heading "Statistic|Name" +column value format 999G999G999G999 heading "Statistic|value" + + +ttitle left "Open Cursor used by session over the statistic" skip 2 + +select a.value + , s.username + , s.sid + , s.serial# +from v$sesstat a + , v$statname b + , v$session s +where a.statistic# = b.statistic# + and s.sid=a.sid + and b.name = 'opened cursors current' + and s.username is not null + / + + +ttitle left "Open Cursor Statistic " skip 2 + +column execute_count format 999G999G999G999G999 heading "SQL Execution" +column parse_count format 999G999G999G999G999 heading "Parse Count" +column cursor_hits format 999G999G999G999G999 heading "Cursor Hits" +column hit_percentage_parse format 99D990 heading "Parse| % Total" +column hit_percentage_cursor format 99D990 heading "Cursor Cache | % Total" + +select inst_id + , execute_count + , parse_count + , round(parse_count/(execute_count/100),3) as hit_percentage_parse + , cursor_hits + , round(cursor_hits/(execute_count/100),3) as hit_percentage_cursor + from ( select name + , value + , inst_id + from gv$sysstat + where name in ('session cursor cache hits','parse count (total)','execute count') + ) + pivot ( + max (value) + FOR name + IN ( 'session cursor cache hits' AS cursor_hits + , 'parse count (total)' as parse_count + , 'execute count' as execute_count + ) + ) +/ + +prompt ... 11g Syntax if you hid an error on 10g! +prompt ... if Cursor Cache % Total is a relatively low percentage +prompt ... you should increate the DB Parameter session_cached_cursors + +ttitle left "Cursor Settings init.ora " skip 2 +show parameter cursor + + +ttitle left "Session cached Cursor Usage " skip 2 +-- +-- see also +-- SCRIPT - to Set the 'SESSION_CACHED_CURSORS' and 'OPEN_CURSORS' Parameters Based on Usage (Doc ID 208857.1) +-- + +select a.inst_id + , 'session_cached_cursors' parameter + , lpad(value, 5) value + , decode(value, 0, ' n/a', to_char(100 * used / value, '990') || '%') usage +from + ( select max(s.value) used , inst_id + from v$statname n + , gv$sesstat s + where n.name = 'session cursor cache count' and s.statistic# = n.statistic# + group by inst_id + ) a, + ( select value,inst_id + from gv$parameter + where name = 'session_cached_cursors' + ) b + where a.inst_id=b.inst_id +union all +select c.inst_id + , 'open_cursors' + , lpad(value, 5) + , to_char(100 * used / value, '990') || '%' +from + ( select s.inst_id , max((s.value)) used + from v$statname n + , gv$sesstat s + where n.name in ('opened cursors current') + and s.statistic# = n.statistic# + group by s.inst_id + ) c, + ( select value,inst_id + from gv$parameter + where name = 'open_cursors' + ) d + where c.inst_id=d.inst_id +order by 1,2 +/ +ttitle off + +prompt ... if usage percentage is a near 100% +prompt ... you should increate the DB Parameter session_cached_cursors \ No newline at end of file diff --git a/database.sql b/database.sql new file mode 100644 index 0000000..ca2eda3 --- /dev/null +++ b/database.sql @@ -0,0 +1,97 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Database information +-- Date: 01.September 2012 +-- +--============================================================================== + +set linesize 130 pagesize 300 + +column inst_id format 99 heading "Inst|Id" +column status format A8 heading "Inst|Status" +column name format A8 heading "DB|Name" +column created format A16 heading "DB Create|Time" +column host_name format A18 heading "Inst Server|Name" +column edition like host_name heading "DB|Version" +column inst_name format A8 heading "Instance|Name" + +column dbid format A12 heading "Database|Id" + +ttitle "Database Information" SKIP 2 + +SET UNDERLINE '=' + +select v.inst_id + , v.instance_name as inst_name + , v.status + , v.host_name + , to_char(d.dbid) as dbid + , d.name + , to_char(d.created,'dd.mm.yyyy hh24:mi') as created + , (select banner from v$version where banner like 'Oracle%') as edition + from gv$database d + ,gv$instance v +where d.inst_id=v.inst_id + order by v.instance_name +/ + +ttitle "Timezone Information" SKIP 2 + +SELECT * FROM v$timezone_file; + +ttitle "DB Log Mode" SKIP 2 + +column FORCE_LOGGING format a20 heading "Force Logging|enabled" +column LOG_MODE format a20 heading "Log|Mode" + +select LOG_MODE,FORCE_LOGGING from v$database; + +--archive log list + +ttitle "Block Change Tracking" SKIP 2 +column filename format a60 +select filename + , status + , bytes + from v$block_change_tracking +/ + +ttitle "MegaByte total DB Size for all files" SKIP 2 + +column mb_total format 999G999G999D00 heading "MegaByte |Total used on disk" +column mb_data format 999G999G999D00 heading "MegaByte |Data + Undo" +column mb_temp format 999G999G999D00 heading "MegaByte |Temporary" +column mb_redo format 999G999G999D00 heading "MegaByte |Redo logs" + +select round((a.data_size+b.temp_size+c.redo_size)/1024/1024,3) as mb_total + , round((a.data_size )/1024/1024,3) as mb_data + , round((b.temp_size)/1024/1024,3) as mb_temp + , round((c.redo_size)/1024/1024,3) as mb_redo +from ( select sum(bytes) data_size from dba_data_files ) a + ,( select nvl(sum(bytes),0) temp_size from dba_temp_files ) b + ,( select sum(bytes) redo_size from sys.v_$log ) c +/ + +ttitle "MegaByte DB Objects in use" SKIP 2 + +column mb_obj format 999G999G999D00 heading "MegaByte DB Objects" + +select round(sum(bytes)/1024/1024,3) as mb_obj + from dba_segments + --where segment_type!='TEMPORARY' +/ + +SET UNDERLINE '-' + +ttitle "Current SCN" SKIP 2 + +column current_scn format 99999999999999999999999999 + +SELECT name + , to_char(sysdate,'dd.mm.yyyy hh24:mi') + , current_scn +FROM v$database +/ + + +ttitle off diff --git a/datapump.sql b/datapump.sql new file mode 100644 index 0000000..65b3b94 --- /dev/null +++ b/datapump.sql @@ -0,0 +1,52 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Get Information about running data pump jobs +-- Date: November 2013 +--============================================================================== +set linesize 130 pagesize 300 + +column owner_name format a10; +column job_name format a20 +column state format a12 + +column operation like state +column job_mode like state + +ttitle "Datapump Jobs" SKIP 2 + + +select owner_name + , job_name + , operation + , job_mode + , state + , attached_sessions +from dba_datapump_jobs +where job_name not like 'BIN$%' +order by 1,2 +/ + +ttitle "Datapump Master Table" SKIP 2 + + +column status format a10; +column object_id format 99999999 +column object_type format a12 +column OBJECT_NAME format a25 + +select o.status + , o.object_id + , o.object_type + , o.owner||'.'||object_name as OBJECT_NAME +from dba_objects o + , dba_datapump_jobs j +where o.owner=j.owner_name + and o.object_name=j.job_name + and j.job_name not like 'BIN$%' order by 4,2 +/ + +ttitle off + +prompt ... +prompt ... check for "NOT RUNNING" Jobs +prompt ... \ No newline at end of file diff --git a/datapump/create_test_case.sql b/datapump/create_test_case.sql new file mode 100644 index 0000000..b46ac18 --- /dev/null +++ b/datapump/create_test_case.sql @@ -0,0 +1,36 @@ +-- Source DB + +create user GPIDBA identified by "xxxxxxxxxxxxxxxxx"; +grant connect, resource to GPIDBA + +grant DATAPUMP_EXP_FULL_DATABASE to GPIDBA + + +--- + + + + +-- Target/Destination + +create user GPIDBA identified by "xxxxxxxxxxxxxxxxx"; +grant connect, resource to GPIDBA; + +grant DATAPUMP_IMP_FULL_DATABASE to GPIDBA; + + +CREATE directory BACKUP AS "/opt/oracle/acfs/import"; + +GRANT READ,WRITE ON directory BACKUP TO GPIDBA; + +connect GPIDBA/"xxxxxxxxxxxxxxxxx" + +CREATE DATABASE LINK DP_TRANSFER CONNECT TO GPIDBA IDENTIFIED BY "xxxxxxxxxxxxxxxxx" USING 'TMGTSTDB'; + + +SQL> select global_name from global_name@DP_TRANSFER; + + + + + diff --git a/datapump/dp_import_stop_job.sql b/datapump/dp_import_stop_job.sql new file mode 100644 index 0000000..c394184 --- /dev/null +++ b/datapump/dp_import_stop_job.sql @@ -0,0 +1,119 @@ +CREATE OR REPLACE PROCEDURE dp_import_stop_job(p_job_name varchar2) +is +--- +---------------------------------- +-- +-- testcall exec db_import_stop_job(p_job_name => 'MY_JOB') +-- +-- +---------------------------------- + v_dp_handle NUMBER; + + cursor c_act_jobs is + + select job_name + , operation + , job_mode + , state + , attached_sessions + from user_datapump_jobs + where job_name not like 'BIN$%' + order by 1,2 + ; + + + v_job_exits boolean:=false; + v_job_mode varchar2(32); + v_job_state varchar2(32); + v_real_job_name varchar2(32); + v_count pls_integer; + + v_sts ku$_Status; + v_job_run_state varchar2(2000); + +BEGIN + + dbms_output.put_line(' -- Stop the Job Parameter ------------' ); + dbms_output.put_line(' -- p_job_name :: '|| p_job_name ); + + -- query all actual jobs + -- to show a list of candidates if job_name is wrong + -- + for rec in c_act_jobs + loop + if rec.job_name = upper(p_job_name) then + v_job_exits:=true; + v_real_job_name:=rec.job_name; + v_job_mode:=rec.job_mode; + v_job_state:=rec.state; + else + v_job_exits:=false; + end if; + dbms_output.put_line('--- Found this Job :: ' ||rec.job_name ); + dbms_output.put_line('+-- Operation :: ' ||rec.operation ); + dbms_output.put_line('+-- Mode :: ' ||rec.job_mode ); + dbms_output.put_line('+-- State :: ' ||rec.state ); + dbms_output.put_line('+-- Sessions :: ' ||rec.attached_sessions ); + end loop; + + if v_job_exits then + + + begin + -- Create Data Pump Handle - "ATTACH" in this case + v_dp_handle := DBMS_DATAPUMP.ATTACH( + job_name => v_real_job_name + ,job_owner => user); + + exception + when DBMS_DATAPUMP.NO_SUCH_JOB then + -- check if the old job table exits + select count(*) into v_count from user_tables where upper(table_name) = upper(v_real_job_name); + if v_count > 0 then + execute immediate 'drop table '||user||'."'||v_real_job_name||'"'; + end if; + + RAISE_APPLICATION_ERROR (-20003, '-- Error :: Job Not running anymore, check for other errors - no mastertable for '||p_job_name || ' get Error '||SQLERRM); + + when others then + RAISE_APPLICATION_ERROR (-20002, '-- Error :: Not possible to attach to the job - Error :: '||SQLERRM); + end; + + + if v_job_state in ('DEFINING') then + + -- check if the job is in the defining state! + -- abnormal situation, normal stop not possible + -- use DBMS_DATAPUMP.START_JOB to restart the job + + DBMS_DATAPUMP.START_JOB ( handle => v_dp_handle ); + + + end if; + + -- print the status + + dbms_datapump.get_status (handle => v_dp_handle + , mask => dbms_datapump.KU$_STATUS_WIP + , timeout => 0 + , job_state => v_job_run_state + , status => v_sts + ); + + dbms_output.put_line('+-- Akt State :: ' ||v_job_run_state ); + + + -- Stop the job + DBMS_DATAPUMP.STOP_JOB ( + handle => v_dp_handle + , immediate => 1 -- stop now + , keep_master => null -- delete Master table + , delay => 5 -- wait 5 seconds before kill for other sessions + ); + + else + RAISE_APPLICATION_ERROR (-20000, '-- Error :: This job name not found::'||p_job_name); + end if; + +end dp_import_stop_job; + +/ + \ No newline at end of file diff --git a/datapump/dp_import_table.sql b/datapump/dp_import_table.sql new file mode 100644 index 0000000..93d84d1 --- /dev/null +++ b/datapump/dp_import_table.sql @@ -0,0 +1,98 @@ +CREATE OR REPLACE PROCEDURE dp_import_table(p_tablename varchar2 + , p_mode varchar2) + +--- +---------------------------------- +-- Valid Parameter 'TRUNCATE', 'REPLACE', 'APPEND', 'SKIP' +-- testcall exec dp_import_table(p_tablename => 'T_ALL_OBJECTS', p_mode=> 'APPEND') +-- +-- +---------------------------------- + +IS + v_dp_handle NUMBER; + PRAGMA AUTONOMOUS_TRANSACTION; + + v_db_directory varchar2(200):='BACKUP'; + v_db_link varchar2(200):='DP_TRANSFER'; + v_job_name varchar2(256):=user ||'_IMPORT' || TO_CHAR (SYSDATE, 'DD_HH24'); + --v_log_file_name varchar2(256):=user||'_' || TO_CHAR (SYSDATE, 'YYYYMMDD-HH24MISS') || '.log'; + -- use same name to import the data later via external table + v_log_file_name varchar2(256):='db_import_plsql.log'; + +BEGIN + + dbms_output.put_line(' -- Import Parameter ------------' ); + + + dbms_output.put_line(' -- Tablename :: '|| p_tablename ); + dbms_output.put_line(' -- Replace Modus :: '|| p_mode); + + + dbms_output.put_line(' -- DB Link :: '|| v_db_link ); + dbms_output.put_line(' -- DB DIRECTORY :: '|| v_db_directory); + dbms_output.put_line(' -- DP JOB Name :: '|| v_job_name); + dbms_output.put_line(' -- DP Log File :: '|| v_log_file_name); + + + if upper(p_mode) not in ('TRUNCATE', 'REPLACE', 'APPEND', 'SKIP') then + RAISE_APPLICATION_ERROR (-20000, '-- Error :: This Tablemode is not supported ::'||p_mode); + end if; + + + -- Create Data Pump Handle - "IMPORT" in this case + v_dp_handle := DBMS_DATAPUMP.open (operation => 'IMPORT' + , job_mode => 'TABLE' + , job_name => v_job_name + , remote_link => v_db_link); + + -- No PARALLEL + DBMS_DATAPUMP.set_parallel (handle => v_dp_handle, degree => 1); + + -- consistent EXPORT + -- Consistent to the start of the export with the timestamp of systimestamp + -- + DBMS_DATAPUMP.SET_PARAMETER( + handle => v_dp_handle + , name => 'FLASHBACK_TIME' + , value => 'systimestamp' + ); + + -- TABLE_EXISTS_ACTION -- : TRUNCATE, REPLACE, APPEND, and SKIP. + DBMS_DATAPUMP.SET_PARAMETER( + handle => v_dp_handle + , name => 'TABLE_EXISTS_ACTION' + , value => upper(p_mode) + ); + + + --import only this table + + DBMS_DATAPUMP.metadata_filter ( handle => v_dp_handle + , name => 'NAME_EXPR' + , VALUE => 'IN ('''||p_tablename||''')'); + + + -- impprt from this Schema + + DBMS_DATAPUMP.metadata_filter (handle => v_dp_handle + , name => 'SCHEMA_EXPR' + , VALUE => 'IN ('''||user||''')'); + + + -- Logfile + DBMS_DATAPUMP.add_file (handle => v_dp_handle + ,filename => v_log_file_name + ,filetype => DBMS_DATAPUMP.KU$_FILE_TYPE_LOG_FILE + ,directory => v_db_directory + ,reusefile => 1 -- overwrite existing files + ,filesize => '10000M'); + + -- Do it! + DBMS_DATAPUMP.start_job (handle => v_dp_handle); + + COMMIT; + + + DBMS_DATAPUMP.detach (handle => v_dp_handle); + +END dp_import_table; +/ \ No newline at end of file diff --git a/datapump/dp_import_user_schema.sql b/datapump/dp_import_user_schema.sql new file mode 100644 index 0000000..98bb377 --- /dev/null +++ b/datapump/dp_import_user_schema.sql @@ -0,0 +1,73 @@ +CREATE OR REPLACE PROCEDURE dp_import_user_schema +IS + +--- +---------------------------------- +-- +-- testcall exec dp_import_user_schema +-- +-- +---------------------------------- + + + v_dp_handle NUMBER; + PRAGMA AUTONOMOUS_TRANSACTION; + + v_db_directory varchar2(200):='BACKUP'; + v_db_link varchar2(200):='DP_TRANSFER'; + v_job_name varchar2(256):=user ||'_IMPORT' || TO_CHAR (SYSDATE, 'DD_HH24'); + --v_log_file_name varchar2(256):=user||'_' || TO_CHAR (SYSDATE, 'YYYYMMDD-HH24MISS') || '.log'; + v_log_file_name varchar2(256):='db_import_plsql.log'; + +BEGIN + + dbms_output.put_line(' -- Import Parameter ------------' ); + dbms_output.put_line(' -- DB Link :: '|| v_db_link ); + dbms_output.put_line(' -- DB DIRECTORY :: '|| v_db_directory); + dbms_output.put_line(' -- DP JOB Name :: '|| v_job_name); + dbms_output.put_line(' -- DP Log File :: '|| v_log_file_name); + + + + -- Create Data Pump Handle - "IMPORT" in this case + v_dp_handle := DBMS_DATAPUMP.open (operation => 'IMPORT' + , job_mode => 'SCHEMA' + , job_name => v_job_name + , remote_link => v_db_link); + + -- No PARALLEL + DBMS_DATAPUMP.set_parallel (handle => v_dp_handle, degree => 1); + + -- consistent EXPORT + -- Consistent to the start of the export with the timestamp of systimestamp + -- + DBMS_DATAPUMP.SET_PARAMETER( + handle => v_dp_handle + , name => 'FLASHBACK_TIME' + , value => 'systimestamp' + ); + + + -- impprt the complete schema Filter + DBMS_DATAPUMP.metadata_filter (handle => v_dp_handle + , name => 'SCHEMA_EXPR' + , VALUE => 'IN ('''||user||''')'); + + + -- Logfile + DBMS_DATAPUMP.add_file (handle => v_dp_handle + ,filename => v_log_file_name + ,filetype => DBMS_DATAPUMP.KU$_FILE_TYPE_LOG_FILE + ,directory => v_db_directory + ,reusefile => 1 -- overwrite existing files + ,filesize => '10000M'); + + + -- Do it! + DBMS_DATAPUMP.start_job (handle => v_dp_handle); + + COMMIT; + + + DBMS_DATAPUMP.detach (handle => v_dp_handle); + +END dp_import_user_schema; +/ \ No newline at end of file diff --git a/datapump/external_table.sql b/datapump/external_table.sql new file mode 100644 index 0000000..7eb5d30 --- /dev/null +++ b/datapump/external_table.sql @@ -0,0 +1,23 @@ +drop table DP_DUMP_LOG; + +CREATE TABLE DP_DUMP_LOG ( + log_line VARCHAR2(4000) +) +ORGANIZATION EXTERNAL ( + TYPE ORACLE_LOADER + DEFAULT DIRECTORY backup + ACCESS PARAMETERS ( + RECORDS DELIMITED BY NEWLINE + FIELDS TERMINATED BY ',' + MISSING FIELD VALUES ARE NULL + ( + log_line CHAR(4000) + ) + ) + LOCATION ('db_import_plsql.log') +) +PARALLEL 1 +REJECT LIMIT UNLIMITED; + + +select * from DP_DUMP_LOG; \ No newline at end of file diff --git a/datapump_filter.sql b/datapump_filter.sql new file mode 100644 index 0000000..4535fb7 --- /dev/null +++ b/datapump_filter.sql @@ -0,0 +1,34 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Show the Data Pump Export/Import Filters +-- Parameter 1: Name of the Export Type +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define DP_TYPE = '&1' +define DP_PATH = '&2' + +prompt +prompt Parameter 1 = Data Pump Type => &&DP_TYPE. +prompt Parameter 2 = Data Pump PATH => &&DP_PATH. +prompt + +column seq_num format 999999 +column full_path format a80 heading "Full Name of the Object" +column het_type format a40 heading "Data Pump|Type of Ex/Import" + +select seq_num + , full_path + , het_type + from sys.datapump_paths +where het_type like upper('&&DP_TYPE.%') + and full_path like upper('%&&DP_PATH.%') +order by het_type,seq_num +/ + + diff --git a/date.sql b/date.sql new file mode 100644 index 0000000..744db7f --- /dev/null +++ b/date.sql @@ -0,0 +1,20 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the actual date of the database +-- +--============================================================================== +set linesize 130 pagesize 300 + +column DBTIMEZONE format a15 heading "Database|Time Zone" +column SESSIONTIMEZONE format a15 heading "Session|Time Zone" +column db_time format a18 heading "DB|Time" +column sess_time format a18 heading "Client|Time" +column diff_time format 999.999 heading "Time gap|Client <=> DB" + +select DBTIMEZONE + , to_char(sysdate,'dd.mm.yyyy hh24:mi') as db_time + , SESSIONTIMEZONE + , to_char(current_date,'dd.mm.yyyy hh24:mi') as sess_time + , sysdate-current_date as diff_time +from dual +/ diff --git a/db_alerts.sql b/db_alerts.sql new file mode 100644 index 0000000..d58d938 --- /dev/null +++ b/db_alerts.sql @@ -0,0 +1,142 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: OEM SQL Script Overview +-- Show the DB internal Alerting Setting + open Alerts +--============================================================================== +-- docu +-- Database metrics, e.g.Tablespace Full(%), not clearing in Grid Control even though they are no longer present in dba_outstanding_alerts (Doc ID 455222.1) +--============================================================================== + + +set linesize 130 pagesize 500 + +column metrics_name format a35 heading "Metric|Name" +column instance_name format a13 heading "Instance|Name" +column object_name format a15 heading "Object|Name" +column warning_operator format a8 heading "Warn|OP" WORD_WRAPPED +column warning_value format a8 heading "Warn|Value" WORD_WRAPPED +column critical_operator format a8 heading "Crit|OP" WORD_WRAPPED +column critical_value format a8 heading "Crit|Value" WORD_WRAPPED +column object_type format a12 heading "Object|Type" WORD_WRAPPED +column consecutive_occurrences format 999 heading "Con|Exec" +column observation_period format 999 heading "Ob|Per" + +ttitle left "show the metric setting in this database" skip 2 + +select object_name + , object_type + , metrics_name + , warning_operator + , warning_value + , critical_operator + , nvl(critical_value,'null') as critical_value + , observation_period + , consecutive_occurrences + , instance_name + from dba_thresholds +order by object_name + ,object_type + ,instance_name +/ + +prompt ... null means NULL!! +prompt ... to set the settings use db_alerts_set.sql +prompt ... + +ttitle left "Check for Metrics from other instances" skip 2 + +select count(*) + ,instance_name +from dba_thresholds +group by instance_name +/ + +prompt ... +prompt ... in a clon database you will find OLD values! +prompt ... + + +ttitle left "Show the outstanding alerts in this database" skip 2 + +select count(*) as total_message_count from sys.dba_outstanding_alerts +/ + +column reason format a40 heading "Reason" +column metric_value format 999G999 heading "Metric|Value" +column message_type format a10 heading "Message|Type" +column creation_time format a21 heading "Creation|Time" + +select reason + , metric_value + , message_type + , to_char(creation_time,'dd.mm.yyyy hh24:mi:ss') as creation_time + , INSTANCE_NAME +from sys.dba_outstanding_alerts +order by SEQUENCE_ID +/ + +prompt +prompt ... +prompt + + +ttitle left "Show the Alert Queue of this database" skip 2 + + +column name format a12 +column queue_table format a15 +column waiting format 999G999G999D99 +column ready format 999G999G999D99 +column expired format 999G999G999D99 +--column total_wait format 999G999G999D99 +--column average_wait format 999G999G999D99 +column owner format a10 +column retention format a10 + +select /*+ rule */ + d.queue_table + , q.waiting + , q.ready + , q.expired + , q.total_wait + , q.average_wait + , d.owner + , d.retention + from gv$aq q + , dba_queues d +where q.qid = d.qid + and d.name = 'ALERT_QUE' +/ + +prompt +prompt ... +prompt + + +ttitle left "Show the messages in the Alert Queue of this database" skip 2 + + +column q_name format a20 +column enq_time format a42 +column deq_time format a30 +column state format a30 +column user_data format a120 heading "User|Data" fold_before WORD_WRAPPED + +select '+--------- enq_time=> '||to_char(enq_time,'dd.mm.yyyy hh24:mi:ss') as enq_time + , 'deq_time=> '||to_char(deq_time,'dd.mm.yyyy hh24:mi:ss') as deq_time + , 'state => '|| state + , user_data + from sys.alert_qt + order by enq_time +/ + +prompt +prompt ... +prompt + + +ttitle off + + + + diff --git a/db_alerts_set.sql b/db_alerts_set.sql new file mode 100644 index 0000000..f832167 --- /dev/null +++ b/db_alerts_set.sql @@ -0,0 +1,110 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: set the threshold of a metric +-- Work in Progress +--============================================================================== + +/* +METRICS_NAME VARCHAR2(64) Metrics name +WARNING_OPERATOR VARCHAR2(12) Relational operator for warning thresholds: +GT +EQ +LT +LE +GE +CONTAINS +NE +DO NOT CHECK +DO_NOT_CHECK +WARNING_VALUE VARCHAR2(256) Warning threshold value +CRITICAL_OPERATOR VARCHAR2(12) Relational operator for critical thresholds: +GT +EQ +LT +LE +GE +CONTAINS +NE +DO NOT CHECK +DO_NOT_CHECK +CRITICAL_VALUE VARCHAR2(256) Critical threshold value +OBSERVATION_PERIOD NUMBER Observation period length (in minutes) +CONSECUTIVE_OCCURRENCES NUMBER Number of occurrences before an alert is issued +INSTANCE_NAME VARCHAR2(16) Instance name; NULL for database-wide alerts +OBJECT_TYPE VARCHAR2(64) Object type: +SYSTEM +SERVICE +EVENT_CLASS +TABLESPACE +FILE +OBJECT_NAME VARCHAR2(513) Name of the object for which the threshold is set +STATUS VARCHAR2(7) Indicates whether the threshold is applicable on a valid object (VALID) or not (INVALID) + +DBMS_SERVER_ALERT.SET_THRESHOLD( + metrics_id => DBMS_SERVER_ALERT.BLOCKED_USERS, + warning_operator => DBMS_SERVER_ALERT.OPERATOR_GT, + warning_value => '0', + critical_operator => NULL, + critical_value => NULL, + observation_period => 5, + consecutive_occurrences => 5, + instance_name => v_instance, + object_type => DBMS_SERVER_ALERT.OBJECT_TYPE_SESSION, + object_name => NULL + + +*/ + +declare + cursor c_metrics (p_instance_name varchar2) + is + select metrics_id + , object_type + , object_name + , instance_name + from table (dbms_server_alert.view_thresholds) + where instance_name = p_instance_name; + + v_instance varchar2 (32); + v_warning_operator binary_integer; + v_warning_value varchar2 (32); + v_critical_operator binary_integer; + v_critical_value varchar2 (32); + v_observation_period binary_integer; + v_consecutive_occurrences binary_integer; +begin + select instance_name into v_instance from v$instance; + + for rec in c_metrics (p_instance_name => 'TSTPBLM1') + loop + sys.dbms_output.put_line ('-- Info - read the Metric : ' || rec.metrics_id); + dbms_server_alert.get_threshold (metrics_id => rec.metrics_id + , warning_operator => v_warning_operator + , warning_value => v_warning_value + , critical_operator => v_critical_operator + , critical_value => v_critical_value + , observation_period => v_observation_period + , consecutive_occurrences => v_consecutive_occurrences + , instance_name => rec.instance_name + , object_type => rec.object_type + , object_name => rec.object_name); + + if v_warning_value != null + then + sys.dbms_output.put_line ('-- Info - unset the Metric : ' || rec.metrics_id); + dbms_server_alert.set_threshold (metrics_id => rec.metrics_id + , warning_operator => null + , warning_value => null + , critical_operator => null + , critical_value => null + , observation_period => null + , consecutive_occurrences => null + , instance_name => rec.instance_name + , object_type => rec.object_type + , object_name => rec.object_name); + end if; + + commit; + end loop; +end; +/ \ No newline at end of file diff --git a/db_events.sql b/db_events.sql new file mode 100644 index 0000000..dd632eb --- /dev/null +++ b/db_events.sql @@ -0,0 +1,43 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Event settings in the database, must be called as SYS +-- Date: 01.2014 +--============================================================================== +set linesize 130 pagesize 300 + +set feedback off +set serveroutput on + +declare + v_level number; + v_dbname varchar2 (30); + v_event_count pls_integer := 0; +begin + dbms_output.put_line (rpad ('-', 30, '-')); + + select name into v_dbname from v$database; + + for v_event in 10000 .. 999999 + loop + dbms_system.read_ev (v_event, v_level); + + if v_level > 0 + then + dbms_output.put_line ( + ' -- database:: ' || v_dbname || ' >> event ' || to_char (v_event) || ' is set at level ' || to_char (v_level)); + v_event_count := v_event_count+ 1; + end if; + end loop; + + if v_event_count = 0 + then + dbms_output.put_line (' -- No Events are set in this database :: ' || v_dbname); + else + dbms_output.put_line (' -- Found ' || to_char (v_event_count) || ' Events are set in this database :: ' || v_dbname); + end if; + + dbms_output.put_line (rpad ('-', 30, '-')); +end; +/ + +set feedback on diff --git a/db_properties.sql b/db_properties.sql new file mode 100644 index 0000000..858a0ce --- /dev/null +++ b/db_properties.sql @@ -0,0 +1,32 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Show the DB Properies of this database +-- Parameter 1: Name of the property +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define PROP_NAME = '&1' + + +prompt +prompt Parameter 1 = Property Name => &&PROP_NAME. +prompt + +column property_name format a30 heading "Property Name" +column value format a40 heading "Value" + + +select property_name + , substr(property_value, 1, 40) value + from database_properties +where property_name like '&&PROP_NAME' +order by property_name + / + + + \ No newline at end of file diff --git a/dbfiles.sql b/dbfiles.sql new file mode 100644 index 0000000..0e0bf0d --- /dev/null +++ b/dbfiles.sql @@ -0,0 +1,91 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: overview over the datafile of the database +-- Date: 01.September 2012 +-- +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Report Database Files" SKIP 1 - + center "Sizes in MB" SKIP 2 + +column tablespace_name format a18 heading "Tablespace" +column df_size format 999999 heading "Size" +column F_ID format 999 +column FILE_NAME format A53 heading "Filename" +column status format A10 +column fragidx format A12 heading "Fragmen. Index" + +select FILE_ID as F_ID + ,round((BYTES / 1024 / 1024)) as df_size + ,TABLESPACE_NAME + ,FILE_NAME + ,ONLINE_STATUS as status + from dba_data_files + order by TABLESPACE_NAME + ,FILE_NAME +/ + +ttitle "Report Temp Files" SKIP 2 + +select FILE_ID as F_ID + ,round((BYTES / 1024 / 1024)) as df_size + ,TABLESPACE_NAME + ,FILE_NAME + ,STATUS as status + from dba_temp_files + order by TABLESPACE_NAME + ,FILE_NAME +/ + +ttitle "Usage of the datafiles" SKIP 2 + +select d.file_name + ,ROUND(max(d.BYTES) / 1024 / 1024, 2) "total MB" + ,DECODE(sum(f.BYTES), null, 0, ROUND(sum(f.BYTES) / 1024 / 1024, 2)) "Free MB" + ,DECODE(sum(f.BYTES), null, 0, ROUND((max(d.BYTES) / 1024 / 1024) - (sum(f.BYTES) / 1024 / 1024), 2)) "Used MB" + --, ROUND (MAX (d.BYTES) / 1024, 2) "total KB" + --, DECODE (SUM (f.BYTES), + -- NULL, 0, + -- ROUND (SUM (f.BYTES) / 1024, 2) + -- ) "Free KB" + --, DECODE (SUM (f.BYTES), + -- NULL, 0, + -- ROUND ((MAX (d.BYTES) / 1024) - (SUM (f.BYTES) / 1024), 2) + -- ) "Used KB" + ,to_char(ROUND(SQRT(max(f.blocks) / sum(f.blocks)) * (100 / SQRT(SQRT(count(f.blocks)))), 2), '999D00') as fragidx + from dba_free_space f + ,dba_data_files d + where f.tablespace_name(+) = d.tablespace_name + and f.file_id(+) = d.file_id + group by d.file_name + / + + ttitle "I/O performance of the datafiles" SKIP 2 + + +column phyrds format 999G999G999 heading "Physical|Reads" +column phywrts format 999G999G999 heading "Physical|Writes" +column max_readtime format 999D999 heading "Max Read|Time" +column max_writetime format 999D999 heading "Max Write|Time" +column avg_iotime format 999D999 heading "AVG IO|Time" +column file_name format a25 heading "File|Name" + +select substr(b.name,length(b.name)-REGEXP_INSTR(reverse(b.name),'[\/|\]')+2,1000) as file_name + , a.phyrds + , a.MAXIORTM/100 as max_readtime + , a.phywrts + , a.MAXIOWTM/100 as max_writetime + , AVGIOTIM/100 as avg_iotime +from v$filestat a + , v$dbfile b +where a.file# = b.file# +order by b.name +/ + +ttitle off + +prompt ... +prompt ... to add a datafile you can use this example +prompt ... "ALTER TABLESPACE ADD DATAFILE '/.dbf' SIZE 10M AUTOEXTEND ON NEXT 10M MAXSIZE 3000M;" +prompt ... diff --git a/ddl_locks.sql b/ddl_locks.sql new file mode 100644 index 0000000..96b40d5 --- /dev/null +++ b/ddl_locks.sql @@ -0,0 +1,62 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: check for DDL Locks +--============================================================================== + +set verify off +set linesize 130 pagesize 4000 + +define OWNER = '&1' +define OBJECTNAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Object Name => &&OBJECTNAME. +prompt + + +column SESSION_ID format a12 heading "Session|Serial" +column OWNER format a20 +column NAME format a22 heading "Object|Name" +column TYPE format a22 +column MODE_HELD format a10 +column MODE_REQUESTED format a10 +column username format a18 + +select dl.SESSION_ID||','||v.SERIAL# as SESSION_ID + , v.username + , dl.OWNER||'.'||dl.NAME as name + , dl.TYPE + , dl.MODE_HELD + , dl.MODE_REQUESTED + from DBA_DDL_LOCKS dl + , v$session v +where OWNER like upper('&&OWNER.%') + and NAME like upper('&&OBJECTNAME.%') + and v.SID=dl.SESSION_ID +order by v.username +/ + + +-- shows only tables? +--select gv.* , do.object_name +-- from GV$LOCKED_OBJECT gv +-- , dba_objects do +--where gv.OBJECT_ID=do.OBJECT_ID +--and do.object_name like upper('&&OBJECTNAME.%') +--/ + +column NAME format a30 + +select en.name + , se.TOTAL_WAITS + from v$system_event se + , v$event_name en +where en.name in ('latch free','library cache load lock','library cache lock','library cache pin') + and se.EVENT_ID=en.EVENT_ID + group by en.name + , se.TOTAL_WAITS +/ + + + diff --git a/desc.sql b/desc.sql new file mode 100644 index 0000000..57ab28a --- /dev/null +++ b/desc.sql @@ -0,0 +1,48 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- replacement for the desc command to search after some columns +--============================================================================== +set verify off +set linesize 130 pagesize 4000 + +define TAB_NAME = '&1' +define COL_NAME = '&2' + +prompt +prompt Parameter 1 = TAB_NAME => &&TAB_NAME. +prompt Parameter 2 = COL Name => &&COL_NAME. +prompt + +column owner format a10 heading "Owner" +column table_name format a18 heading "Table|Name" +column COLUMN_NAME format a30 heading "Column|Name" +column comments format a25 heading "Comment on |this column" +column data_type format a23 heading "Data type" +column data_default format a10 heading "Column default" +column nullable format a4 heading "Null ?" +column char_length format a4 heading "Char Count" + +select t.OWNER + , t.TABLE_NAME + , t.COLUMN_NAME + , decode(nullable,'Y','YES','NO') as nullable + , case t.data_type + when 'VARCHAR2' then 'varchar2('||lpad(data_length,4)||' '|| decode(t.char_used,'B','Byte','C','Char',t.char_used)||')' + when 'NUMBER' then 'number ('|| nvl(t.data_precision,'') ||' - '|| nvl(t.DATA_SCALE,'') ||')' + when 'DATE' then 'date' + when 'LONG' then 'long' + else rpad(lower(t.data_type),8) ||'('||lpad(t.data_length,4)||nvl(t.data_precision,'') ||')' + end as data_type + --, case when char_length > 0 then to_char(t.char_length) else '-' end as char_length + --, data_default + , c.comments + from dba_tab_columns t + , DBA_COL_COMMENTS c +where t.COLUMN_NAME like upper('%&&COL_NAME.%') + and t.TABLE_NAME like replace(upper('&&TAB_NAME.'),'V$','V_$') + and t.OWNER=c.OWNER (+) + and t.TABLE_NAME = c.TABLE_NAME (+) + and t.COLUMN_NAME = c.COLUMN_NAME (+) +order by OWNER,TABLE_NAME,COLUMN_NAME +/ + diff --git a/dict.sql b/dict.sql new file mode 100644 index 0000000..e6c0930 --- /dev/null +++ b/dict.sql @@ -0,0 +1,25 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: search data dictionary views +-- Date: September 2012 +-- +--============================================================================== + +-- FIX IT +-- umbauen auf REGEXP_SUBSTR(table_name,'_+,') um dba_,all_,user_ +-- + +set linesize 130 pagesize 300 + +set verify off + +column table_name format a30 +column comments format a85 + +select table_name,comments + from dict + where lower(comments) like lower('%&1.%') + and table_name like 'DBA%' +/ + +set verify on diff --git a/dimension_ddl.sql b/dimension_ddl.sql new file mode 100644 index 0000000..457d158 --- /dev/null +++ b/dimension_ddl.sql @@ -0,0 +1,28 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: DB Links DDL +--============================================================================== +set linesize 250 pagesize 3000 + +define USER_NAME = &1 + +set long 1000000 + +ttitle left "create DDL for all DIMENSION of this user &&USER_NAME. " skip 2 + +select '-- DIMENSION OWNER : '||owner||chr(10)||chr(13)||dbms_metadata.get_ddl('DIMENSION',object_name,owner ) ||';'||chr(10)||chr(13) as stmt + from dba_objects +where object_type='DIMENSION' + and owner=upper('&&USER_NAME.') + / + +-- fix it to plsql block to use parameter +-- set the transformation attributes +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true ); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true ); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'OID', false); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SEGMENT_ATTRIBUTES', false); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'TABLESPACE', true ); + +ttitle off diff --git a/directory.sql b/directory.sql new file mode 100644 index 0000000..ff82aff --- /dev/null +++ b/directory.sql @@ -0,0 +1,47 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show informations about directories in the database +-- Date: 08.08.2013 +-- +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Directories in the database" SKIP 1 + +column owner format a15 +column directory_name format a25 +column directory_path format a60 +column grantee format a25 +column grantor format a18 +column privilege format a10 +column privilege_list format a30 + +select owner + , directory_name + , directory_path + from dba_directories + order by 1 + ,2 +/ + +ttitle "Grants to this directories" SKIP 1 + +select t.table_name as directory_name + , t.grantor + , t.grantee + --, listagg(t.privilege,':') WITHIN GROUP (ORDER BY t.privilege ) AS privilege_list + from dba_tab_privs t + , dba_directories d + where t.table_name = d.directory_name + group by t.table_name + , t.grantor + , t.grantee +order by t.table_name + , t.grantee +/ + +prompt ... +prompt To grant use : grant read,write on directory xxxx to yyyyyy; +prompt ... + +ttitle off diff --git a/flash.sql b/flash.sql new file mode 100644 index 0000000..6c7d4d5 --- /dev/null +++ b/flash.sql @@ -0,0 +1,106 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: show flash features +-- +-- Must be run with dba privileges +-- Source +-- http://docs.oracle.com/cd/E11882_01/appdev.112/e40758/d_flashb.htm#ARPLS142 +--============================================================================== + +set linesize 130 pagesize 300 + +ttitle "Report Flashback Feature of the Database" skip 2 - + +column FLASHBACK_ON format A20 + +select FLASHBACK_ON from V$DATABASE +/ + +column INST_ID format A4 +column RETENTION_TARGET format A20 +column FLASH_SIZE format A20 +column ESTIMATED_SIZE format A20 + +ttitle "Report Flashback Size of the Database" skip 2 - + + +select to_char (INST_ID) as inst_id + , RETENTION_TARGET || ' Minuten' RETENTION_TARGET + , round ( (FLASHBACK_SIZE) + / 1024 + / 1024) + || ' MB' + FLASH_SIZE + , round ( (ESTIMATED_FLASHBACK_SIZE) + / 1024 + / 1024) + || ' MB' + ESTIMATED_SIZE + from GV$FLASHBACK_DATABASE_LOG +/ + + +ttitle "Report Flashback Logs of the Database" skip 2 - + +column last_first_time format A20 +column maxsize format A10 + + select to_char (INST_ID) as inst_id + , max (LOG#) as last_logid + , to_char (max (FIRST_TIME), 'dd.mm.yyyy hh24:mi') as last_first_time + , round ( max (BYTES) + / 1024 + / 1024) + || ' MB' + as maxsize + from GV$FLASHBACK_DATABASE_LOGFILE +group by inst_id +/ + +ttitle " Flashback Restore Points" +column scn format 99999999999999999 +column RESTORE_POINT_TIME format a18 heading "RS P Time" +column time format a18 heading "Time" +column name format a30 heading "Name" +column GUARANTEE_FLASHBACK_DATABASE format a6 heading "Garant." + +select scn + , to_char (RESTORE_POINT_TIME, 'dd.mm.yyyy hh24:mi') as RESTORE_POINT_TIME + , to_char (TIME, 'dd.mm.yyyy hh24:mi') as TIME + , NAME + , GUARANTEE_FLASHBACK_DATABASE + from V$RESTORE_POINT; + +ttitle "Oldest possible time to flashback" skip 2 - + +select to_char (oldest_flashback_time, 'dd-mon-yyyy hh24:mi:ss') as "Oldest possible time" from v$flashback_database_log +/ + +ttitle "Oldest possible SCN to flashback" skip 2 - + +column oldest_flashback_scn format 99999999999999999999999999 heading "Oldest possible SCN" + +select oldest_flashback_scn from v$flashback_database_log +/ + + +ttitle "Report Flashback Logs Buffer" skip 2 - + +column name format A40 + +select * + from v$sgastat + where name like 'flashback%'; + + +prompt .... check if there are some tablespaces with flashback disabled! + +select NAME, FLASHBACK_ON + from v$tablespace + where FLASHBACK_ON = 'NO' +/ + +prompt .... no row should be visible to avoid error! +prompt + +ttitle off \ No newline at end of file diff --git a/get_plan.sql b/get_plan.sql new file mode 100644 index 0000000..8c6c637 --- /dev/null +++ b/get_plan.sql @@ -0,0 +1,42 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: get the plan of the last "explain plan for" +--============================================================================== + +set verify off +set linesize 170 pagesize 4000 + +--ALLSTATS LAST NOTE + + +/* + +http://docs.oracle.com/cd/B19306_01/appdev.102/b14258/d_xplan.htm + +format + +Controls the level of details for the plan. It accepts four values: + + BASIC: Displays the minimum information in the plan—the operation ID, the operation name and its option. + TYPICAL: This is the default. Displays the most relevant information in the plan (operation id, name and option, #rows, #bytes and optimizer cost). Pruning, parallel and predicate information are only displayed when applicable. Excludes only PROJECTION, ALIAS and REMOTE SQL information (see below). + SERIAL: Like TYPICAL except that the parallel information is not displayed, even if the plan executes in parallel. + ALL: Maximum user level. Includes information displayed with the TYPICAL level with additional information (PROJECTION, ALIAS and information about REMOTE SQL if the operation is distributed). + +For finer control on the display output, the following keywords can be added to the above three standard format options to customize their default behavior. Each keyword either represents a logical group of plan table columns (such as PARTITION) or logical additions to the base plan table output (such as PREDICATE). Format keywords must be separated by either a comma or a space: + ROWS - if relevant, shows the number of rows estimated by the optimizer + BYTES - if relevant, shows the number of bytes estimated by the optimizer + COST - if relevant, shows optimizer cost information + PARTITION - if relevant, shows partition pruning information + PARALLEL - if relevant, shows PX information (distribution method and table queue information) + PREDICATE - if relevant, shows the predicate section + PROJECTION -if relevant, shows the projection section + ALIAS - if relevant, shows the "Query Block Name / Object Alias" section + REMOTE - if relevant, shows the information for distributed query (for example, remote from serial distribution and remote SQL) + NOTE - if relevant, shows the note section of the explain plan + + +*/ + +SELECT * FROM TABLE( dbms_xplan.display( NULL, NULL, 'ALL,COST', NULL )) +/ + diff --git a/health_mon.sql b/health_mon.sql new file mode 100644 index 0000000..67a9a12 --- /dev/null +++ b/health_mon.sql @@ -0,0 +1,49 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Query the Oracle Health Monitor +-- Work in progress +--============================================================================== +-- see http://www.pipperr.de/dokuwiki/doku.php?id=dba:oracle_health_monitor +--============================================================================== +set linesize 130 pagesize 300 + +column name format a40 + +select name + from v$hm_check + where internal_check='N' +/ + +column check_name format a40 +column parameter_name format a20 +column description format a40 +column type format a15 +column default_value format a20 heading "Default|value" + +select c.name check_name + , p.name parameter_name + , p.type + , p.default_value + , p.description + from v$hm_check_param p, v$hm_check c +where p.check_id = c.id + and c.internal_check = 'N' +order by c.name +/ + +prompt ... Example for call +prompt ... +prompt ... BEGIN +prompt ... DBMS_HM.RUN_CHECK ( +prompt ... check_name => 'Transaction Integrity Check', +prompt ... run_name => 'MY__RUN_NAME', +prompt ... input_params => 'TXN_ID=8.66.2'); +prompt ... END; +prompt ... + + +/* + V$HM_RUN + V$HM_FINDING + V$HM_RECOMMENDATION +*/ \ No newline at end of file diff --git a/help.sql b/help.sql new file mode 100644 index 0000000..25b9ade --- /dev/null +++ b/help.sql @@ -0,0 +1,391 @@ +--============================================================================== +-- Author: Gunther Pippčrr +-- Desc: SQL Script Overview +--============================================================================== + +DOC +------------------------------------------------------------------------------- + +#The daily scripts for the DBA +=============================== + + - dict.sql - query the data dictionary - parameter 1 - part of the comments text + + - database.sql - name and age of the database + - status.sql - status of the instance/cluster + - cdb.sql - check this DB (12c onwards) for plugable configuration + - date.sql - get the actual date and time of the DB + - instance.sql - status of the instance where the user is connected + - limit.sql - resource limits since last startup of the instances + - dbfiles.sql - list of all database data files + + - tablespace.sql - Information about the tablespaces + - tablespace_usage.sql - Information usage on a tablespace - Parameter 1 the name of the tablespace + - tablespace_ddl.sql - get the DDL of a tablespace, show default storage options! - Parameter name of the tablespace + - tablespace_space.sql - get a overview over the free and used space for a tablespace - parameter name of the tablespace + - awr_tablespace_history.sql - get the historical Size of a tablespace from the AWR + - tablespace_tab_storage.sql - show all tables on a tablespace + - tablespace_autoextend.sql - set all datafile of a tablespace to autoextend + - tablespace_set_size.sql - set all datafile of a tablespace to the same size + - tablespace_create.sql - print the ddl to create a uniform tablespace - Parameter Name of the tablespace + - tablespace_last_objects.sql - get the last 5 objects in a tablespace + + - sessions.sql - actual connections to the database + - session_history.sql - get a summary over the last active sessions + - session_long_active.sql - all session that are longer active + - session_longops.sql - get information about long running SQL statements + - session_killed.sql - get the process information for killed sessions + - ses_statistic.sql - get the statistic information of a session + - my_opt_settings.sql - Optimizer settings in my session + - my_ses_stat.sql - Satistic of my session + - session_opt_settings.sql - Optimizer settings in a session - parameter 1 username + - session_user_env.sql - show all sys context values in a user session + - session_user_nls_lang.sql - get the NLS Lang User session setting (only SYS !) + + - starttrace.sql - start a trace of my session + - stoptrace.sql - stop trace of my session + - trace_status.sql - show all traces in the database + + - service_session.sql - sessions per service over all instances + - trans.sql - running transactions in the database + - undo.sql - show activity on the undo segment + - undo_stat.sql - show statistic for the undo tablespace usage + - open_trans.sql - all longer open running transactions in the database - uncommitted transaction! + + - bgprocess.sql - Background processes in the database + - process.sql - actual processes in the database parameter 1 - name of the DB or OS User + Parameter 2 - if Y shows also internal processes + - process_get.sql - show the information about the session with this PID - parameter 1 PID + + - resource_manager.sql - show the information about the resource manager + - resource_manager_sessions.sql - Show the resource manager settings of the running sessions + - tempspace_usage.sql - show processes using the temp tablespace + - parallel.sql - parallel SQL informations + - parallel_dbms.sql - DBMS_PARALLEL chunks in work + + - tns.sql - show services and tns settings on services + - tns_history.sql - show services statistics for the last 12 hours (only services with some traffic) + - taf.sql - Check TAF settings of the connections + - connection_pool.sql - Show the Database Resident Connection Pooling (DRCP) Settings + - ssl.sql - check the sql*net connection if ssl or encryption is in use + - sqlnet.sql - get SQL*Net Informations + + - locks.sql - locks in the database - mode 6 is the blocker! + - ddl_locks.sql - check for DDL Locks + + - wait.sql - waiting sessions + - wait_text.sql - text to a wait event - parameter 1 part of the event name + - wait_get_name.sql - search for a name of a wait event + + - latch.sql - get Information’s about the DB latch usage + - checkpoint.sql - get the actual status for the instance recovery + + - my_user.sql - who am I and over with service I connect to the database + + - nls.sql - global and session NLS Settings + - version.sql - version of the database + - test_sqlnet_fw.sql - test the time-outs of SQL*Net + + - init.sql - init.ora entries + - init_rac.sql - show init.ora parameter in a RAC Environment to check if same parameters on each node + - db_events.sql - test if some events are set in the DB environment + - db_properties.sql - get the database properties + + - xmldb.sql - show configuration of the XML DB + - acl.sql - show the acls of the Database (for security) + - my_acl.sql - show my rights + + - java.sql - java access rights + - java_recomplie_invalid.sql - compile invalid (resolve) java classes in a user schema + + - invalid.sql - show all invalid objects + - invalid_synoyms.sql - delete Script for invalid synonym + - invalid_obj_report.sql - get report for development for invalid objects in the database + - invalid_constraints.sql - get all invalid constraints + + - user.sql - rights and roles of a user and object grants - parameter 1 - Name of the user + - users.sql - overview over the DB users - parameter 1 - Name of the user + - user_ddl.sql - get the script to create a user - parameter 1 - Name of the user + - user_history.sql - get some static information for the login behavior of this user - Parameter 1 - Name of the user + - user_objects.sql - show the counts of objects from none default users + - user_oracle_default.sql - define the list of the default oracle db schemas + + - vpd.sql - show the VPD - Virtual Private Database Settings + + - user_tab.sql - get all the tables and views of a user - parameter 1 - part of the table name + - ls.sql - gets all the tables and shows the size of the user tab + + - roles.sql - all roles in the database - parameter 1 part of the role name + - role.sql - get the rights on a role + - role_ddl.sql - get the dll of one role in the database - parameter 1 the role name + + - any_rights.sql - show all users with any rights in the database + - inherit_rights.sql - show all users with inherit priviliges rights + + - profile.sql - profiles for the user of this database + - proxy.sql - proxy settings in the database + - proxy_to.sql - All schemas that can be switch to this schema with proxy rights - parameter 1 name of the schema + - proxy_client.sql - from which user you can connect to this user - parameter 1 the user + + - comment.sql - search over all comments - parameter 1 - part of the comment text + + - desc.sql - describe a table - parameter 1 Table name - 2 - part of the column name + - tab.sql - search a table or views in the database - parameter 1 - part of the table + - tab_overview_report.sql - report over all none default tables in the database + - tab_cat.sql - get the tables and views of the current user + - tab_count.sql - count the entries in a table - parameter 1 - name of the table + - tab_space.sql - space usage of a table + - tab_stat.sql - get the statics of the table - parameter - Owner, Table name + - tab_desc.sql - describe the columns of the table - parameter 1 - part of the table + - tab_ddl.sql - get the create script of a table - parameter - Owner, Table name + - tab_priv.sql - get the priviliges on a tab - parameter - Owner, Table name + - tab_last.sql - get the change date of a record in the table - parameter - Owner, Table name + - tab_mod.sql - get the last modifications of the table - parameter - Owner, Table name + - tab_data_changes.sql - get an overview over changes on the tables of a user - parameter - Owner + - tab_umlaut.sql - check for tables/views if umlauts are used for the naming of tables and columns + - tab_identity_col.sql - get the sequence of a ID Column from the database - parameter - Owner, Table name + - my_tab_rights.sql - get all rights on tables outside my schema + + - tab_usage.sql - check if the table is used in the last time - parameter - Owner, Table name + - tab_part.sql - get the partition information of a table - parameter - Owner, Table name + - partition.sql - Analyse the partitions of the tables of a user + + - tab_ext.sql - get information about external tables + - tab_iot.sql - show information about a index organized table - parameter - Owner, Table name + - tab_iot_all.sql - Show all IOT in the database + + - tab_mat.sql - Information about materialized views + - tab_mat_log.sql - Information about materialized views Logs + - refresh_group.sql - Get all refresh groups of the DB for the materialized views + - my_refresh_group.sql - Get all refresh groups of your Schema + + - tab_defekt_blocks.sql - check for corrupted blocks + - tab_defekt_blocks_bad_table.sql - create rowid table for all readable data for a table with a defect lob segment + + - tab_redef.sql - example for an online table redefinition + - tab_stat_overview.sql - statistic over all table of a user parameter 1 - schema name + - analyse_changed_rows.sql - analyses changed row for a table + - recreate_tables.sql - create the script to reorganise the smaller tables of a tablespace with alter table move + + - column_type.sql - get all columns in the database with this data-type parameter 1 - data type - owner + - column.sql - search all tables with this column name - parameter 1 - name of the column + + - synonym.sql - search all synonym of a user - parameter - Owner, data type + - synonym_detail.sql - get information over one synonym - parameter - Owner, synonym Name + + - lob.sql - show the lob settings of the tables of the user - parameter - Owner + - lob_detail.sql -Get the details for the lob data type for this table - parameter owner and table name + - dimension_ddl.sql - Get the DDL of a oracle dimension object in the database + + - sequence.sql - search a sequence in the database parameter 1 - name of the sequence + + - recycle.sql - show the content summary of the dba recyclebin + + - tab_tablespace.sql - get the tablespaces of the user - parameter - Owner + - tab_tablespace_all.sql - get the used tablespace overview of this database + + - index.sql - get the information’s over a index - parameter - Owner, Index name + - index_all.sql - get all indexes of a user - parameter - Owner + - index_mon.sql - check the result of index monitoring + - index_ddl.sql - get the DDL of an index + + - obj_dep.sql - get the dependencies of a object in the database - parameter - Owner, object name + - obj_deps_report.sql - get a overview of dependencies in a database as HTML Report + - obj_grants.sql - get the grants for this object in the database - parameter - Owner, object name + - obj_last_ddl.sql - get the last DDL for all objects of a user - parameter - Owner + + - plsql_info.sql - information about a pl/sql function/package + - plsql_search.sql - search for a pl/sql function/procedure also in packages - parameter Search String + - plsql_depend.sql - information about the dependencies of a package/procedure - parameter - Owner, object name + - plsql_depend_on.sql - Which objects depends on this pl/sql code + - plsql_errors.sql - show the errors of pl/sql objects + - plsql_dll.sql - information about a pl/sql function/package - parameter - Owner, object name + - my_plsql.sql - show all package of the current user + - plsql_usage.sql - which package are used in the last time and how often over the SGA Cache + - plsql_running.sql - actual running pl/sql in the database + + - select.sql - select first 3 records of the table as list - parameter 1 - name of the table + - view_count.sql - count entries in a view - parameter 1 - name of the view + - view_getsql.sql - get the real SQL statement behind the call of a view - parameter - Owner, view name + + - asm.sql - asm disk status and filling degree of the asm disks + + - asm_disk.sql - asm disk groups space + - asm_all_disks.sql - show the disk infos + - asm_balance.sql - asm disk disk balance - Parameter 1 - name of the disk group + - asm_partner.sql - Information about asm partner disk + - asm_files.sql - All files on an ASM disk group + + - asm_failgroup.sql - Show the failgroup information of a disk group - Parameter 1 - name of the disk group + - asm_offline_failgroup.sql - create the script to offline all disks in a failgroup - Parameter 1 over the nameing convention of the disk! + - asm_online_failgroup.sql - create the script to online all failgroup with offline disks + - asm_rebalance.sql - Show the rebalance information of a asm resync of disks + - asm_attribute.sql - Show the parameter of a ASM Diskgroup - parameter 1 Diskgroup Name - parameter 2 - parameter name + + - flash.sql - show the flash back information’s + - reco.sql - recovery area settings and size + - archive_log_status.sql - status of the archivelog files + + - redo.sql - redo log information (use redo10g.sql for 10g/9i) + - redo_change.sql - who create how much redo per day last 7 in the database + - scn.sql - scn in the archive log history + - sqn.sql - sequence log + + - ext/tsc.sql - table space size information + - directory.sql - show directories in the database + - my_directory.sql - show directories of the actual connect user in the database + - links.sql - show the DB Links in the database + - links_ddl.sql - get the DDL of all DB links in the database + - links_usage.sql - get the sourcecode that use the DB links + + - audit.sql - show the audit settings + - audit_sum.sql - audit log summary + - audit_login.sql - audit the logins of users + - audit_failed_login.sql - check for failed logins in the last time + - audit_logoff_cleanup.sql - check for dropped Sessions in the last time + + - jobs.sql - jobs in the database job$ and scheduler tasks info + - jobs_dbms.sql - jobs declared with dbms_job - old style jobs + - jobs_sheduler.sql - jobs declared over the job scheduler + - jobs_errors.sql - jobs in the database job$ and scheduler tasks info with errors + - jobs_window_resource_class.sql - show the relation between job windows , job classes and resource plans + - jobs_logs.sql - Details of a job + + - sga.sql - show information about the oracle sga usage + - buffer.sql - show information about the buffer cache usage / must run as sys + - buffer_cache.sql - show information about objects in the buffer cache + - pga.sql - show information about the PGA usage + + - statistic.sql - show information over the statistics on the DB and stat age on tables and when the stats job runs + - statistic_backup.sql - save all statistics of the DB in backup tables + + - cursor.sql - show information about the cursor usage + + - sql_find.sql - find a SQL Statement in the Cache - parameter 1 part of the SQL statement + - sql_plan.sql - get the Execution Plan for one SQL ID from the cache + - sql_temp.sql - SQL that use the temp table space for sorting + - sql_show_bind.sql - Show the bind variables of the SQL statement from the cursor Cache - parameter 1 - SQL ID + - sql_parallel.sql - Show the parallel execution for this statement - parameter 1 - SQL ID + - sql_opt_settings.sql - Show the optimizer settings for this statement - parameter 1 - SQL ID + + - sql_kill_session.sql - create the command to kill all sessions running this SQL at the moment - parameter 1 - SQL ID + - sql_purge_cursor.sql - purge the cursor out of the cache - parameter 1 - SQL ID + + - sql_profile.sql - show all profiles in the database + - sql_profile_details.sql - get the details of a SQL profile - parameter 1 - Profile Name + - sql_baseline.sql - get the defined baseline + - sql_baseline_evolve.sql - evolve and get the details of one baseline - parameter 1 - the baseline sql_handle name + - sql_baseline_plan.sql - get the details of of a plan in a baseline - parameter 1 - the baseline sql_baseline_plan + - sql_session_stat.sql - get statistics from running session for this SQL - parameter 1 - SQL ID + + - get_plan.sql - get the plan of the last "explain plan for" + + - ash.sql - usage of the active session history ASH + + - awr.sql - usage of the AWR repository and of the SYSAUX table space + - awr_sql_find.sql - find a SQL Statement in the AWR History - parameter 1 part of the SQL statement + - awr_sql_find_report.sql - create overview report over the usage of a SQL statement or hint - parameter 1 part of the SQL statement + - awr_sql_stat.sql - get statistic of the SQL execution of one statement - parameter 1 - SQL ID + - awr_sql_hash.sql - get the different hashes if exits - parameter 1 - SQL ID + - awr_sql_plan.sql - get plan of the SQL execution of one statement - parameter 1 - SQL ID + - awr_sql_time_stat.sql - get all SQL statements from the awr for this time - parameter 1 - Start date - parameter 2 end date in DE format + - awr_temp_usage.sql - get the SQL that use temp tablespace from the awr for this time - parameter 1 - Start date - parameter 2 end date in DE format + - awr_pga_stat.sql - statistic of the pga usage + - awr_sys_stat.sql - statistic of system historical statistics information + + - awr_session_stat.sql - statistic of the sessions of a user + - awr_session_resource_plan_historie.sql - Show the consumer group of all history active sessions of a user + - awr_act_active_sessions.sql - get information about the act active Session in the last 90 minutes + - awr_ash_top_sql.sql - select the last top sql statements from the active session history + - awr_act_blocking_sessions.sql - get information about blocking sessions in the database + - awr_session_none_technical_user.sql - get information about none technical user sessions + - awr_changed_plans.sql - search for changed plans in a time period - parameter 1 - Start date - parameter 2 end date in DE format + - awr_resourcelimit.sql - display the resource limits of the last days + - awr_os_stat.sql - display the OS statistic of the last days + - awr_call_awr_report.sql - create AWR Report of the database + - awr_call_ash_report.sql - create ASH Report of the database + - awr_call_sqlmonitor_report.sql - call a sql Monitor Report + + - statspack_delete_job.sql - create a job to clean the statspack repository + + - calibrate_io.sql - Use I/O calibrate to analyses io of the database and set the internal I/O views + - system_stat.sql - get the DB internal system stat values like workload statistic and I/O calibrate values + + - ctx.sql - Oracle Text indexes for a user and ctx settings - parameter 1 - name of the user + + - rman.sql - rman settings of this database and summary information about the last backups for this database and the block change tracking feature + - rman_process.sql - get information over running rman processes for tracing + - rman_status.sql - get the status of the last backup in the database + + - datapump.sql - show datapump sessions + - datapump_filter.sql - show all possible filter values für the INCLUDE/EXCLUDE parameter of datapump + + - standby_status.sql - status of a standby / DG environment + + - streams_status.sql - status of streams replication + - streams_config.sql - streams configuration + - streams_logs.sql - show the streams archive logs - which can be deleted + - streams_print_error.sql - print the SQL Statements for all LCRS in a transaction if a streams error occurs + - streams_print_lcr.sql - print the LCR of one Message + - streams_logmnr.sql - information about the log miner process + + - db_alerts.sql - get the internal metric settings of the DB side monitoring + - db_alerts_set.sql - set the threshold of a metric + + - health_mon.sql - call the health monitoring in 11g - get the parameter + + - login.sql - set the login prompt + + - http_ftp_port.sql - get the port settings of the database + + - ords.sql - get the ORDS REST service definitions + - apex_version.sql - get the ORDS and APEX Version in this DB + + #Create Scripts + ================= + + - clean_user.sql - create the DDL to delete every object in the schema - parameter 1 - user name + + - space_tablespace.sql - create the DDL to shrink a table space - parameter 1 - Name of the table space (%) for all + - space_tablespace_auto.sql - shrink each possible tablespace without asking + + - recreate_index.sql - Script to create a index recreation script + - recreate_table.sql - Script to reorganize all small tables in a tablespace, off-line with !alter Table move! + + + - create_mon_index.sql - Script to create index enable or disable monitoring scripts for a user - parameter 1 - user name + + - create_all_statistic.sql - Recreate the statistic of the database + + #Reports + ================= + + - check_col_usage.sql - HTML Report - Table column used in SQL Statements but not indexed and all indexes with more than one column to check for duplicate indexing + + - top_sql.sql - HTML Report - Top SQL Statements in the database for Buffer / CPU / Sort Usage + - sql_user_report.sql - HTML Report - Show all SQL statements for this user in the SGA + + - audit_rep.sql - HTML Report - Audit Log entries + + - licence.sql - HTML Report - License Report Overview - Feature Usage + + #Setup + ================= + + - 01-db-setup/create_global_errorlog.sql - create a global error table and error trigger + maintain job + - 01-db-setup/delete_global_errorlog.sql - delete the global error trigger + error table + - 01-db-setup/report_global_errorlog.sql - template to create HTML report over all errors in the sql error log + + - 01-db-setup/create_audit_log_database.sql - create own table space for auditlog, move audit log to this table pace - create clean job + - 01-db-setup/set_audit_minimal_settings.sql - set minimal audit parameter + + - 01-db-setup/monitor_user_sessions.sql - create a log table to monitor user connection over some time + - 01-db-setup/ create-logon-trigger-user-handling.sql - create logon trigger to restrict access to the database + + #The OEM Query Scripts + ================= + - get the the help of the OEM scripts use oem/help_oem.sql + +------------------------------------------------------------------------------- +# + diff --git a/http_ftp_port.sql b/http_ftp_port.sql new file mode 100644 index 0000000..a437bbc --- /dev/null +++ b/http_ftp_port.sql @@ -0,0 +1,16 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Query the audit log entries +-- +-- Must be run with dba privileges +-- +--============================================================================== +set linesize 130 pagesize 300 + +select dbms_xdb.gethttpport as "HTTP-Port" + , dbms_xdb_config.getHttpsPort() as "HTTPS-Port" + , dbms_xdb.getftpport as "FTP-Port" + from dual + / + + \ No newline at end of file diff --git a/index.sql b/index.sql new file mode 100644 index 0000000..029ab14 --- /dev/null +++ b/index.sql @@ -0,0 +1,176 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show information about a index +-- Parameter 1: Owner of the index +-- Parameter 2: Index Name +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 4000 + +define OWNER = '&1' +define INDEX_NAME = '&2' + +prompt +prompt Parameter 1 = Owner => &&OWNER. +prompt Parameter 2 = Index Name => &&INDEX_NAME. +prompt + + +column index_owner format a10 heading "Index|Owner" +column index_name format a25 heading "Index|Name" +column status format a12 heading "Status" +column part_info format 999 heading "Partition|count" + +ttitle "Check the Status of the Index" skip 2 + +select owner as index_owner + , index_name + , status + , 0 as part_info + from dba_indexes + where owner like upper ('&&OWNER.%') + and index_name like upper ('%&&INDEX_NAME.') +union + select index_owner + , index_name + , status + , count (partition_name) + from dba_ind_partitions + where status not in ('VALID', 'N/A', 'USABLE') + and index_owner like upper ('&&OWNER.%') + and index_name like upper ('&&INDEX_NAME.') +group by index_owner, index_name, status +/ + + + +ttitle center "Index &&OWNER..&&INDEX_NAME. Columns" skip 2 + +set linesize 130 pagesize 2000 + +column index_name format a16 heading "Index|Name" +column table_name format a13 heading "Table|Name" +column column_name format a13 heading "Column|Name" +column TABLESPACE_NAME format a15 heading "Table|Space" +-- fold_before +column pos1 format a12 heading "c1" +column pos2 format a8 heading "c2" +column pos3 format a6 heading "c3" +column pos4 format a4 heading "c4" +column pos5 format a4 heading "c5" +column pos6 format a4 heading "c6" +-- if you like more enable! +column pos7 format a3 heading "c7" noprint +column pos8 format a3 heading "c8" noprint +column pos9 format a2 heading "c9" noprint +-- +column size_mb format 999G999G999 heading "Size|MB" +column part_count format 9G999 heading "Cn|Pa" + + + select i.INDEX_OWNER + , i.TABLE_NAME + , i.INDEX_NAME + , round ( sum (s.bytes) + / 1024 + / 1024 + , 0) + size_mb + , count (s.PARTITION_NAME) as part_count + , i.pos1 + , i.pos2 + , i.pos3 + , i.pos4 + , i.pos5 + , i.pos6 + , i.pos7 + , i.pos8 + , i.pos9 + , s.TABLESPACE_NAME + from (select * + from ( select index_owner + , table_name + , index_name + , column_name + , column_position + from dba_ind_columns + where index_owner like upper ('&&OWNER.%') + and index_name like upper ('&&INDEX_NAME.') + order by index_owner, table_name) pivot (min (column_name) + for column_position + in ('1' as pos1 + , '2' as pos2 + , '3' as pos3 + , '4' as pos4 + , '5' as pos5 + , '6' as pos6 + , '7' as pos7 + , '8' as pos8 + , '9' as pos9))) i + , dba_segments s + where s.owner = i.index_owner + and s.SEGMENT_NAME = i.INDEX_NAME +group by i.INDEX_OWNER + , i.TABLE_NAME + , i.INDEX_NAME + , i.pos1 + , i.pos2 + , i.pos3 + , i.pos4 + , i.pos5 + , i.pos6 + , i.pos7 + , i.pos8 + , i.pos9 + , s.TABLESPACE_NAME +/ + +--ttitle center "Index &&OWNER..&&INDEX_NAME. Partitions" SKIP 2 + +ttitle center "Index &&OWNER..&&INDEX_NAME. Statistic" skip 2 + +column compression format a9 heading "Comp" +column blevel format 999 heading "BLevel" +column block_rate format 999 heading "B Rate" +column leaf_blocks format 99999999999 heading "Leaf" +column blocks format 99999999999 heading "Blocks" +column num_rows format 99999999999 heading "Num Rows" +column distinct_keys format 99999999999 heading "Distinct | Keys" +column avg_leaf_blocks_per_key format 999 heading "AVG|L-Blk." +column avg_data_blocks_per_key format 999 heading "AVG|Data-Blk." +column status format a6 heading "Status" +column PARTITION_NAME format a20 heading "Part|Name" + + +select nvl (s.PARTITION_NAME, 'N/A') as PARTITION_NAME + , i.COMPRESSION + , i.blevel + , i.leaf_blocks + , s.blocks + , decode (nvl (i.leaf_blocks, 0) + , 0, 0 + , ( s.blocks + / i.leaf_blocks)) + as block_rate + , i.NUM_ROWS + , i.DISTINCT_KEYS + , i.AVG_LEAF_BLOCKS_PER_KEY + , i.AVG_DATA_BLOCKS_PER_KEY + , i.status + , to_char (i.LAST_ANALYZED, 'dd.mm.rr hh24:mi') as LAST_ANALYZED + , to_char (o.LAST_DDL_TIME, 'dd.mm.rr hh24:mi') as Created + from dba_indexes i, dba_segments s, DBA_OBJECTS o + where s.owner = i.owner + and s.SEGMENT_NAME = i.index_name + and o.object_name = i.index_name + and nvl (o.SUBOBJECT_NAME, 'X') = nvl (s.PARTITION_NAME, 'X') + and o.owner = i.owner + and i.owner like upper ('&&OWNER.%') + and i.index_name like upper ('&&INDEX_NAME.') +/ + +ttitle off \ No newline at end of file diff --git a/index_all.sql b/index_all.sql new file mode 100644 index 0000000..4dd55fd --- /dev/null +++ b/index_all.sql @@ -0,0 +1,53 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get all indexes of a user - parameter - Owner +--============================================================================== +set verify off +set linesize 130 pagesize 4000 + +define OWNER = '&1' + + +prompt +prompt Parameter 1 = Owner => &&OWNER. +prompt + +ttitle center "All Indexes of this Owner: &&OWNER. " skip 2 + +column compression format a9 heading "Comp" +column blevel format 999 heading "BLevel" +column block_rate format 999 heading "B Rate" +column leaf_blocks format 99999999999 heading "Leaf" +column blocks format 99999999999 heading "Blocks" +column num_rows format 99999999999 heading "Num Rows" +column distinct_keys format 99999999999 heading "Distinct | Keys" +column avg_leaf_blocks_per_key format 999 heading "AVG|L-Blk." +column avg_data_blocks_per_key format 999 heading "AVG|Data-Blk." +column status format a6 heading "Status" +column index_owner format a10 heading "Index|Owner" +column index_name format a26 heading "Index|Name" +column table_name format a13 heading "Table|Name" + +select i.COMPRESSION + , i.blevel + , i.leaf_blocks + , s.blocks + --, decode(nvl(i.leaf_blocks,0),0,0,(s.blocks/i.leaf_blocks)) as block_rate + , i.NUM_ROWS + , i.DISTINCT_KEYS + --, i.AVG_LEAF_BLOCKS_PER_KEY + --, i.AVG_DATA_BLOCKS_PER_KEY + , i.status + , i.index_name + , to_char (o.LAST_DDL_TIME, 'dd.mm.rr hh24:mi') as Created + from dba_indexes i, dba_segments s, DBA_OBJECTS o + where s.owner = i.owner + and s.SEGMENT_NAME = i.index_name + and nvl(s.partition_name,'n/a')=nvl(o.subobject_name,'n/a') + and o.object_name = i.index_name + and o.owner = i.owner + -- and i.owner like upper ('&&OWNER.') + and o.owner not in ('SYS','MDSYS','SI_INFORMTN_SCHEMA','ORDPLUGINS','ORDDATA','ORDSYS','EXFSYS','XS$NULL','XDB','CTXSYS','WMSYS','APPQOSSYS','DBSNMP','ORACLE_OCM','DIP','OUTLN','SYSTEM','FLOWS_FILES','PUBLIC','SYSMAN','OLAPSYS','OWBSYS','OWBSYS_AUDIT','PUBLIC','TSMSYS') + -- and o.LAST_DDL_TIME between sysdate-14 and sysdate +order by o.LAST_DDL_TIME +/ diff --git a/index_ddl.sql b/index_ddl.sql new file mode 100644 index 0000000..1c832ca --- /dev/null +++ b/index_ddl.sql @@ -0,0 +1,61 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: extract the DDL of index in the database +-- +-- Parameter 2: Owner of the table/object +-- Parameter 1: Name of the index +--============================================================================== +set verify off +set linesize 130 pagesize 4000 + +define OWNER = '&1' +define INDEX_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Index Name => &&INDEX_NAME. +prompt + +variable ddllob clob + +set heading off +set echo off + +set long 1000000; + +declare + cursor c_tab_idx + is + select index_name, owner + from dba_indexes + where index_name = upper ('&&INDEX_NAME.') + and TABLE_OWNER = upper ('&&OWNER.'); +begin +-- set the transformation attributes + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'OID', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SEGMENT_ATTRIBUTES', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'TABLESPACE', true ); +-- no Schema Name inside + DBMS_METADATA.SET_TRANSFORM_PARAM(dbms_metadata.SESSION_TRANSFORM, 'EMIT_SCHEMA', false); + + -- + :ddllob := '-- call Index DLL for Index &&OWNER..&&INDEX_NAME.'; + dbms_output.put_line (:ddllob); + + -- get the index DDL for this table + for rec in c_tab_idx + loop + :ddllob := :ddllob || chr (10) || chr (10) || '-- DDL for Index : ' || rec.index_name || chr (10); + :ddllob := :ddllob || dbms_metadata.get_ddl ('INDEX', rec.index_name, rec.owner); + end loop; +end; +/ + +print ddllob + +undefine ddllob + +set heading on \ No newline at end of file diff --git a/index_mon.sql b/index_mon.sql new file mode 100644 index 0000000..3bf6d55 --- /dev/null +++ b/index_mon.sql @@ -0,0 +1,68 @@ +-- ================================================= +-- GPI - Gunther Pippèrr +-- Desc: check the result of index monitoring +-- ================================================= +-- source see https://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:12840327558363 +--============================================================================== +column SPOOL_NAME_COL new_val SPOOL_NAME + +select replace ( + ora_database_name + || '_' + || sys_context ('USERENV', 'HOST') + || '_' + || to_char (sysdate, 'dd_mm_yyyy_hh24_mi') + || '_col_usage.html' + , '\' + , '_') + --' resolve syntax highlight bug FROM my editer .-( + as SPOOL_NAME_COL + from dual +/ + + +column owner format a15 heading "Owner" +column index_name format a32 heading "Index|Name" +column table_name format a20 heading "Table|Name" +column USED format a3 heading "In|Use" +column MONITORING format a3 heading "Mon|On" +column start_monitoring format a20 heading "Start|Monitoring" +column end_monitoring format a20 heading "End|Monitoring" + + +spool &&SPOOL_NAME + +set markup html on + +set verify off +set linesize 130 pagesize 2000 + +select to_char (sysdate, 'dd.mm.yyyy hh24:mi') as anlayse_date from dual +/ + +select u.name owner + , t.name TABLE_NAME + , io.name index_name + , decode (bitand (i.flags, 65536), 0, 'NO', 'YES') MONITORING + , decode (bitand (ou.flags, 1), 0, 'NO', 'YES') USED + , ou.start_monitoring + , ou.end_monitoring + from sys.user$ u + , sys.obj$ io + , sys.obj$ t + , sys.ind$ i + , sys.object_usage ou + where i.obj# = ou.obj# + and io.obj# = ou.obj# + and t.obj# = i.bo# + and u.user# = io.owner# +order by t.name, io.name +/ + +set markup html off +spool off +ttitle off + +-- works only in a ms windows enviroment +-- autostart of the result in a browser window +host &&SPOOL_NAME diff --git a/inherit_rights.sql b/inherit_rights.sql new file mode 100644 index 0000000..8136561 --- /dev/null +++ b/inherit_rights.sql @@ -0,0 +1,50 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the user rights and grants +-- Date: September 2012 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + + +column grantee format a25 +column GRANTOR format a25 +column PRIVILEGE format a25 heading "Priv" +column table_name format a20 heading "Table|Name" +column ADMIN_OPTION format a3 heading "Adm|OPT" +column COMMON format a3 heading "Com" +column INHERITED format a7 heading "Inherit" + + +column table_name format a26 heading "User|Name" + + +ttitle left "INHERIT PRIVILEGES for &&USER_NAME" skip 2 + +select grantee, table_name, privilege + from dba_tab_privs + where privilege = 'INHERIT PRIVILEGES' + and grantee like upper('&&USER_NAME.') + / + + +ttitle left "INHERIT PRIVILEGES from to other User" skip 2 + +select GRANTEE + , PRIVILEGE + , ADMIN_OPTION + , COMMON + , INHERITED + from dba_sys_privs + where privilege like '%INHERIT%' + and grantee like upper('&&USER_NAME.') +/ + +ttitle OFF + +column table_name format a20 heading "table_name" + +-------------- diff --git a/init.sql b/init.sql new file mode 100644 index 0000000..fb4193e --- /dev/null +++ b/init.sql @@ -0,0 +1,88 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: check init.ora parameter +-- Date: 01.September 2012 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 4000 + +prompt +prompt Parameter 1 = DB Parameter => '&1' +prompt + +define PARA_NAME = '&1' + +ttitle left "init.ora parameter" skip 2 + +column inst_id format 99 heading "In|Id" +column name format a32 heading "Parameter" +column value format a25 heading "Value" +column isdefault format a2 heading "De" +column isses_modifiable format a2 heading "Se" +column issys_modifiable format a2 heading "Sy" +column ismodified format a2 heading "Mo" +column isadjusted format a2 heading "Ad" +column isdeprecated format a2 heading "Dp" +column isbasic format a2 heading "Ba" +column isinstance_modifiable format a1 heading "Im" +column description format a30 heading "Description" + + +select inst_id + , name + , value + , decode(isdefault,'TRUE','Y','FALSE','-',isdefault) as isdefault + , decode(isses_modifiable,'TRUE','Y','FALSE','-',isses_modifiable) as isses_modifiable + , decode(issys_modifiable,'TRUE','Y','IMMEDIATE','I','DEFERRED','D','FALSE','-',issys_modifiable) as issys_modifiable + , decode(isinstance_modifiable,'TRUE','Y','FALSE','-',isinstance_modifiable) as isinstance_modifiable + , decode(ismodified,'TRUE','Y','MODIFIED','M','SYSTEM_MOD','S','FALSE','-',ismodified) as ismodified + , decode(isadjusted,'TRUE','Y','FALSE','-',isadjusted) as isadjusted + , decode(isdeprecated,'TRUE','Y','FALSE','-',isdeprecated) as isdeprecated + , decode(isbasic,'TRUE','Y','FALSE','-',isbasic) as isbasic + , DESCRIPTION + from gv$parameter +where name like lower('%&&PARA_NAME.%') +order by 1 +/ + +prompt .... +prompt .... column "De" = is default +prompt .... column "Se" = can be changed with alter session +prompt .... column "Sy" = can be changed with alter system => I = change will work immediately | D = only new sessions +prompt .... column "Im" = can be changed for one instance in a cluster +prompt .... column "Mo" = has been modified after instance startup => M = alter session | S=alter system +prompt .... column "Ad" = is adjusted internaly by oracle +prompt .... column "Dp" = is deprecated +prompt .... column "Ba" = is basic parameter +prompt .... +prompt .... to adjust : alter system set = scope=both|memory|spfile sid='*' +prompt .... + +ttitle left "init.ora parameter Hidden Values" skip 2 + + +column value format a20 heading "Instance|Value" +column value_session format a20 heading "Session|Value" +column name format a40 heading "Parameter" + +select a.ksppinm as name + , b.ksppstvl as value_session + , b.addr + , c.ksppstvl as value + , decode(b.ksppstdf,'TRUE','Y','FALSE','-',b.ksppstdf) as isdefault + , decode(bitand(a.ksppiflg/256,3),1, 'Y', '-') as isses_modifiable + --, decode(bitand(a.ksppiflg/65536,3),1,'IMMEDIATE',2,'DEFERRED',3,'IMMEDIATE','FALSE') as issys_modifiable + , ksppdesc as description +from sys.x$ksppi a + , sys.x$ksppcv b + , sys.x$ksppsv c +where a.indx = b.indx + and a.indx = c.indx + --and substr(ksppinm,1,1)='_' + and lower(a.ksppinm) like lower('%&&PARA_NAME.%') +order by a.ksppinm +/ + + +ttitle off diff --git a/init_rac.sql b/init_rac.sql new file mode 100644 index 0000000..735bcc4 --- /dev/null +++ b/init_rac.sql @@ -0,0 +1,31 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show init.parameter in a RAC Environment to check if same parameters on each node +-- Date: 01.September 2012 +--============================================================================== +set linesize 130 pagesize 300 + +ttitle left "Check Rac init.ora non default parameter if equal" skip 2 + +column parameter format a30 +column value_instance1 format a30 heading "Value|Inst 1" +column value_instance2 format a25 heading "Value|Inst 2" +column value_instance3 format a10 heading "Value|Inst 3" +column value_instance4 format a10 heading "Value|Inst 4" + +select inst1.name as parameter + , inst1.VALUE as value_instance1 + , inst2.VALUE as value_instance2 + , inst3.VALUE as value_instance3 + , inst4.VALUE as value_instance4 + from (select * from gv$parameter where (isdefault != 'TRUE' or name in ('parameter','nls_language','nls_territory','nls_length_semantics') )and inst_id=1) inst1 + ,(select * from gv$parameter where (isdefault != 'TRUE' or name in ('parameter','nls_language','nls_territory','nls_length_semantics') )and inst_id=2) inst2 + ,(select * from gv$parameter where (isdefault != 'TRUE' or name in ('parameter','nls_language','nls_territory','nls_length_semantics') )and inst_id=3) inst3 + ,(select * from gv$parameter where (isdefault != 'TRUE' or name in ('parameter','nls_language','nls_territory','nls_length_semantics') )and inst_id=4) inst4 + where inst1.name = inst2.name (+) + and inst1.name = inst3.name (+) + and inst1.name = inst4.name (+) +order by 1 +/ + +ttitle off \ No newline at end of file diff --git a/instance.sql b/instance.sql new file mode 100644 index 0000000..9521408 --- /dev/null +++ b/instance.sql @@ -0,0 +1,32 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Status of the login instance +-- Date: 01.September 2013 +--============================================================================== +set linesize 130 pagesize 300 + +ttitle left "Status of this instances" skip 2 + +column status format A8 heading "Status" +column name format A8 heading "Instance|Name" +column startzeit format A15 heading "Start|Time" +column host_name format A35 heading "Server|Name" + +select status + , instance_name as name + , to_char(STARTUP_TIME, 'dd.mm.YY hh24:mi') as startzeit + , host_name + from v$instance + order by 1 +/ + +ttitle left "The instance is running under this OS User:" skip 2 + +column osuser format A20 heading "OS User" + +select osuser + from v$session + where program like '%PMON%' +/ + +ttitle off diff --git a/invalid.sql b/invalid.sql new file mode 100644 index 0000000..7911c45 --- /dev/null +++ b/invalid.sql @@ -0,0 +1,141 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show invalid objects in the database +-- Date: 01.September 2012 +-- +--============================================================================== +set linesize 130 pagesize 300 +set verify off + +ttitle center "Invalid Objects in the database" skip 2 + +define IGNORE_SCHEMA='''GPI''' + +column owner format a15 +column object_type format a18 + +break on report +compute sum of anzahl on report + + select owner, object_type, count (*) as anzahl + from dba_objects + where status != 'VALID' + and object_type!='MATERIALIZED VIEW' + --and owner not in (&IGNORE_SCHEMA) +--group by rollup(owner, object_type) +group by owner, object_type +order by owner +/ + + +ttitle "count of invalid materialized view" skip 2 +select owner + , count (*) as anzahl + , compile_state + , staleness + from dba_mviews +where compile_state != 'VALID' or staleness !='FRESH' + --and owner not in (&IGNORE_SCHEMA) +group by owner,compile_state,staleness +order by owner,compile_state +/ + +ttitle "Count of not validated or invalid constraints" skip 2 + +select owner,count(*) as anzahl,validated,status + from dba_constraints + where ( validated != 'VALIDATED' + or status != 'ENABLED') + and owner not in + ('SYS' + , 'MDSYS' + , 'SI_INFORMTN_SCHEMA' + , 'ORDPLUGINS' + , 'ORDDATA' + , 'ORDSYS' + , 'EXFSYS' + , 'XS$NULL' + , 'XDB' + , 'CTXSYS' + , 'WMSYS' + , 'APPQOSSYS' + , 'DBSNMP' + , 'ORACLE_OCM' + , 'DIP' + , 'OUTLN' + , 'SYSTEM' + , 'FLOWS_FILES' + , 'PUBLIC' + , 'SYSMAN' + , 'OLAPSYS' + , 'OWBSYS' + , 'OWBSYS_AUDIT') +group by validated,status,owner +order by owner +/ +prompt ... +prompt ... for more details use invalid_constraints.sql +prompt ... + +clear breaks + + + + +ttitle "List of invalid indexes" skip 2 + +select owner + , index_name + , status + , 'no partition' + from dba_indexes + where status not in ('VALID', 'N/A') +union +select index_owner + , index_name + , status + , partition_name + from dba_ind_partitions + where status not in ('VALID', 'N/A', 'USABLE') +order by owner +/ + + + +ttitle "List of invalid Objects" skip 2 +break on owner skip 2 +column owner noprint + + select object_type || '-> ' || decode (owner, 'PUBLIC', '', owner || '.') || object_name as Overview, owner + from dba_objects + where status != 'VALID' + and owner not in (&IGNORE_SCHEMA) + and object_type!='MATERIALIZED VIEW' +order by owner,object_type +/ + +clear breaks +column owner print + +ttitle "-- Command to touch the Objects" skip 2 +set pagesize 4000 + +spool desc_invalid.log + +select 'desc ' || decode (owner, 'PUBLIC', '', owner || '.') || object_name as "-- TOUCH_ME" + from dba_objects + where status != 'VALID' + and owner not in (&IGNORE_SCHEMA) + and object_type!='MATERIALIZED VIEW' +order by owner,object_type +/ + +spool off + +prompt ... +prompt ... to describe all invalid objects call desc_invalid.log +prompt ... + +set pagesize 300 + +ttitle off \ No newline at end of file diff --git a/invalid_constraints.sql b/invalid_constraints.sql new file mode 100644 index 0000000..55c5c4a --- /dev/null +++ b/invalid_constraints.sql @@ -0,0 +1,53 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show invalid constraints in the database +-- Date: 10 2015 +-- +--============================================================================== +set linesize 130 pagesize 300 + + +ttitle "List of not validated or invalid constraints" skip 2 + +column owner format a20 +column table_name format a30 +column constraint_name format a30 +column validated format a20 + +select owner + , table_name + , constraint_name + , status + , validated + from dba_constraints + where ( validated != 'VALIDATED' + or status != 'ENABLED') + and owner not in + ('SYS' + , 'MDSYS' + , 'SI_INFORMTN_SCHEMA' + , 'ORDPLUGINS' + , 'ORDDATA' + , 'ORDSYS' + , 'EXFSYS' + , 'XS$NULL' + , 'XDB' + , 'CTXSYS' + , 'WMSYS' + , 'APPQOSSYS' + , 'DBSNMP' + , 'ORACLE_OCM' + , 'DIP' + , 'OUTLN' + , 'SYSTEM' + , 'FLOWS_FILES' + , 'PUBLIC' + , 'SYSMAN' + , 'OLAPSYS' + , 'OWBSYS' + , 'OWBSYS_AUDIT') +order by owner +/ + + +ttitle off \ No newline at end of file diff --git a/invalid_obj_report.sql b/invalid_obj_report.sql new file mode 100644 index 0000000..04ba323 --- /dev/null +++ b/invalid_obj_report.sql @@ -0,0 +1,52 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: HTML Report over all invalid objects of a database, +-- for example to discuss with development which objects can be deleted +-- Date: September 2015 +-- +--============================================================================== + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_invalid_overview.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + +set verify off +SET linesize 250 pagesize 2000 + +spool &&SPOOL_NAME + +set markup html on + +ttitle left "Invalid Object Overview of this database" skip 2 + +select o.owner + , o.object_name + , o.object_type + , o.status + , 'IN USE' as IN_USE_OR_ARCHIVE + , 'n/a' as comments + , 'n/a' as responsible_developer + , o.created + , o.LAST_DDL_TIME + -- dependencies + , (select count(*) as results from dba_dependencies dep where dep.REFERENCED_OWNER=o.owner and dep.REFERENCED_NAME=o.object_name) as depObjCount + , (select substr(rtrim ( xmlagg (xmlelement (c, dep.type||':'||dep.name || ',') order by dep.name).extract ('//text()'), ',' ),1,3999) as results from dba_dependencies dep where dep.REFERENCED_OWNER=o.owner and dep.REFERENCED_NAME=o.object_name) as depObjList + from dba_objects o +where o.status!='VALID' + and o.object_type!='MATERIALIZED VIEW' +order by owner,object_type +/ + +set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window + +host &&SPOOL_NAME diff --git a/invalid_synoyms.sql b/invalid_synoyms.sql new file mode 100644 index 0000000..cd185d9 --- /dev/null +++ b/invalid_synoyms.sql @@ -0,0 +1,66 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show invalid synonyms in the database and create delete script +-- Date: 01.Oktober 2015 +-- +--============================================================================== +set linesize 130 pagesize 900 + + +ttitle center "Count of synonyms without an existing owner in the database" skip 2 + + +break on report +compute sum of anzahl on report + +select count(*) as anzahl + , table_owner + from dba_synonyms +where table_owner not in (select username from dba_users) + and (db_link is null or db_link = 'PUBLIC') +group by table_owner; + +clear breaks + +ttitle center "Invalid synonyms in the database" skip 2 + +column owner format a15 +column table_owner format a15 + +select decode(s.owner, 'PUBLIC', 'PUBLIC SYNONYM ', 'SYNONYM ') as SYN_TYPE, s.owner, s.synonym_name, '=>>', s.table_owner, s.table_name + from dba_synonyms s +where table_owner not in ('SYSTEM', 'SYS') + and (db_link is null or db_link = 'PUBLIC') + and not exists (select 1 + from dba_objects o + where decode(s.table_owner, 'PUBLIC', o.owner, s.table_owner) = o.owner + and s.table_name = o.object_name) +/ + +ttitle center "Delete Script" skip 2 + +set pagesize 4000 + +spool delete_synonym_invalid.log + + +select 'drop ' || decode(s.owner, 'PUBLIC', 'PUBLIC SYNONYM ', 'SYNONYM ' || s.owner || '.') ||'"'|| s.synonym_name || '";' as DELETE_ME + from dba_synonyms s +where table_owner not in ('SYSTEM', 'SYS') + and (db_link is null or db_link = 'PUBLIC') + and not exists (select 1 + from dba_objects o + where decode(s.table_owner, 'PUBLIC', o.owner, s.table_owner) = o.owner + and s.table_name = o.object_name) +/ + +spool off + +prompt ... +prompt ... to drop all invalid synonyms you can call delete_synonym_invalid.log +prompt ... + +set pagesize 300 + + +ttitle off diff --git a/java.sql b/java.sql new file mode 100644 index 0000000..ec2fec5 --- /dev/null +++ b/java.sql @@ -0,0 +1,31 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get Information about the installed java options and security settings +--============================================================================== +set linesize 130 pagesize 4000 + +column KIND +column GRANTEE format a15 +column TYPE_SCHEMA format a10 heading "Type|Schema" +column TYPE_NAME format a25 heading "Type|Name" +column NAME format a25 heading "Name" +column ACTION format a25 +column ENABLED format a10 +column SEQ format 9999 + +ttitle "Java Access Rights" SKIP 2 + +select KIND + , GRANTEE + , TYPE_SCHEMA + , TYPE_NAME + , NAME + , ACTION + , ENABLED + , SEQ +from DBA_JAVA_POLICY +where GRANTEE != 'SYS' +order by SEQ +/ + +ttitle off diff --git a/java_recomplie_invalid.sql b/java_recomplie_invalid.sql new file mode 100644 index 0000000..4c85a25 --- /dev/null +++ b/java_recomplie_invalid.sql @@ -0,0 +1,49 @@ +-- -- +-- +-- +-- --- + +set serveroutput on + +---------- + +select count(*),owner + from dba_objects + where status != 'VALID' + and Object_type='JAVA CLASS' + group by owner +/ + +---------- + +declare + cursor c_resolve is + select 'alter java class '|| owner ||'.' ||'"'||object_name||'" resolve' as command + from dba_objects + where status != 'VALID' + and Object_type='JAVA CLASS'; + begin + for i in 1 .. 10 + loop + for rec in c_resolve + loop + begin + execute immediate rec.command; + dbms_output.put_line(' -- Info execute ::'||rec.command); + exception + when others then + dbms_output.put_line(' -- Error execute ::'||rec.command ||' :: SQLERRM:'||SQLERRM); + end; + end loop; + end loop; +end; +/ + +---------- + +select count(*),owner + from dba_objects + where status != 'VALID' + and Object_type='JAVA CLASS' + group by owner +/ diff --git a/jobs.sql b/jobs.sql new file mode 100644 index 0000000..28ad84a --- /dev/null +++ b/jobs.sql @@ -0,0 +1,18 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc : Information about jobs in the database +--============================================================================== +SET linesize 130 pagesize 300 + +@jobs_dbms.sql + +@jobs_sheduler.sql + +prompt +prompt init.ora Settings for the job queue + +show parameter job_queue_processes + +prompt +prompt +prompt diff --git a/jobs_dbms.sql b/jobs_dbms.sql new file mode 100644 index 0000000..99ff8bd --- /dev/null +++ b/jobs_dbms.sql @@ -0,0 +1,71 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show all jobs create over dbms_job in the database +-- Date: 01.September 2012 +--============================================================================== +set linesize 130 pagesize 300 + +ttitle left "Job Infos -- Oracle JOB Table " skip 2 + +column job format 9999999 heading "Job|Name" +column last_date format a14 heading "Last|date" +column this_date format a14 heading "This|date" +column next_date format a14 heading "Next|date" +column interval format a30 heading "Interval" word_wrapped +column broken format a3 heading "Is|Brocken" +column schema_user format a11 heading "Schema|User" +column owner format a11 heading "Owner" +column failures format 99 heading "Fail|Cnt" +column what format a10 heading "What|is called" word_wrapped +column instance format 9999 heading "Inst|ID" + + +ttitle left "Job Infos -- Oracle JOB defined with dbms_job" skip 2 + + select job + , schema_user + , substr (what, 1, 20) as what + , to_char (last_date, 'dd.mm.yy hh24:mi') as last_date + , to_char (this_date, 'dd.mm.yy hh24:mi') as this_date + , to_char (next_date, 'dd.mm.yy hh24:mi') as next_date + , interval + , failures + , broken + , instance + from dba_jobs +order by schema_user, job +/ + + +ttitle left "Job Infos -- job calls what?" skip 2 + +column what format a110 heading "What|is called" word_wrapped + + select job, WHAT as what + from dba_jobs +order by job +/ + +ttitle left "Job Infos -- Oracle JOB Table Jobs with failures " skip 2 + +column what format a10 heading "What|is called" word_wrapped + +select job + , schema_user + , substr (what, 1, 20) as what + , to_char (last_date, 'dd.mm.yy hh24:mi') as last_date + , to_char (this_date, 'dd.mm.yy hh24:mi') as this_date + , to_char (next_date, 'dd.mm.yy hh24:mi') as next_date + , interval + , failures + , broken + from dba_jobs + where (failures > 0 or broken = 'Y') +order by schema_user, job +/ + +ttitle off + +prompt +prompt -- ***************************************************** +prompt \ No newline at end of file diff --git a/jobs_errors.sql b/jobs_errors.sql new file mode 100644 index 0000000..fef2a56 --- /dev/null +++ b/jobs_errors.sql @@ -0,0 +1,113 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show all jobs in the database with an error +--=============================================================================== +set linesize 130 pagesize 300 + +------------------------------------------------------------ + +ttitle left "Job Infos -- Oracle Failed JOBs " skip 2 + +column job format 9999999 +column what format a15 +column last_date format a13 +column this_date format a13 +column next_date format a13 +column interval format a20 +column broken format a2 +column schema_user format a10 + +column owner format a10 + + select job + , schema_user + , substr (what, 1, 20) as what + , to_char (last_date, 'dd.mm hh24:mi') as last_date + , to_char (this_date, 'dd.mm hh24:mi') as this_date + , to_char (next_date, 'dd.mm hh24:mi') as next_date + , interval + , failures + , broken + from dba_jobs + where (failures > 0 or broken = 'Y') +order by schema_user, job +/ + +column what format a100 + + select job, WHAT as what + from dba_jobs + where (failures > 0 or broken = 'Y') +order by schema_user, job +/ + + + +------------------------------------------------------------ +-- What scheduled tasks failed during execution, and why? + +ttitle 'Scheduled Tasks That Failed' skip 2 +prompt Scheduled Tasks That Failed: + +column log_date format a32 heading 'Log Date' +column owner format a06 heading 'Owner' +column job_name format a26 heading 'Job' +column status format a10 heading 'Status' +column actual_start_date format a32 heading 'Actual|Start|Date' +column error# format 999999 heading 'Error|Nbr' + + select log_id + , log_date + , owner + , job_name + , status + , substr (actual_start_date, 1, 18) || ' ...' as actual_start_date + , error# + from dba_scheduler_job_run_details + where nvl (status, '-') <> 'SUCCEEDED' + and log_date > ( sysdate - 7) +order by log_id desc +/ + +------------------------------------------------------------ + +ttitle 'Scheduled Tasks with out a status' skip 2 +prompt Scheduled Tasks with out a status: + + select log_id + , log_date + , owner + , job_name + , status + , OPERATION + from dba_scheduler_job_log + where nvl (status, '-') <> 'SUCCEEDED' + and log_date > ( sysdate + - 7) +order by log_id desc +/ + + +------------------------------------------------------------ +ttitle 'Auto Task with an error' skip 2 + +column client_name format a25 heading "Job|Name" +column job_status format a10 heading "Job|status" +column job_info format a25 heading "Job|Info" +column JOB_START_TIME format a18 heading "Last|Start" +column window_name format a18 heading "Window|Name" + + select client_name + , window_name + , job_status + , job_info + , JOB_START_TIME + from dba_autotask_job_history + where ( job_status <> 'SUCCEEDED' + or job_status is null) +order by 1, 2 +/ + +prompt +prompt +ttitle off \ No newline at end of file diff --git a/jobs_logs.sql b/jobs_logs.sql new file mode 100644 index 0000000..bdc82c7 --- /dev/null +++ b/jobs_logs.sql @@ -0,0 +1,58 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the logs of a job +--============================================================================== +set linesize 130 pagesize 300 + +------------------------------------------------------------ + +define JOB_NAME='&1' + +prompt +prompt Parameter 1 = JOB_NAME => &&JOB_NAME. +prompt + +------------------------------------------------------------ +-- Job Runs + +ttitle 'Job Runs over dba_scheduler_job_run_details' skip 2 + +column log_date format a32 heading 'Log Date' +column owner format a06 heading 'Owner' +column job_name format a26 heading 'Job' +column status format a10 heading 'Status' +column actual_start_date format a32 heading 'Actual|Start|Date' +column error# format 999999 heading 'Error|Nbr' +column instance_id format 9999 heading "Inst|ID" + + select log_id + , log_date + , owner + , job_name + , status + , substr (actual_start_date, 1, 18) || ' ...' as actual_start_date + , error# + , instance_id + from dba_scheduler_job_run_details + where job_name like upper ('%&&JOB_NAME.%') + and log_date > ( sysdate - 7) +order by log_id desc +/ + +ttitle 'Log : dba_scheduler_job_log' skip 2 + +prompt Scheduled Tasks with out a status: + + select log_id + , log_date + , owner + , job_name + , status + , OPERATION + from dba_scheduler_job_log + where job_name like upper ('%&&JOB_NAME.%') + and log_date > ( sysdate - 7) +order by log_id desc +/ + +ttitle off diff --git a/jobs_sheduler.sql b/jobs_sheduler.sql new file mode 100644 index 0000000..9e85cb2 --- /dev/null +++ b/jobs_sheduler.sql @@ -0,0 +1,216 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show all jobs create over dbms_sheduler in the database +--============================================================================== +set linesize 130 pagesize 800 + +ttitle "Job Scheduler Information -- Oracle scheduler table " skip 2 + +column log_id format 9999999 heading "Log|id" +column log_date format a13 heading "Log|date" +column job_name format a15 heading "Job|name" +column status format a10 heading "Job|status" +column cpu_used format a10 heading "Cpu|used" +column program_name format a10 heading "Program|name" +column last_start_date format a11 heading "Last|start date" +column failure_count format 999 heading "Fail|cnt" +column next_run_date format a11 heading "Next|start date" +column job format 9999999 heading "Job|Name" +column last_date format a11 heading "Last|date" +column this_date format a11 heading "This|date" +column next_date format a11 heading "Next|date" +column interval format a30 heading "Interval" word_wrapped +column broken format a3 heading "Is|Brocken" +column schema_user format a11 heading "Schema|User" +column owner format a11 heading "Owner" +column failures format 99 heading "Fail|Cnt" +column what format a10 heading "What|is called" word_wrapped +column state format a4 heading "Sta|te" +column job_action format a13 heading "Job|Action" word_wrapped +column run_count format 99G999G999 heading "Run|cnt" +column CREATED format a17 heading "Job|Created" +column job_class format a17 heading "Job|Class" +column job_class_name format a28 heading "Job|Class Name" +column resource_consumer_group format a25 heading "Consumer|Group" +column service format a18 heading "Service" +column logging_level format a18 heading "Log|Level" +column log_history format 99999999 heading "Log|Hist" +column comments format a20 heading "Comments" word_wrapped + + +ttitle "Job Scheduler -- Oracle scheduler table" skip 2 + + + select js.owner + , js.job_name + , decode (js.state, 'SCHEDULED', 'SHUD', 'DISABLED', 'DIS', 'RUNNING', 'RUN', js.state) as state + , js.JOB_CLASS + , js.program_name + , js.job_action + , to_char (o.CREATED, 'dd.mm.yyyy hh24:mi') as CREATED + --, JOB_STYLE + , js.run_count + , js.failure_count + , to_char (js.last_start_date, 'dd.mm hh24:mi') as last_start_date + , to_char (js.next_run_date, 'dd.mm hh24:mi') as next_run_date + from dba_scheduler_jobs js, dba_objects o + where js.owner = o.owner(+) + and js.job_name = o.OBJECT_NAME(+) +order by owner, job_name +/ + + +ttitle "Job Scheduler Classes" skip 2 + + select job_class_name + , resource_consumer_group + , service + , logging_level + , log_history + , comments + from dba_scheduler_job_classes +order by job_class_name +/ + + +ttitle "Job Scheduler History -- Oracle scheduler table of the last day - only the last 20" skip 2 + + +column job_name format a30 heading "Job|name" + +select * + from ( select log_id + , to_char (log_date, 'dd.mm hh24:mi') as log_date + , owner + , job_name + , status + from dba_scheduler_job_log + where log_date > ( sysdate + - 1) + order by log_date, owner) + where rownum < 20 +/ + +ttitle "Job Scheduler History -- Summary of the last 24 hours" skip 2 + + select owner + , job_name + , nvl (status, '-') as status + , count (*) + from dba_scheduler_job_log + where log_date > ( sysdate + - 1) +group by owner, job_name, nvl (status, '-') +order by owner, job_name +/ + +ttitle 'Scheduled Tasks duration histroy of the last day - only the first 40' + +select * + from ( select l.job_name + , sum ( extract (second from d.cpu_used) + + ( extract (minute from d.cpu_used) + * 60) + + ( extract (hour from d.cpu_used) + * 60 + * 60)) + as timeused + , l.log_id + , l.job_class + from dba_scheduler_job_log l, dba_scheduler_job_run_details d + where d.log_id = l.log_id + and d.log_date > ( sysdate + - 1) + group by l.job_name, l.log_id, l.job_class + order by l.log_id) + where rownum < 40 +/ + +-- What scheduled tasks failed during execution, and why? + +ttitle 'Scheduled Tasks That Failed' +prompt Scheduled Tasks That Failed: + +column log_date format a32 heading 'Log Date' +column owner format a06 heading 'Owner' +column job_name format a26 heading 'Job' +column status format a10 heading 'Status' +column actual_start_date format a32 heading 'Actual|Start|Date' +column error# format 999999 heading 'Error|Nbr' + + select log_id + , log_date + , owner + , job_name + , status + , substr (actual_start_date, 1, 18) || ' ...' as actual_start_date + , error# + from dba_scheduler_job_run_details + where nvl (status, '-') <> 'SUCCEEDED' + and log_date > ( sysdate + - 1) +order by log_id desc +/ + + +ttitle 'Scheduled Tasks without a Status - may be failed' +prompt Scheduled Tasks That Failed: + + select log_id + , log_date + , owner + , job_name + , status + , OPERATION + from dba_scheduler_job_log + where nvl (status, '-') <> 'SUCCEEDED' + and log_date > ( sysdate + - 1) +order by log_id desc +/ + +ttitle left "Job Scheduler Window Settings " skip 2 + +prompt +prompt check if the window is not activ in the past! +prompt + +column check_active format a10 heading 'Check|if ok' + + select window_name + , to_char (last_start_date, 'DD.MM.YYYY HH24:MI') as last_start_date + , enabled + , active + , decode (active, 'TRUE', '<==CHECK IF POSSIBLE', '-') as check_active + from dba_scheduler_windows +order by last_start_date +/ + + + +ttitle 'Auto Tasks:' +prompt Auto Task overview: + +column client_name format a35 heading "Job|Name" +column status format a10 heading "Job|status" +column mean_job_duration format a10 heading "Mean|duration" +column mdl7 format a10 heading "Max|duration" +column next_start_date format a18 heading "Next|run" +column window_group_name format a18 heading "Window|group" + + select c.client_name + , c.status + , w.window_group_name + , w.next_start_date + , c.mean_job_duration + , c.max_duration_last_7_days as mdl7 + from dba_autotask_client c, dba_scheduler_window_groups w + where w.window_group_name = c.window_group +order by 1 +/ + +ttitle off + +prompt +prompt -- ***************************************************** +prompt diff --git a/jobs_window_resource_class.sql b/jobs_window_resource_class.sql new file mode 100644 index 0000000..437505b --- /dev/null +++ b/jobs_window_resource_class.sql @@ -0,0 +1,58 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Show the relation between job windows , job classes and resource plans +--=============================================================================== +set linesize 130 pagesize 300 + +column job_class_name format a25 +column job_class_service format a25 +column resource_plan format a28 +column consumer_group format a25 +column job_window format a20 + + +select jc.job_class_name + , jc.service as job_class_service + , cg.consumer_group + , pd.plan as resource_plan + , sw.window_name as job_window + from dba_scheduler_job_classes jc + , dba_rsrc_consumer_groups cg + , dba_rsrc_plan_directives pd + , dba_scheduler_windows sw + , DBA_RSRC_GROUP_MAPPINGS gm + where jc.resource_consumer_group = cg.consumer_group + and cg.consumer_group = pd.group_or_subplan(+) + and sw.resource_plan(+) = pd.group_or_subplan +order by 1 +/ + + +select jc.job_class_name + , jc.service as job_class_service + , pd.group_or_subplan + , pd.plan as resource_plan + from dba_scheduler_job_classes jc, dba_rsrc_plan_directives pd, DBA_RSRC_GROUP_MAPPINGS gm + where gm.CONSUMER_GROUP = pd.group_or_subplan + and gm.ATTRIBUTE = 'SERVICE_NAME' + and gm.value = jc.service +order by 1 +/ + +select jc.job_class_name + , jc.service as job_class_service + , cg.consumer_group + , p.plan as resource_plan + , sw.window_name as job_window + from dba_rsrc_consumer_groups cg + , dba_rsrc_plan_directives pd + , dba_rsrc_plans p + , dba_scheduler_job_classes jc + , dba_scheduler_windows sw + where jc.resource_consumer_group = cg.consumer_group + and cg.consumer_group = pd.group_or_subplan + and p.plan = pd.plan + and pd.type = 'CONSUMER_GROUP' + and sw.resource_plan(+) = p.plan +order by jc.job_class_name +/ \ No newline at end of file diff --git a/latch.sql b/latch.sql new file mode 100644 index 0000000..ea9527f --- /dev/null +++ b/latch.sql @@ -0,0 +1,20 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get Information’s about the DB latch usage +--============================================================================== +set linesize 130 pagesize 300 + +column name format a32 +column gets format 999G999G999 +column ratio_miss format 90D99 +column spin_gets format 999G999G999 + +select a.name + , a.gets gets + , a.misses + , ROUND(a.misses * 100 / DECODE(a.gets, 0, 1, a.gets), 2) ratio_miss + , a.spin_gets + from v$latch a + where a.misses <> 0 + order by 2 desc + / diff --git a/licence.sql b/licence.sql new file mode 100644 index 0000000..5bbb31b --- /dev/null +++ b/licence.sql @@ -0,0 +1,191 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: HTML Report - License Report Overview - Feature Usage +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +col SPOOL_NAME_COL new_val SPOOL_NAME + +select replace ( + ora_database_name + || '_' + || sys_context ('USERENV', 'HOST') + || '_' + || to_char (sysdate, 'dd_mm_yyyy_hh24_mi') + || '_licence.html' + , '\' + , '_') + --' resolve syntax highlight bug FROM my editer .-( + as SPOOL_NAME_COL + from dual +/ + + + +spool &&SPOOL_NAME + +set markup html on + +ttitle center "Database Information" skip 2 + + select v.instance_name + , v.inst_id + , v.host_name + , to_char (d.dbid) as dbid + , d.name + , to_char (d.created, 'dd.mm.yyyy hh24:mi') as "Create Time" + , (select banner + from v$version + where banner like 'Oracle Data%') + as edition + from gv$database d, gv$instance v +order by v.instance_name +/ + + +ttitle center "Installed Options" skip 2 + + select parameter as "Option", value as "Installed" + from v$option + where value = 'TRUE' +order by value desc +/ + +ttitle center "Last Feature Check" skip 2 + + select to_char (FS.LAST_SAMPLE_DATE, 'dd.mm.yyyy hh24:mi') as "Last Feature Check" + from dba_feature_usage_statistics fs +group by FS.LAST_SAMPLE_DATE +/ + +ttitle center "11g Feature Overview" skip 2 + +prompt "for the 'Oracle Supported Script see Options / Features View 11g see metalink note Database Options/Management Packs Usage Reporting for Oracle Database 11g Release 2 [ID 1317265.1]" + +with v_feature + as (select a feature_option, b detailname + from (select 'Active Data Guard' a, 'Active Data Guard - Real-Time Query on Physical Standby' b from dual + union all + select 'Advanced Compression', 'HeapCompression' from dual + union all + select 'Advanced Compression', 'Backup BZIP2 Compression' from dual + union all + select 'Advanced Compression', 'Backup DEFAULT Compression' from dual + union all + select 'Advanced Compression', 'Backup HIGH Compression' from dual + union all + select 'Advanced Compression', 'Backup LOW Compression' from dual + union all + select 'Advanced Compression', 'Backup MEDIUM Compression' from dual + union all + select 'Advanced Compression', 'Backup ZLIB, Compression' from dual + union all + select 'Advanced Compression', 'SecureFile Compression (user)' from dual + union all + select 'Advanced Compression', 'SecureFile Deduplication (user)' from dual + union all + select 'Advanced Compression', 'Data Guard' from dual + union all + select 'Advanced Compression', 'Oracle Utility Datapump (Export)' from dual + union all + select 'Advanced Compression', 'Oracle Utility Datapump (Import)' from dual + union all + select 'Advanced Security', 'ASO native encryption and checksumming' from dual + union all + select 'Advanced Security', 'Transparent Data Encryption' from dual + union all + select 'Advanced Security', 'Encrypted Tablespaces' from dual + union all + select 'Advanced Security', 'Backup Encryption' from dual + union all + select 'Advanced Security', 'SecureFile Encryption (user)' from dual + union all + select 'Change Management Pack (GC)', 'Change Management Pack (GC)' from dual + union all + select 'Data Masking Pack', 'Data Masking Pack (GC)' from dual + union all + select 'Data Mining', 'Data Mining' from dual + union all + select 'Diagnostic Pack', 'Diagnostic Pack' from dual + union all + select 'Diagnostic Pack', 'ADDM' from dual + union all + select 'Diagnostic Pack', 'AWR Baseline' from dual + union all + select 'Diagnostic Pack', 'AWR Baseline Template' from dual + union all + select 'Diagnostic Pack', 'AWR Report' from dual + union all + select 'Diagnostic Pack', 'Baseline Adaptive Thresholds' from dual + union all + select 'Diagnostic Pack', 'Baseline Static Computations' from dual + union all + select 'Tuning Pack', 'Tuning Pack' from dual + union all + select 'Tuning Pack', 'Real-Time SQL Monitoring' from dual + union all + select 'Tuning Pack', 'SQL Tuning Advisor' from dual + union all + select 'Tuning Pack', 'SQL Access Advisor' from dual + union all + select 'Tuning Pack', 'SQL Profile' from dual + union all + select 'Tuning Pack', 'Automatic SQL Tuning Advisor' from dual + union all + select 'Database Vault', 'Oracle Database Vault' from dual + union all + select 'WebLogic Server Management Pack Enterprise Edition', 'EM AS Provisioning and Patch Automation (GC)' + from dual + union all + select 'Configuration Management Pack for Oracle Database', 'EM Config Management Pack (GC)' from dual + union all + select 'Provisioning and Patch Automation Pack for Database' + , 'EM Database Provisioning and Patch Automation (GC)' + from dual + union all + select 'Provisioning and Patch Automation Pack', 'EM Standalone Provisioning and Patch Automation Pack (GC)' + from dual + union all + select 'Exadata', 'Exadata' from dual + union all + select 'Label Security', 'Label Security' from dual + union all + select 'OLAP', 'OLAP - Analytic Workspaces' from dual + union all + select 'Partitioning', 'Partitioning (user)' from dual + union all + select 'Real Application Clusters', 'Real Application Clusters (RAC)' from dual + union all + select 'Real Application Testing', 'Database Replay: Workload Capture' from dual + union all + select 'Real Application Testing', 'Database Replay: Workload Replay' from dual + union all + select 'Real Application Testing', 'SQL Performance Analyzer' from dual + union all + select 'Spatial' + , 'Spatial (Not used because this does not differential usage of spatial over locator, which is free)' + from dual + union all + select 'Total Recall', 'Flashback Data Archive' from dual)) + select nvl (fs.name, fe.detailname) as "Name" + , fe.feature_option as "Option" + , fs.version as "Version" + , nvl (fs.currently_used, 'FALSE') as "In Use" + , fs.detected_usages as "Detected" + , to_char (fs.first_usage_date, 'dd.mm.yyyy hh24:mi') as "First Usage" + , to_char (fs.last_usage_date, 'dd.mm.yyyy hh24:mi') as "Last Usage" + , fs.description as "Description" + from dba_feature_usage_statistics fs, v_feature fe + where fe.detailname(+) = fs.name +order by nvl (fs.currently_used, 'FALSE') desc, fs.name +/ + +set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window +host &&SPOOL_NAME \ No newline at end of file diff --git a/limit.sql b/limit.sql new file mode 100644 index 0000000..a1be123 --- /dev/null +++ b/limit.sql @@ -0,0 +1,30 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get Information over the usage of resources of the database +-- Date: November 2013 +-- +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Resource Limit Informations" SKIP 2 + +column INST_ID format 9999 heading "INST|ID" +column RESOURCE_NAME format a25 heading "Resource|Name" +column CURRENT_UTILIZATION format 999G999G999 heading "Act|Usage" +column MAX_UTILIZATION format 999G999G999 heading "Max|Usage" +column INITIAL_ALLOCATION format a10 heading "Init|Value" +column LIMIT_VALUE format 999999 heading "Limit|Value" + + +select inst_id + , resource_name + , current_utilization + , max_utilization + , initial_allocation + , limit_value + from gv$resource_limit +order by 1,2 desc +/ + +ttitle off + diff --git a/links.sql b/links.sql new file mode 100644 index 0000000..f58e42a --- /dev/null +++ b/links.sql @@ -0,0 +1,94 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: DB Links +-- Date: 01.September 2012 +-- +--============================================================================== +set linesize 130 pagesize 300 + +set verify off + +define LINKHOST = &1 + +variable PLINKHOST varchar2(32) + +prompt +prompt Parameter 1 = Link Host => &&LINKHOST. +prompt + +begin + if length('&&LINKHOST.') < 1 then + :PLINKHOST:='%'; + else + :PLINKHOST:='&&LINKHOST.'||'%'; + end if; +end; +/ + + + +prompt +prompt Link Infos -- The DB Links this user can see +prompt + +column owner format a20 +column host format a40 +column db_link format a25 +column username format a20 + + +select db_link + , host + , owner + , username + from all_db_links +where lower(host) like lower(:PLINKHOST) + / + + +ttitle left "Link Infos -- All DB Links in the database" skip 2 + +select db_link + , owner + , host + , username + from dba_db_links +where lower(host) like lower(:PLINKHOST) + / + + + + +prompt ... +prompt ... to create a private db link use this statement: +prompt ... "CREATE DATABASE LINK mylink CONNECT TO remote_user IDENTIFIED BY remote_pwd USING 'remote_db';" +prompt ... to get the DDL of all links use links_ddl.sql +prompt ... + +--see http://docs.oracle.com/cd/B28359_01/server.111/b28310/ds_admin005.htm + + +ttitle left "DB Links in Use now in the database" skip 2 + + +column DB_LINK format A25 +column OWNER_ID format 99999 HEADING "OWNID" +column LOGGED_ON format A5 HEADING "LOGON" +column HETEROGENEOUS format A5 HEADING "HETER" +column PROTOCOL format A8 +column OPEN_CURSORS format 999 HEADING "OPN_CUR" +column IN_TRANSACTION format A3 HEADING "TXN" +column UPDATE_SENT format A6 HEADING "UPDATE" +column COMMIT_POINT_STRENGTH format 99999 HEADING "C_P_S" + +SELECT * FROM V$DBLINK +/ + +ttitle off + +--undef variables --- + +undefine PUSERNAME + +--------------------- +set verify on diff --git a/links_ddl.sql b/links_ddl.sql new file mode 100644 index 0000000..3be436a --- /dev/null +++ b/links_ddl.sql @@ -0,0 +1,30 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: DB Links DDL +--============================================================================== + +set linesize 130 pagesize 300 + +set long 1000000 + +ttitle left "create DDL for all DB Links in the Database" skip 2 + +select '-- DBLINK OWNER : '||owner||chr(10)||chr(13)||dbms_metadata.get_ddl('DB_LINK',db_link,owner ) ||';'||chr(10)||chr(13) as stmt + from dba_db_links +--where upper(HOST) like '%GPI%' +/ + + + -- fix it to plsql block to use parameter +-- set the transformation attributes +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true ); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true ); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'OID', false); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SEGMENT_ATTRIBUTES', false); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'TABLESPACE', true ); + + + +ttitle off + diff --git a/links_usage.sql b/links_usage.sql new file mode 100644 index 0000000..d4bfc82 --- /dev/null +++ b/links_usage.sql @@ -0,0 +1,140 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: HTML Report for the db link Usages in the database +-- Date: September 2015 +-- +--============================================================================== + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_link_usage.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + +set verify off +SET linesize 250 pagesize 2000 + +spool &&SPOOL_NAME + +---set markup html ON ENTMAP OFF + +define SEARCH_HOST='GPI' + + +declare + cursor c_links + is + select owner,db_link + from dba_db_links + where upper(HOST) like '%&&SEARCH_HOST%' + order by 1; + + v_count pls_integer:=0; + +begin + dbms_output.put_line (''); + dbms_output.put_line (''); + dbms_output.put_line (''); + dbms_output.put_line (''); + dbms_output.put_line (''); + + for rec in c_links + loop + v_count:=0; + dbms_output.put_line (''); + dbms_output.put_line (''); + dbms_output.put_line (''); + dbms_output.put_line (''); + -- check source code + for srec in (select owner + , name + , type + , line + , text + from dba_source + where upper (text) like '%' || upper (rec.db_link) || '%' order by owner, name ,line) + loop + dbms_output.put_line (''); + dbms_output.put_line ( ' '); + v_count:=v_count+1; + dbms_output.put_line (''); + end loop; + + -- check materialsed views + for srec in ( select owner + , mview_name as name + , 'MV' as type + , 'n/a' as line + , query as text + from dba_mviews v + where upper(master_link)=upper (rec.db_link) order by owner,mview_name ) + loop + dbms_output.put_line (''); + dbms_output.put_line ( ' '); + v_count:=v_count+1; + dbms_output.put_line (''); + end loop; + dbms_output.put_line (''); + dbms_output.put_line (''); + dbms_output.put_line (''); + end loop; + dbms_output.put_line ('
' + || 'OWNER' + || ' ' + || 'TYPE' + || ' ' + || 'Object Name' + || ' ' + || 'Line' + || ' ' + || 'CODE' + ||'
'); + dbms_output.put_line ('Owner:' || upper (rec.owner)); + dbms_output.put_line (''); + dbms_output.put_line ('DB Link Usage for Link:' || upper (rec.db_link)); + dbms_output.put_line ('
' + || srec.owner + || ' ' + || srec.type + || ' ' + || srec.name + || ' ' + || srec.line + || ' ' + || substr (srec.text + , 1 + , 80 + ) + ||'
' + || srec.owner + || ' ' + || srec.type + || ' ' + || srec.name + || ' ' + || srec.line + || ' ' + || substr (srec.text + , 1 + , 250 + ) + ||'
'); + dbms_output.put_line ('DB Link Usage for this link:' || to_char(v_count)); + dbms_output.put_line ('
'); + dbms_output.put_line (''); +end; +/ + + + +---set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window +--host &&SPOOL_NAME + diff --git a/lob.sql b/lob.sql new file mode 100644 index 0000000..2b345ba --- /dev/null +++ b/lob.sql @@ -0,0 +1,40 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the lob settings of the tables of the user - parameter - Owner +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt + +column owner format a11 heading "User" +column table_name format a19 heading "Table name" +column column_name format a19 heading "Column|Name" +column segment_name format a25 heading "Segment|Name" +column IN_ROW format a3 heading "In|Row" +column SECUREFILE format a3 heading "Sec|File" +column tablespace_name format a10 heading "Tab|Space" +column mb format 999G999D99 heading "Size|MB" +column PARTITION_NAME format a8 heading "Part|Name" + +select --l.owner + --, + l.table_name + , l.column_name + , l.tablespace_name + , l.segment_name + , substr(s.PARTITION_NAME,1,6)||'..' as PARTITION_NAME + , round(decode(nvl(s.bytes,0),0,0,(s.bytes/1024/1024)),2) as mb + , l.in_row + , l.securefile +from dba_lobs l + , dba_segments s +where l.segment_name = s.segment_name(+) + and upper(l.owner)=upper('&&OWNER.') +order by l.table_name +/ + diff --git a/lob_detail.sql b/lob_detail.sql new file mode 100644 index 0000000..20d81ee --- /dev/null +++ b/lob_detail.sql @@ -0,0 +1,173 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc - Get the details for the lob data type for this table +-- Parameter owner and table name +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TABLE_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Table Name => &&TABLE_NAME. +prompt + + +column owner format a12 heading "User" +column table_name format a30 heading "Table name" +column column_name format a20 heading "Column|Name" +column segment_name format a30 heading "Segment|Name" +column IN_ROW format a3 heading "In|Row" +column SECUREFILE format a3 heading "Sec|File" + +-- +-- to avoid ORA-00600: internal error code, arguments: [qmxtrGetRealOPn], [], [], [], [], [], [], [], [], [], [], [] +-- use this hint! /*+ NO_XML_QUERY_REWRITE */ +-- + +select /*+ NO_XML_QUERY_REWRITE */ * + from xmltable('ROWSET/ROW/*' + passing xmltype( + cursor( + select * from dba_lobs where upper(owner)=upper('&&OWNER.') and upper(table_name)=upper('&&TABLE_NAME.') + ) + ) + columns property varchar2(30) path 'node-name(.)' + , value varchar2(30) path '.' + ) +/ + +set serveroutput on + +declare + + cursor c_lob_info is + select segment_name + , owner + , securefile + , decode(securefile,'YES','SECUREFILE','BASICFILE') as lob_type + from dba_lobs + where upper(owner)=upper('&&OWNER.') + and upper(table_name)=upper('&&TABLE_NAME.'); + + v_segment_size_blocks number; + v_segment_size_bytes number; + v_used_blocks number; + v_used_bytes number; + v_expired_blocks number; + v_expired_bytes number; + v_unexpired_blocks number; + v_unexpired_bytes number; + v_unf number; + v_unfb number; + v_fs1 number; + v_fs1b number; + v_fs2 number; + v_fs2b number; + v_fs3 number; + v_fs3b number; + v_fs4 number; + v_fs4b number; + v_full number; + v_fullb number; + + v_file_name dba_data_files.file_name%type; + v_tablespace_name dba_segments.TABLESPACE_NAME%type; + v_segment_management dba_tablespaces.SEGMENT_SPACE_MANAGEMENT%type; +begin + for rec in c_lob_info + loop + + + dbms_output.put_line('Info -- Segment Name :' || rec.segment_name); + dbms_output.put_line('Info -- LOB File Type :' || rec.lob_type); + + --to fix + -- declare + --* + --ERROR at line 1: + --ORA-03213: Invalid Lob Segment Name for DBMS_SPACE package + --ORA-06512: at "SYS.DBMS_SPACE", line 210 + --ORA-06512: at line 12 + -- use right package for each Lob type! + begin + + if rec.securefile ='YES' then + dbms_space.space_usage( + segment_owner => rec.owner, + segment_name => rec.segment_name, + segment_type => 'LOB', + partition_name => NULL, + segment_size_blocks => v_segment_size_blocks, + segment_size_bytes => v_segment_size_bytes, + used_blocks => v_used_blocks, + used_bytes => v_used_bytes, + expired_blocks => v_expired_blocks, + expired_bytes => v_expired_bytes, + unexpired_blocks => v_unexpired_blocks, + unexpired_bytes => v_unexpired_bytes); + + + dbms_output.put_line('Info -- Secure File in use'); + dbms_output.put_line('Info -- segment_size_blocks :'|| v_segment_size_blocks); + dbms_output.put_line('Info -- segment_size_bytes in MB :'|| to_char(v_segment_size_bytes/(1024*1024),'999G999G999D99')); + dbms_output.put_line('Info -- used_bytes in MB :'|| to_char(v_used_bytes/(1024*1024),'999G999G999D99')); + dbms_output.put_line('Info -- expired_bytes in MB :'|| to_char(v_expired_bytes/(1024*1024),'999G999G999D99')); + dbms_output.put_line('Info -- unexpired_bytes in MB :'|| to_char(v_unexpired_bytes/(1024*1024),'999G999G999D99')); + + else + dbms_space.space_usage( + segment_owner => rec.owner + ,segment_name => rec.segment_name + ,segment_type => 'LOB' + ,unformatted_blocks => v_unf + ,unformatted_bytes => v_unfb + ,fs1_blocks => v_fs1 + ,fs1_bytes => v_fs1b + ,fs2_blocks => v_fs2 + ,fs2_bytes => v_fs2b + ,fs3_blocks => v_fs3 + ,fs3_bytes => v_fs3b + ,fs4_blocks => v_fs4 + ,fs4_bytes => v_fs4b + ,full_blocks => v_full + ,full_bytes => v_fullb + ,partition_name => ''); + + dbms_output.put_line('Info -- Basic File in use'); + dbms_output.put_line('Info -- Total Count of blocks that are unformatted :'||to_char(v_unf,'999G999G999') ||' |Bytes MB:'||to_char(v_unfb/(1024*1024),'999G999G999D99')); + dbms_output.put_line('Info -- Total Count of blocks that are full in the segment :'||to_char(v_full,'999G999G999')||' |Bytes MB:'||to_char(v_fullb/(1024*1024),'999G999G999D99')); + + dbms_output.put_line('Info -- '); + + dbms_output.put_line('Info -- Count of blocks that has at least 0 to 25% free space :'||v_fs1||' |Bytes :'||v_fs1b); + dbms_output.put_line('Info -- Count of blocks that has at least 25 to 50% free space :'||v_fs2||' |Bytes :'||v_fs2b); + dbms_output.put_line('Info -- Count of blocks that has at least 50 to 75% free space :'||v_fs3||' |Bytes :'||v_fs3b); + dbms_output.put_line('Info -- Count of blocks that has at least 75 to 100% free space :'||v_fs4||' |Bytes :'||v_fs4b); + + dbms_output.put_line('Info ------------------------------------------------------------------'); + + end if; + + exception + when others then + dbms_output.put_line('Error --'); + dbms_output.put_line('Error -- '||SQLERRM); + dbms_output.put_line('Error -- +This procedure can be used only on segments in tablespaces with AUTO SEGMENT SPACE MANAGEMENT'); + dbms_output.put_line('Error -- +Action: Check the segment name and type and reissue the statement'); + select distinct s.TABLESPACE_NAME , t.SEGMENT_SPACE_MANAGEMENT into v_tablespace_name , v_segment_management + from dba_segments s , dba_tablespaces t + where upper(s.segment_name) like upper('&&TABLE_NAME.') + and upper(s.owner)=upper('&&OWNER.') + and s.TABLESPACE_NAME=t.TABLESPACE_NAME; + + dbms_output.put_line('Error -- +Tablespace for the table &&TABLE_NAME.:: '||v_tablespace_name ||' - Segment Management for this tablespace:: '||v_segment_management); + dbms_output.put_line('Error --'); + end; + end loop; + +end; +/ + diff --git a/locks.sql b/locks.sql new file mode 100644 index 0000000..744884c --- /dev/null +++ b/locks.sql @@ -0,0 +1,97 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script Locks overview +-- Date: 2012 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 +set echo off + +ttitle left "Lock Overview in the database" skip 2 + +column obj_name format a16 heading "Locked|Object" + +column orauser format a14 heading "Oracle|Username" +column os_user_name format a14 heading "O/S|Username" + +column ss format a12 heading "SID:Ser#" +column time format a16 heading "Logon|Date/Time" +column procid format a10 heading "Process|ID" +column machine format a15 heading "PC Name|User" +column logMod format 9 heading "=> 6|blocker!" + + +select owner || '.' || object_name as obj_name + , oracle_username || ' (' || s.status || ')' as orauser + , os_user_name + , machine + , l.process as procid + , lc.inst_id + , s.sid || ',' || s.serial# as ss + , to_char (s.logon_time, 'dd.mm.yyyy hh24:mi') time + --,l.LOCKED_MODE as logMod + , lc.lmode logMod + from gv$locked_object l + , dba_objects o + , gv$session s + , gv$transaction t + , gv$lock lc + where l.object_id = o.object_id + and s.sid = l.session_id + and s.inst_id = l.inst_id + and s.taddr = t.addr(+) + and s.inst_id = t.inst_id(+) + and s.sid = lc.sid + and lc.type = 'TX' + and s.inst_id = lc.inst_id +order by oracle_username + , ss + , obj_name + , s.logon_time +/ + +ttitle off + +/* Query OMS Metrik +with blocked_resources + as ( select id1 + , id2 + , sum (ctime) as blocked_secs + , max (request) as max_request + , count (1) as blocked_count + from v$lock + where request > 0 + group by id1, id2) + , blockers + as (select l.*, br.blocked_secs, br.blocked_count + from v$lock l, blocked_resources br + where br.id1 = l.id1 + and br.id2 = l.id2 + and l.lmode > 0 + and l.block <> 0) +select b.id1 || '_' || b.id2 || '_' || s.sid || '_' || s.serial# as id + , 'SID,SERIAL:' + || s.sid + || ',' + || s.serial# + || ',LOCK_TYPE:' + || b.type + || ',PROGRAM:' + || s.program + || ',MODULE:' + || s.module + || ',ACTION:' + || s.action + || ',MACHINE:' + || s.machine + || ',OSUSER:' + || s.osuser + || ',USERNAME:' + || s.username + as info + , b.blocked_secs + , b.blocked_count + from v$session s, blockers b + where b.sid = s.sid +*/ diff --git a/login.sql b/login.sql new file mode 100644 index 0000000..27a136c --- /dev/null +++ b/login.sql @@ -0,0 +1,170 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: set the sqlplus prompt +-- try to find out the os of sqlplus and set the title bar of the sql*Plus window if windows +-- +-- +--============================================================================== +set termout off + +-- get the host name + +col x new_value y +define y=? +-- use only the first part of the host name to avoid error with value to long + +select decode (substr (sys_context ('USERENV', 'SERVER_HOST') + , 1 + , instr (sys_context ('USERENV', 'SERVER_HOST'), '.') + - 1) + , '', sys_context ('USERENV', 'SERVER_HOST') + , substr (sys_context ('USERENV', 'SERVER_HOST') + , 1 + , instr (sys_context ('USERENV', 'SERVER_HOST'), '.') + - 1)) + x + from dual +/ + +-- get the data for the window title + +col u new_value z +define z=? + +select sys_context ('USERENV', 'INSTANCE_NAME') + || ' ++ Service :: ' + || sys_context ('USERENV', 'SERVICE_NAME') + || ' ++ User :: ' + || user + u + from dual +/ + +-- the the operation System to set the title bar of the sqlplus window +-- the problem is the the detection of the operation system of sqlplus +-- to call the right os command to set the title window + +-- try to the the os from a return code +-- not working, error out is bad.... +-- if command uptime exits we guess linux +-- +-- WHENEVER OSERROR continue +-- +-- --host set +-- var HR varchar2(5) +-- +-- set verify off +-- get the return code from host +-- begin +-- :HR := '&_RC'; +-- end; +-- / +-- set verify on + +-------- + +var OS varchar2(5) + +declare + v_oracle_home varchar2 (512); + v_module varchar2 (512); + v_os_user varchar2 (512); + v_host varchar2 (512); +begin + :OS := 'XX'; + + -- try to get the OS from the Oracle Home Path + -- only possible if you have DBA rights + if (sys_context ('USERENV', 'ISDBA') != 'FALSE') + then + -- dbms_system is only valid if you are dba + -- must be called there for dynamic! + -- but this is not the client environment ... + -- execute immediate 'begin dbms_system.get_env(''ORACLE_HOME'',:1); end;' using out v_oracle_home; + -- if instr(v_oracle_home,'/') > 0 then + -- + + -- if you are dba you will see sqlplus.exe + -- use the .exe to detect windows + + v_module := sys_context ('USERENV', 'MODULE'); + + if instr (v_module, '.exe') > 0 + then + :OS := 'WIN'; + else + :OS := 'LINUX'; + end if; + else + -- try to check if sqlplus was started from a windows environment + -- the windows login name is host\user + -- try to detect the \ + + v_os_user := sys_context ('USERENV', 'OS_USER'); + v_host := sys_context ('USERENV', 'HOST'); + + if instr (v_os_user, '\') > 0 + then + -- ' needed for syntax highlightning of my editor ... + :OS := 'WIN'; + else + -- check again the with the host + if instr (v_host, '\') > 0 + then + -- ' needed for syntax highlightning of my editor ... + :OS := 'WIN'; + else + :OS := 'LINUX'; + end if; + end if; + end if; +end; +/ + +--- define this variable to avoid error with nolog logins +define SCRIPTPART_CALL='set_no_titel.sql' + +col SCRIPTPART_COL new_val SCRIPTPART_CALL + +select decode (:OS, 'LINUX', 'set_linux_title.sql', 'set_windows_title.sql') as SCRIPTPART_COL from dual +/ + +undefine OS + +-- call the os script for the title setting +-- +@@&&SCRIPTPART_CALL "&z" "&y" + +set sqlprompt "_USER'@'_CONNECT_IDENTIFIER-&y>" + + +-- set the session information + +begin + dbms_application_info.set_module ('DBA Connection', 'DBA'); + dbms_application_info.set_client_info ('DBA'); + dbms_session.set_identifier ('DBA'); +end; +/ + +--- global Settings +set trimspool on +set serveroutput on +set pagesize 300 +set linesize 130 +set +-- suppress scientific notation +set numwidth 12 +-- +-- set your personal prefer time format +alter session set nls_date_format='dd.mm.rr hh24:mi'; +-- +-- + +-- +set verify off +column SQLPLUS_VERSION format a20 +select decode(substr('&&_SQLPLUS_RELEASE',0,1), '0','SQLCL','SQLPLUS') as SQLPLUS_VERSION from dual; +set verify on + +set termout on diff --git a/ls.sql b/ls.sql new file mode 100644 index 0000000..c14c0ed --- /dev/null +++ b/ls.sql @@ -0,0 +1,58 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: List tables +-- Date: 01.September 2013 +-- +--============================================================================== +set verify off + +set linesize 130 pagesize 300 + +ttitle left "List of Tables" skip 2 + + +column table_name format a30 heading "Table|name" +column num_rows format 999G999G999 heading "Num|rows" +column size_MB format 999G990D000 heading "Size|MB" +column table_size format 999G990D000 heading "Size Table|MB" +column index_size format 999G990D000 heading "Size Index|MB" + + select t.table_name + , t.num_rows + , round(s.bytes/1024/1024,3) as size_MB + from user_tables t + , user_segments s + where t.table_name = s.segment_name(+) +order by t.table_name +/ +prompt +prompt ... num rows are from the db table statistic! +prompt + +ttitle left "Space usage of all tables and indexes" + +select round(table_size/1024/1024,3) as table_size + , round(index_size/1024/1024,3) as index_size +from ( + select sum(decode(s.segment_type,'TABLE',s.bytes,0)) as table_size + , sum(decode(s.segment_type,'INDEX',s.bytes,0)) as index_size + from user_segments s + where s.segment_name not in ( select object_name from recyclebin ) +) +/ + +ttitle left "Space usage of the recycle user bin" +select round(table_size/1024/1024,3) as table_size + , round(index_size/1024/1024,3) as index_size +from ( + select sum(decode(s.segment_type,'TABLE',s.bytes,0)) as table_size + , sum(decode(s.segment_type,'INDEX',s.bytes,0)) as index_size + from user_segments s + where s.segment_name in ( select object_name from recyclebin ) +) +/ +prompt +prompt ... to clean the recycle Bin : purge recyclebin; +prompt + +ttitle off \ No newline at end of file diff --git a/monitoring/session_count_mon.sql b/monitoring/session_count_mon.sql new file mode 100644 index 0000000..d605e1e --- /dev/null +++ b/monitoring/session_count_mon.sql @@ -0,0 +1,9 @@ +select + sum(decode(s.type,'BACKGROUND',1,0)) BackgroundSessions +, sum(case when s.type='USER' then decode(status,'ACTIVE',0,1) else 0 end) UserSessions +, sum(case when s.type='USER' then decode(status,'ACTIVE',1,0) else 0 end) ActiveSessions +, count(*) as TotalProcessCount + from v$session s , + v$process p +where s.PADDR (+) = p.ADDR +and nvl(s.sid,-1) <> sys_context('userenv','SID') ; diff --git a/my_acl.sql b/my_acl.sql new file mode 100644 index 0000000..ec27f7f --- /dev/null +++ b/my_acl.sql @@ -0,0 +1,31 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show my rights +--============================================================================== +--http://docs.oracle.com/cd/B28359_01/appdev.111/b28419/d_networkacl_adm.htm#CHDJFJFF +--http://www.oracle.com/webfolder/technetwork/de/community/dbadmin/tipps/acl/index.html +--http://www.oracleflash.com/36/Oracle-11g-Access-Control-List-for-External-Network-Services.html +--http://www.oracle-base.com/articles/11g/fine-grained-access-to-network-services-11gr1.php +--============================================================================== +set linesize 130 pagesize 300 + +column acl format a40 heading "ACL" +column host format a16 +column principal format a16 +column privilege format a10 +column is_grant format a8 +column lower_port format a12 heading "Lower Port" +column upper_port format a12 heading "Upper Port" + +set lines 1000 + +SELECT host + , to_char(lower_port) lower_port + , to_char(upper_port) upper_port + , privilege + , status +FROM user_network_acl_privileges +/ + +prompt ... to check if your pattern match use this function +prompt ... select * from table(dbms_network_acl_utility.domains('')); \ No newline at end of file diff --git a/my_directory.sql b/my_directory.sql new file mode 100644 index 0000000..e654b13 --- /dev/null +++ b/my_directory.sql @@ -0,0 +1,47 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show informations about directories in the database +-- Date: 08.08.2013 +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Directories in the database" SKIP 1 + +column owner format a15 +column directory_name format a25 +column directory_path format a60 +column grantee format a25 +column grantor format a18 +column privilege format a10 +column privilege_list format a30 + +select owner + , directory_name + , directory_path + from all_directories + order by 1 + ,2 +/ + +ttitle "Grants to this directories" SKIP 1 + +select t.table_name as directory_name + , t.grantor + , t.grantee + , listagg(t.privilege,':') WITHIN GROUP (ORDER BY t.privilege ) AS privilege_list + from all_tab_privs t + , all_directories d + where t.table_name= d.directory_name + group by t.table_name + , t.grantor + , t.grantee +order by t.table_name + , t.grantee +/ + +ttitle off + +prompt ... +prompt To grant use : grant read,write on directory xxxx to yyyyyy; +prompt ... + diff --git a/my_opt_settings.sql b/my_opt_settings.sql new file mode 100644 index 0000000..c93f97d --- /dev/null +++ b/my_opt_settings.sql @@ -0,0 +1,25 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the my optimizer settings +-- +--============================================================================== +set linesize 130 pagesize 300 + +column name format a40 heading "OptFeature|Name" +column sql_feature format a20 heading "SQL|Feature" +column isdefault format a4 heading "DEF|AULT" +column value format a20 heading "Value" +column sid format 9999 heading "My|SID" + +select o.name + , o.sql_feature + , o.isdefault + , o.value + from gv$ses_optimizer_env o + , gv$session s +where s.sid = o.sid + and s.inst_id=o.inst_id + and s.username= user + and s.sid=sys_context('userenv','SID') +order by o.name +/ diff --git a/my_plsql.sql b/my_plsql.sql new file mode 100644 index 0000000..0cf8539 --- /dev/null +++ b/my_plsql.sql @@ -0,0 +1,30 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the local objects +-- Must be run with user privileges +-- +--============================================================================== + + +set verify off +set linesize 130 pagesize 300 + +define OBJ_NAME = '&1' + +prompt +prompt Parameter 1 = OBJ Name => &&OBJ_NAME. +prompt + +column object_name format a30 +column object_type format a16 +column last_ddl_time format a18 + +select object_name + , object_type + , to_char(last_ddl_time ,'dd.mm.yyyy hh24:mi') as last_ddl_time +from user_objects +where OBJECT_NAME like upper('%&OBJ_NAME.%') + and object_type not in ('INDEX','LOB','TABLE','VIEW','SEQUENCE') +order by object_type + ,object_name +/ \ No newline at end of file diff --git a/my_proxy.sql b/my_proxy.sql new file mode 100644 index 0000000..e8336d5 --- /dev/null +++ b/my_proxy.sql @@ -0,0 +1,47 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the users of the database +-- Date: November 2017 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + + +column CURRENT_USER format a14 heading "CURRENT|USER" +column CURRENT_USERID format a14 heading "CURRENT|USERID" +column PROXY_USER format a14 heading "PROXY|USER" +column PROXY_USERID format a14 heading "PROXY|USERID" +column AUTH_IDENT format a20 heading "AUTH|IDENT" + +ttitle left "My akct Identity" skip 2 + +SELECT SYS_CONTEXT ('USERENV', 'CURRENT_USER') CURRENT_USER + , SYS_CONTEXT ('USERENV', 'CURRENT_USERID') CURRENT_USERID + , SYS_CONTEXT ('USERENV', 'PROXY_USER') PROXY_USER + , SYS_CONTEXT ('USERENV', 'PROXY_USERID') PROXY_USERID + , SYS_CONTEXT ('USERENV', 'AUTHENTICATED_IDENTITY') AUTH_IDENT +FROM DUAL +/ + +ttitle left "To which users I can proxy" skip 2 + + +column proxy format a15 heading "Proxy" +column client format a15 heading "Client|User" +column authentication format a5 heading "Auth" +column authorization_constraint format a40 heading "Auth|Const" +column role format a15 heading "Role" + +select CLIENT + , AUTHENTICATION + , AUTHORIZATION_CONSTRAINT + , ROLE + from USER_PROXIES +order by 1 +/ + + + +ttitle off + diff --git a/my_refresh_group.sql b/my_refresh_group.sql new file mode 100644 index 0000000..ed7157f --- /dev/null +++ b/my_refresh_group.sql @@ -0,0 +1,22 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Get all refresh groups of your Schema +--============================================================================== +set linesize 130 pagesize 300 + +column owner format a20 +column mview_name format a25 +column last_refresh_date format a18 +column rname format a20 +column next_date format a18 + +select mv.owner + , mv.mview_name + , to_char(mv.last_refresh_date,'dd.mm.yyyy hh24:mi') as last_refresh_date + , rc.rname + , to_char(rc.next_date,'dd.mm.yyyy hh24:mi') as next_date +from user_mviews mv + , user_refresh_children rc +where mv.owner = rc.owner (+) + and mv.mview_name = rc.name (+) +/ \ No newline at end of file diff --git a/my_session.sql b/my_session.sql new file mode 100644 index 0000000..ab44756 --- /dev/null +++ b/my_session.sql @@ -0,0 +1,207 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- +-- Desc: get Information about my session +-- +--============================================================================== + +set verify off + +set linesize 130 pagesize 300 + +ttitle left "My Oracle session and the process to this session" skip 2 + +column process_id format a8 heading "Process|ID" +column inst_id format 99 heading "Inst|ID" +column username format a8 heading "DB User|name" +column osusername format a8 heading "OS User|DB Process" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column machine format a14 heading "Remote|pc/server" +column terminal format a14 heading "Remote|terminal" +column program format a17 heading "Remote|program" +column module format a15 heading "Remote|module" +column client_info format a15 heading "Client|info" +column pname format a8 heading "Process|name" +column tracefile format a20 heading "Trace|File" + + select p.inst_id + , vs.sid + , vs.serial# + , nvl (vs.username, 'n/a') as username + , p.username as osusername + , p.pname + , to_char (p.spid) as process_id + , vs.machine + --, p.terminal + , vs.module + , vs.program + , vs.client_info + --, substr(p.tracefile,length(p.tracefile)-REGEXP_INSTR(reverse(p.tracefile),'[\/|\]')+2,1000) as tracefile + --, p.tracefile + from gv$session vs, gv$process p + where vs.paddr = p.addr + and vs.inst_id = p.inst_id + and vs.sid = sys_context ('userenv', 'SID') + and vs.inst_id = sys_context ('userenv', 'INSTANCE') +order by vs.username, p.inst_id, p.spid +/ + +ttitle left "My SID and my Serial over dbms_debug_jdwp" skip 2 + +SELECT dbms_debug_jdwp.current_session_id sid + , dbms_debug_jdwp.current_session_serial serial +FROM dual +/ + +ttitle left "Trace File Locations" skip 2 + +column full_trace_file_loc format a70 heading "Trace|File" + +select value as full_trace_file_loc + from v$diag_info + where name = 'Default Trace File' +/ + +--select p.inst_id +-- , to_char(p.spid) as process_id +-- , p.tracefile as full_trace_file_loc +--from gv$session vs +-- , gv$process p +--where vs.paddr=p.addr +-- and vs.inst_id=p.inst_id +-- and vs.sid=sys_context('userenv','SID') +-- and vs.inst_id=sys_context('userenv','INSTANCE') +--order by vs.username +-- , p.inst_id +--/ + +ttitle left "Check if this Session is connected via TCP with SSL TCPS or TCP" skip 2 + + +SELECT SYS_CONTEXT('USERENV','NETWORK_PROTOCOL') AS connect_protocol + FROM dual +/ + + +ttitle left "TAF Setting" skip 2 +column inst_id format 99 heading "Inst|ID" +column username format a14 heading "DB User|name" +column machine format a36 heading "Remote|pc/server" +column failover_type format a6 heading "Fail|type" +column failover_method format a6 heading "Fail|method" +column failed_over format a6 heading "Fail|over" + +select inst_id + , machine + , username + , failover_type + , failover_method + , failed_over + from gv$session + where sid = sys_context ('userenv', 'SID') + and inst_id = sys_context ('userenv', 'INSTANCE') +/ + + +ttitle left "Session NLS Lang Values" skip 2 + +select sys_context ('USERENV', 'LANGUAGE') as NLS_LANG_Parameter from dual; + + +ttitle left "Session NLS Values" skip 2 + +column parameter format a24 heading "NLS Session Parameter" +column value format a30 heading "Setting" + +select PARAMETER, value + from nls_session_parameters +order by 1 +/ + +--------------- +--- Source https://stackoverflow.com/questions/8114453/read-all-parameters-from-sys-context-userenv +-- thanks to beloblotskiy +--------------- +column NAME format a30 heading "Sys Context|Parameter" +column VAL format a50 heading "Sys Context|Value" + +ttitle left "Session sys_context Values" skip 2 + + +select context_values.* + from ( + select * + from ( + select + sys_context ('userenv','ACTION') ACTION, + sys_context ('userenv','AUDITED_CURSORID') AUDITED_CURSORID, + sys_context ('userenv','AUTHENTICATED_IDENTITY') AUTHENTICATED_IDENTITY, + sys_context ('userenv','AUTHENTICATION_DATA') AUTHENTICATION_DATA, + sys_context ('userenv','AUTHENTICATION_METHOD') AUTHENTICATION_METHOD, + sys_context ('userenv','BG_JOB_ID') BG_JOB_ID, + sys_context ('userenv','CLIENT_IDENTIFIER') CLIENT_IDENTIFIER, + sys_context ('userenv','CLIENT_INFO') CLIENT_INFO, + sys_context ('userenv','CURRENT_BIND') CURRENT_BIND, + sys_context ('userenv','CURRENT_EDITION_ID') CURRENT_EDITION_ID, + sys_context ('userenv','CURRENT_EDITION_NAME') CURRENT_EDITION_NAME, + sys_context ('userenv','CURRENT_SCHEMA') CURRENT_SCHEMA, + sys_context ('userenv','CURRENT_SCHEMAID') CURRENT_SCHEMAID, + sys_context ('userenv','CURRENT_SQL') CURRENT_SQL, + sys_context ('userenv','CURRENT_SQLn') CURRENT_SQLn, + sys_context ('userenv','CURRENT_SQL_LENGTH') CURRENT_SQL_LENGTH, + sys_context ('userenv','CURRENT_USER') CURRENT_USER, + sys_context ('userenv','CURRENT_USERID') CURRENT_USERID, + sys_context ('userenv','DATABASE_ROLE') DATABASE_ROLE, + sys_context ('userenv','DB_DOMAIN') DB_DOMAIN, + sys_context ('userenv','DB_NAME') DB_NAME, + sys_context ('userenv','DB_UNIQUE_NAME') DB_UNIQUE_NAME, + sys_context ('userenv','DBLINK_INFO') DBLINK_INFO, + sys_context ('userenv','ENTRYID') ENTRYID, + sys_context ('userenv','ENTERPRISE_IDENTITY') ENTERPRISE_IDENTITY, + sys_context ('userenv','FG_JOB_ID') FG_JOB_ID, + sys_context ('userenv','GLOBAL_CONTEXT_MEMORY') GLOBAL_CONTEXT_MEMORY, + sys_context ('userenv','GLOBAL_UID') GLOBAL_UID, + sys_context ('userenv','HOST') HOST, + sys_context ('userenv','IDENTIFICATION_TYPE') IDENTIFICATION_TYPE, + sys_context ('userenv','INSTANCE') INSTANCE, + sys_context ('userenv','INSTANCE_NAME') INSTANCE_NAME, + sys_context ('userenv','IP_ADDRESS') IP_ADDRESS, + sys_context ('userenv','ISDBA') ISDBA, + sys_context ('userenv','LANG') LANG, + sys_context ('userenv','LANGUAGE') LANGUAGE, + sys_context ('userenv','MODULE') MODULE, + sys_context ('userenv','NETWORK_PROTOCOL') NETWORK_PROTOCOL, + sys_context ('userenv','NLS_CALENDAR') NLS_CALENDAR, + sys_context ('userenv','NLS_CURRENCY') NLS_CURRENCY, + sys_context ('userenv','NLS_DATE_FORMAT') NLS_DATE_FORMAT, + sys_context ('userenv','NLS_DATE_LANGUAGE') NLS_DATE_LANGUAGE, + sys_context ('userenv','NLS_SORT') NLS_SORT, + sys_context ('userenv','NLS_TERRITORY') NLS_TERRITORY, + sys_context ('userenv','OS_USER') OS_USER, + sys_context ('userenv','POLICY_INVOKER') POLICY_INVOKER, + sys_context ('userenv','PROXY_ENTERPRISE_IDENTITY') PROXY_ENTERPRISE_IDENTITY, + sys_context ('userenv','PROXY_USER') PROXY_USER, + sys_context ('userenv','PROXY_USERID') PROXY_USERID, + sys_context ('userenv','SERVER_HOST') SERVER_HOST, + sys_context ('userenv','SERVICE_NAME') SERVICE_NAME, + sys_context ('userenv','SESSION_EDITION_ID') SESSION_EDITION_ID, + sys_context ('userenv','SESSION_EDITION_NAME') SESSION_EDITION_NAME, + sys_context ('userenv','SESSION_USER') SESSION_USER, + sys_context ('userenv','SESSION_USERID') SESSION_USERID, + sys_context ('userenv','SESSIONID') SESSIONID, + sys_context ('userenv','SID') SID, + sys_context ('userenv','STATEMENTID') STATEMENTID, + sys_context ('userenv','TERMINAL') TERMINAL + from dual + ) + unpivot include nulls ( + val for name in (action, audited_cursorid, authenticated_identity, authentication_data, authentication_method, bg_job_id, client_identifier, client_info, current_bind, current_edition_id, current_edition_name, current_schema, current_schemaid, current_sql, current_sqln, current_sql_length, current_user, current_userid, database_role, db_domain, db_name, db_unique_name, dblink_info, entryid, enterprise_identity, fg_job_id, global_context_memory, global_uid, host, identification_type, instance, instance_name, ip_address, isdba, lang, language, module, network_protocol, nls_calendar, nls_currency, nls_date_format, nls_date_language, nls_sort, nls_territory, os_user, policy_invoker, proxy_enterprise_identity, proxy_user, proxy_userid, server_host, service_name, session_edition_id, session_edition_name, session_user, session_userid, sessionid, sid, statementid, terminal) + ) + ) context_values +/ + + + + +ttitle off \ No newline at end of file diff --git a/my_tab_rights.sql b/my_tab_rights.sql new file mode 100644 index 0000000..8277342 --- /dev/null +++ b/my_tab_rights.sql @@ -0,0 +1,24 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- +-- get my table rights on this database +-- +--============================================================================== +set linesize 130 pagesize 300 + +column table_schema format a20 +column table_name format a30 +column privilege format a15 + + +prompt ... will show you all table privileges on the database. + +select table_schema + , table_name + , privilege +from all_tab_privs +where grantee=user +order by 1,2,3 +/ + +prompt diff --git a/my_user.sql b/my_user.sql new file mode 100644 index 0000000..e1bf383 --- /dev/null +++ b/my_user.sql @@ -0,0 +1,40 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get my user connection +--============================================================================== +set linesize 130 pagesize 300 + +column MY_USER_AND_SERVICE format a100 heading "My Connection is" + +select 'Instance :: '||SYS_CONTEXT('USERENV', 'INSTANCE_NAME')||' ++ Service :: '||SYS_CONTEXT('USERENV', 'SERVICE_NAME') || ' ++ User :: '||user ||' ++ SID :: '||sys_context('userenv','SID')||' + Inst ID :: '||sys_context('userenv','INSTANCE') as MY_USER_AND_SERVICE + from dual +/ + +select dbms_debug_jdwp.current_session_id sid + , dbms_debug_jdwp.current_session_serial serial +from dual +/ + +prompt + + +prompt ... will show you are privileges on the database. + +select * from session_privs +/ + +select * from session_roles +/ + + +prompt INHERIT PRIVILEGES for this user + + + +select grantee + , table_name + , privilege + from user_tab_privs + where privilege = 'INHERIT PRIVILEGES' + / + diff --git a/nls.sql b/nls.sql new file mode 100644 index 0000000..167f86b --- /dev/null +++ b/nls.sql @@ -0,0 +1,62 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: nls settings of the Session and the database +-- Date: September 2012 +-- +--============================================================================== +set linesize 130 pagesize 300 + +ttitle left "Session NLS Lang Values" skip 2 + +select sys_context ('USERENV', 'LANGUAGE') as NLS_LANG_Parameter from dual; + +ttitle left "Session NLS Values" skip 2 + +column parameter format a24 heading "NLS Session Parameter" +column value format a30 heading "Setting" + +select PARAMETER, value + from nls_session_parameters +order by 1 +/ + +ttitle left "Database Time Zone" skip 2 + +select dbtimezone from dual +/ + +ttitle left "Session Time Zone" skip 2 + +select sessiontimezone from dual +/ + +ttitle left "Session Time Values" skip 2 + +select to_char (sysdate, 'dd.mm.yyyy hh24:mi') as "DB Time" + , to_char (current_date, 'dd.mm.yyyy hh24:mi') as "Client Time" + , sysdate + - current_date + as "Time gab between client and db" + from dual +/ + + +ttitle left "Char set of the database" skip 2 +column parameter format a24 heading "NLS DB Character Set" + +select PARAMETER, value + from nls_database_parameters + where parameter in ('NLS_CHARACTERSET', 'NLS_NCHAR_CHARACTERSET', 'NLS_LENGTH_SEMANTICS','NLS_LANGUAGE','NLS_TERRITORY') +order by 2 +/ + +ttitle left "NLS_LENGTH_SEMANTICS of the database" skip 2 + +show parameter NLS_LENGTH_SEMANTICS + +prompt +prompt ... if NLS_LENGTH_SEMANTICS is byte new varchar2 columns will be defaulted to varchar2( xx byte) +prompt + + +ttitle off \ No newline at end of file diff --git a/obj_dep.sql b/obj_dep.sql new file mode 100644 index 0000000..858ffd8 --- /dev/null +++ b/obj_dep.sql @@ -0,0 +1,43 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the dependencies of a object in the database - parameter - Owner, object name +-- Date: 08.2013 +--============================================================================== +-- http://www.dba-oracle.com/t_tracking_table_constraint_dependencies.htm +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TAB_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&TAB_NAME. +prompt + +ttitle left "Dependency Usage of the table &OWNER..&TAB_NAME." skip 2 + +column clevel heading "Object|level" format a16 +column obj_name heading "Object|name" format a40 +column type heading "Object|type" format a8 +column referenced_type like type +column ref_obj heading "Ref|object" format a40 + +select lpad(' ', 2 * (level - 1)) || to_char(level, '999') as clevel + , type + , owner || '.' || name as obj_name + , referenced_owner || '.' || referenced_name as ref_obj + , referenced_type + from all_dependencies + start with owner = upper('&OWNER') + and name = upper('&TAB_NAME') +connect by prior referenced_owner = owner + and prior referenced_name = name + and prior referenced_type = type +/ + +prompt +prompt ... alternativ use the utldtree utility $ORACLE_HOME/rdbms/admin/utldtree.sql +prompt ... to create the helper function and call => deptree_fill('object_type', 'object_owner', 'object_name'); | select * from ideptree; +prompt diff --git a/obj_deps_report.sql b/obj_deps_report.sql new file mode 100644 index 0000000..9d67c5c --- /dev/null +++ b/obj_deps_report.sql @@ -0,0 +1,77 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: HTML Report for the dependencies in the database +-- Date: September 2015 +-- +--============================================================================== + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_dependencies.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + +set verify off +SET linesize 250 pagesize 2000 + +spool &&SPOOL_NAME + + +set markup html on + +ttitle left "Schema Referenzes over grants " skip 2 + + +select grantee ,'=',PRIVILEGE,'>' ,owner ,count(*) as cnt + from DBA_TAB_PRIVS + where GRANTOR not in ('SYS','MDSYS','SI_INFORMTN_SCHEMA','ORDPLUGINS','ORDDATA','ORDSYS','EXFSYS','XS$NULL','XDB','CTXSYS','WMSYS','APPQOSSYS','DBSNMP','ORACLE_OCM','DIP','OUTLN','SYSTEM','FLOWS_FILES','SYSMAN','OLAPSYS','OWBSYS','OWBSYS_AUDIT') + and table_name not like 'BIN$%' + and PRIVILEGE in ('UPDATE','INSERT') + group by owner ,'=>',PRIVILEGE,'>', grantee +order by grantee,PRIVILEGE +/ + + +ttitle left "Schema Referenzes over Object Rights - insert or update" skip 2 + +select dep.owner ,' => Use Object from' + , dep.referenced_owner as Referenz + , count(*) as total_obj_cnt + , sum(decode(dep.referenced_type,'INDEX',1,0)) as idx_cnt + , sum(decode(dep.referenced_type,'TABLE',1,0)) as tab_cnt + , sum(decode(dep.referenced_type,'VIEW',1,0)) as view_cnt + , sum(decode(dep.referenced_type,'PACKAGE BODY',1,decode(dep.referenced_type,'PACKAGE',1,0))) as package_cnt + from dba_dependencies dep + where dep.owner not in ('SYS','MDSYS','SI_INFORMTN_SCHEMA','ORDPLUGINS','ORDDATA','ORDSYS','EXFSYS','XS$NULL','XDB','CTXSYS','WMSYS','APPQOSSYS','DBSNMP','ORACLE_OCM','DIP','OUTLN','SYSTEM','FLOWS_FILES','SYSMAN','OLAPSYS','OWBSYS','OWBSYS_AUDIT') + and dep.referenced_owner != 'PUBLIC' + and dep.referenced_owner != dep.owner +group by dep.owner ,'=>', dep.referenced_owner +order by 1 +/ + + +ttitle left "Schema Referenzes over Object Rights - select " skip 2 + +select grantee ,'=',PRIVILEGE,'>' ,owner ,count(*) as cnt + from DBA_TAB_PRIVS + where GRANTOR not in ('SYS','MDSYS','SI_INFORMTN_SCHEMA','ORDPLUGINS','ORDDATA','ORDSYS','EXFSYS','XS$NULL','XDB','CTXSYS','WMSYS','APPQOSSYS','DBSNMP','ORACLE_OCM','DIP','OUTLN','SYSTEM','FLOWS_FILES','SYSMAN','OLAPSYS','OWBSYS','OWBSYS_AUDIT') + and table_name not like 'BIN$%' + and PRIVILEGE in ('SELECT') + group by owner ,'=>',PRIVILEGE,'>', grantee +order by grantee,PRIVILEGE +/ + + +set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window +host &&SPOOL_NAME + + + diff --git a/obj_grants.sql b/obj_grants.sql new file mode 100644 index 0000000..64e2bc1 --- /dev/null +++ b/obj_grants.sql @@ -0,0 +1,42 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: grants to an object in the database +--============================================================================== +--desc DBA_ROLE_PRIVS +--desc DBA_SYS_PRIVS +--desc DBA_TAB_PRIVS +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TAB_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&TAB_NAME. +prompt + +ttitle left "Grants of the object &OWNER..&TAB_NAME." skip 2 + +column GRANTEE format a20 +column OWNER format a20 +column TABLE_NAME format a20 +column GRANTOR format a20 +column PRIVILEGE format a20 + +select OWNER + , TABLE_NAME + , GRANTOR + , GRANTEE + , PRIVILEGE + -- , GRANTABLE + -- , HIERARCHY + from dba_tab_privs + where owner = upper ('&OWNER') + and table_name = upper ('&TAB_NAME') +/ + +ttitle off + + diff --git a/obj_last_ddl.sql b/obj_last_ddl.sql new file mode 100644 index 0000000..51e6bb7 --- /dev/null +++ b/obj_last_ddl.sql @@ -0,0 +1,36 @@ +-- ============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the last DDL Changes from a user +-- ============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define OBJECT_TYPE = '%' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Object Type => &&OBJECT_TYPE. +prompt + +column OBJECT_NAME format a30 +column OBJECT_TYPE format a16 +column CREATED format a18 +column LAST_DDL_TIME format a18 + +ttitle "show the last 30 DDL's on this Schema" skip 2 + +select * from ( + select o.OBJECT_NAME + ,o.OBJECT_TYPE + ,o.CREATED + ,o.LAST_DDL_TIME + from dba_objects o + where o.owner like upper( '&&OWNER.' ) + and object_type like upper('&&OBJECT_TYPE.') + order by 4 desc +) +where rownum < 100 +/ + +ttitle off diff --git a/oem/check_agent.sql b/oem/check_agent.sql new file mode 100644 index 0000000..c9e539e --- /dev/null +++ b/oem/check_agent.sql @@ -0,0 +1,103 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: check the Agent Settings on DB side +--============================================================================== +-- docu +-- Database metrics, e.g.Tablespace Full(%), not clearing in Grid Control even though they are no longer present in dba_outstanding_alerts (Doc ID 455222.1) +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +set serveroutput on size 1000000 + +ttitle left "Check the rights to AQ for the OEM_MONITOR Role " skip 2 + +select GRANTOR + , grantee + , PRIVILEGE + , table_name + from DBA_TAB_PRIVS + where grantee like upper ('OEM_MONITOR') + and GRANTOR = 'SYS' + and table_name like '%Q%' +order by table_name +/ + +prompt ... +prompt ... check for ALERT_QUE , DBMS_AQ , DBMS_AQADM +prompt ... if not grant the rights to the OEM_MONITOR Role +prompt ... +prompt + +ttitle left "Check the rights to this Role " skip 2 + +select grantee, default_role + from dba_role_privs + where granted_role = 'OEM_MONITOR' +/ + +prompt + + +ttitle left "Check the registered Agents to this database " skip 2 + +column AGENT_NAME format a40 +column PROTOCOL format 999 +column SPARE1 format a40 + + select AGENT_NAME, PROTOCOL, nvl (SPARE1, 'null') as SPARE1 + from system.AQ$_INTERNET_AGENTS +order by 1 +/ + +prompt ... +prompt ... check for agents with old severnames or old instance names +prompt ... +prompt + +ttitle left "Check the Subscriber to the SYS.ALERT_QUE" skip 2 + +-- Auflisten der Subscriber für die Queues +-- + +declare + subs dbms_aqadm.aq$_subscriber_list_t; + nsubs binary_integer; + i binary_integer; +begin + subs := dbms_aqadm.queue_subscribers (queue_name => 'SYS.ALERT_QUE'); + nsubs := subs.count; + dbms_output.put_line ('Subscriber to the SYS.ALERT_QUE Queue:'); + dbms_output.put_line ('----------------'); + + for i in 0 .. + nsubs + - 1 + loop + dbms_output.put_line (rpad (subs (i).name, 30, ' ') || ' with adress : ' || subs (i).address); + end loop; +end; +/ + +prompt ... +prompt ... to unsubscribe use +prompt ... set serveroutput on size 1000000 +prompt ... exec DBMS_AQADM.REMOVE_SUBSCRIBER ( queue_name =>'SYS.ALERT_QUE', subscriber => SYS.AQ$_AGENT ('OLDSERVER_3872_', NULL, NULL)); +prompt +prompt +prompt ... +prompt ... to purge the queue use: +prompt ... +prompt declare +prompt v_po_t dbms_aqadm.aq$_purge_options_t; +prompt begin +prompt dbms_aqadm.purge_queue_table( queue_table =>'SYS.ALERT_QT', purge_condition => null, purge_options =>v_po_t ); +prompt commit; +prompt end; +prompt ... +prompt + + + +ttitle off \ No newline at end of file diff --git a/oem/check_missing_alert_log_rights.sql b/oem/check_missing_alert_log_rights.sql new file mode 100644 index 0000000..f31fa4c --- /dev/null +++ b/oem/check_missing_alert_log_rights.sql @@ -0,0 +1,19 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- check Report to get all DB Instances with missing alert.log +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +column property_value format a40 heading "Property|Value" +column property_name format a60 heading "Property|Name" + +select target_name + , property_name + , property_value + from mgmt$target_properties + where property_name='alert_log_file' + and property_value='[MISSING_LOG]' +order by property_name +/ + diff --git a/oem/check_oracle_home_integrity.sql b/oem/check_oracle_home_integrity.sql new file mode 100644 index 0000000..7590c6d --- /dev/null +++ b/oem/check_oracle_home_integrity.sql @@ -0,0 +1,71 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get the Oracle Home of a target +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + + +define TARGET_NAME = '&1' + +prompt +prompt Parameter 1 = Target Name of the Oracle Home=> &&TARGET_NAME. +prompt + +set verify off + +set long 100 + +column orig_locatoin format a25 heading "Orignal|OHome" +column target_name format a56 heading "Target|Name" +column snap_location format a25 heading "Snap|OHome" +column target_dir format a25 heading "Target|Dir" +column is_current format a2 heading "C|R" +column target_guid format a32 heading "Target|Guid" +column start_timestamp format a18 heading "Snap|Time" + +select p.target_name + , p1.property_value as orig_locatoin + , i.location as snap_location + , case when p1.property_value = i.location then 'OK' else 'WRONG' end as testresult + , s.is_current + , to_char (s.start_timestamp, 'dd.mm.yyyy hh24:mi') as start_timestamp + from MGMT_LL_HOME_INFO i + , mgmt$target_properties p + , mgmt$target_properties p1 + , mgmt_ecm_gen_snapshot s + where p.property_name = 'HOME_GUID' + and p.property_value = i.oui_home_guid + and p1.property_name = 'INSTALL_LOCATION' + and p1.target_guid = p.target_guid + and s.snapshot_type = 'oracle_home_config' + and s.snapshot_guid = i.ecm_snapshot_id + and s.target_guid = p.target_guid + and lower (p.target_name) like lower ('&&TARGET_NAME.%') +order by s.is_current, p.target_name +/ + +prompt Check over all targets + +select * + from (select p.target_name + , p1.property_value as orig_locatoin + , i.location as snap_location + , case when p1.property_value = i.location then 'OK' else 'WRONG' end as testresult + , s.is_current + , to_char (s.start_timestamp, 'dd.mm.yyyy hh24:mi') as start_timestamp + from MGMT_LL_HOME_INFO i + , mgmt$target_properties p + , mgmt$target_properties p1 + , mgmt_ecm_gen_snapshot s + where p.property_name = 'HOME_GUID' + and p1.property_name = 'INSTALL_LOCATION' + and p1.target_guid = p.target_guid + and s.snapshot_type = 'oracle_home_config' + and s.snapshot_guid = i.ecm_snapshot_id + and s.target_guid = p.target_guid + -- and lower(p.target_name) like lower('&&TARGET_NAME.%') + ) + where testresult = 'WRONG' +order by is_current, target_name +/ diff --git a/oem/get_all_server_push_alerts.sql b/oem/get_all_server_push_alerts.sql new file mode 100644 index 0000000..489596a --- /dev/null +++ b/oem/get_all_server_push_alerts.sql @@ -0,0 +1,21 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get all metrics that are DB server defined +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +select distinct met.column_label + from (select distinct metric_guid + , target_type + , metric_name + , metric_column + , column_label + from mgmt_metrics + where target_type in ('oracle_database', 'rac_database')) met + , mgmt_metric_thresholds thresh + , mgmt_targets target + where thresh.metric_guid = met.metric_guid + and target.target_guid = thresh.target_guid + and thresh.is_push = 1; \ No newline at end of file diff --git a/oem/get_credentials.sql b/oem/get_credentials.sql new file mode 100644 index 0000000..312632a --- /dev/null +++ b/oem/get_credentials.sql @@ -0,0 +1,53 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get Credential Informations +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +column target_type format a20 +column user_name format a20 +column credential_set_name format a20 + +select t.target_name, tc.user_name, tc.credential_set_name + from SYSMAN.MGMT_TARGET_CREDENTIALS tc, SYSMAN.MGMT_TARGETS t + where tc.target_guid = t.target_guid +--and tc.user_name = 'SYSMAN' +order by 1, 2 +/ + +column target_type format a20 +column set_name format a20 +column cred_type_name format a20 +column cred_type_target_type format a20 + +select cst.target_type + , cst.set_name + , cst.cred_type_name + , cst.cred_type_target_type + , cs.target_type_meta_ver + from em_credential_set_types cst, mgmt_credential_sets cs + where cst.target_type = cs.target_type + and cst.set_name = cs.set_name + and cs.target_type_meta_ver = (select MAX_TYPE_META_VER + from mgmt_target_types tt + where cs.target_type = tt.target_type) + and cs.target_type = 'oracle_database' +/ + +select t.target_name + , tc.user_name + , tc.set_name + , nc.cred_name + from em_target_creds tc, MGMT_TARGETS t, EM_NC_CREDS nc + where tc.target_guid = t.target_guid + and t.target_type = 'host' + and nc.cred_guid = tc.cred_guid + and tc.user_name = '' + and tc.set_name = 'HostCredsPriv' +/ + +select * + from em_credential_set_types + where target_type = 'oracle_database' +/ diff --git a/oem/get_host_targets.sql b/oem/get_host_targets.sql new file mode 100644 index 0000000..cbd4df4 --- /dev/null +++ b/oem/get_host_targets.sql @@ -0,0 +1,41 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get all Targets on a host +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +define HOST_NAME = '&1' + +prompt +prompt Parameter 1 = Host Name => &&HOST_NAME. +prompt + +set long 100 + + +column target_name format a53 heading "Target|Name" +column host_name format a32 heading "Host|Name" +column entity_type format a15 heading "Target|Type" +column manage_status format a10 heading "Mon|Status" +column location format a40 heading "Install|OHome" + + select e.host_name + , e.entity_name as target_name + , e.entity_type + , decode (e.manage_status, 1, '-> Candi.', 2, 'Monit.', 0, '-Disab.', e.manage_status) as manage_status + --, e.promote_status + , nvl (p.property_value, p2.property_value) as location + from mgmt$manageable_entities e, mgmt$target_properties p, mgmt$target_properties p2 + where e.host_name like ('&&HOST_NAME.%') + and p.property_name(+) = 'INSTALL_LOCATION' + and p.target_guid(+) = e.ENTITY_GUID + and p2.property_name(+) = 'OracleHome' + and p2.target_guid(+) = e.ENTITY_GUID +-- and entity_type='oracle_home' +order by e.host_name + , e.entity_type + , e.entity_name + , e.promote_status + , e.manage_status +/ \ No newline at end of file diff --git a/oem/get_last_compliance_check_on_target.sql b/oem/get_last_compliance_check_on_target.sql new file mode 100644 index 0000000..e95cb8c --- /dev/null +++ b/oem/get_last_compliance_check_on_target.sql @@ -0,0 +1,24 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the times the compliance rules for a target are checked +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +define TARGET_NAME = '&1' + +prompt +prompt Parameter 1 = TARGET_NAME => &&TARGET_NAME. +prompt + +select root_cs_name "Compliance Standard" + , parent_cs_name "Parent Compliance Standard" + , rule_name "Rule Name" + , root_target_name "Target Name" + , root_target_type "Target Type" + , compliance_score "Compliance Score" + , last_evaluation_date "Last Evaluation Date" + from mgmt$cs_rule_eval_summary + where root_target_name = '&TARGET_NAME.' +order by last_evaluation_date desc +/ \ No newline at end of file diff --git a/oem/get_metric_extension.sql b/oem/get_metric_extension.sql new file mode 100644 index 0000000..a2c5df3 --- /dev/null +++ b/oem/get_metric_extension.sql @@ -0,0 +1,44 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get all user defined metric extension +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + + +define METRIK_NAME = '&1' + +prompt +prompt Parameter 1 = METRIK_NAME => &&METRIK_NAME. +prompt + + +column target_type format a10 +column name format a30 +column display_name format a30 +column extype format a10 + + select mg.target_type + , decode (mg.me_type, 1, 'Metrik Ext', 'Config Ext') as extype + , mg.name + , mg.latest_prod_version + from em_mext_groups mg + where mg.name = '&&METRIK_NAME.' +order by mg.me_type +/ + + select m.name + , m.version + , m.target_type + , m.display_name + , m.DESCRIPTION + from em_mext_versions m + where m.version = (select max (i.version) + from em_mext_versions i + where i.name = m.name) + and m.name = '&&METRIK_NAME.' +order by m.target_type +/ + + \ No newline at end of file diff --git a/oem/get_open_incidents.sql b/oem/get_open_incidents.sql new file mode 100644 index 0000000..b2aa59b --- /dev/null +++ b/oem/get_open_incidents.sql @@ -0,0 +1,95 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get all open incidents +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +set serveroutput on size 1000000 + + +define METRIK_SUM='&1' + +prompt +prompt Parameter 1 = METRIK_SUM => &&METRIK_SUM. +prompt + + +column target_name format a20 heading "Target|Name" +column target_type format a12 heading "Target|Type" +column msg format a30 heading "Message" WORD_WRAPPED +column event_name format a28 heading "Event|Name" +column reported_date format a18 heading "Reported|Date" +column severity format a8 heading "Severtiy" +column open_status format 99 heading "OP|ST" + +ttitle left "Incidents in the Environment" skip 2 + + +select t.target_name + ,t.target_type + ,e.msg + ,e.event_name + ,to_char(e.reported_date,'dd.mm.yyyy hh24:mi') as reported_date + ,e.severity + ,e.open_status + from sysman.mgmt$incidents i + ,sysman.MGMT$TARGET t + ,sysman.mgmt$events e + where t.target_guid = i.target_guid + and i.severity != 'Clear' + and e.incident_id = i.incident_id + and e.severity != 'Clear' + and upper(i.summary_msg) like upper('%&&METRIK_SUM.%') + -- and e.event_class = 'metric_alert' + order by t.target_name,e.event_class +/ + + + + +column target_name format a40 heading "Target|Name" +column target_type format a18 heading "Target|Type" +column severity format a8 heading "Severtiy" +column status_count format 99999 heading "Status|Count" + + +ttitle left "Summary over the Incidents in the Environment" skip 2 +select t.target_name + ,t.target_type + ,e.severity + ,count(*) as status_count + from sysman.mgmt$incidents i + ,sysman.MGMT$TARGET t + ,sysman.mgmt$events e + where t.target_guid = i.target_guid + and i.severity != 'Clear' + and e.incident_id = i.incident_id + and e.severity != 'Clear' + and upper(i.summary_msg) like upper('%&&METRIK_SUM.%') + -- and e.event_class = 'metric_alert' +group by t.target_name + ,t.target_type + ,e.severity + order by t.target_name +/ + +/* +internal OEM Base Tables for a incident over the e.event_id + +Event +select rowid,e.* from em_event_raw e where e.event_instance_id=? + +Incident +select rowid,e.* from em_issues_internal e where e.issue_id=? + + +to fix a not closeable incident on each table: +=> severity to 0 +=> open status to 0 +=> closed_date to actual date +!!! Not supported !!!! + +*/ + +ttitle off diff --git a/oem/get_target.sql b/oem/get_target.sql new file mode 100644 index 0000000..503f165 --- /dev/null +++ b/oem/get_target.sql @@ -0,0 +1,61 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get a target +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + + +define TARGET_NAME = '&1' + +prompt +prompt Parameter 1 = TARGET_NAME => &&TARGET_NAME. +prompt + +set verify off + +set long 100 + + +column target_name format a50 heading "Target|Name" +column host_name format a30 heading "Host|Name" +column target_type format a15 heading "Target|Type" +column last_metric_load_time format a18 heading "Last|Metric Load" +column last_collection format a18 heading "Last|Collection" +column first_metadata_load_time format a18 heading "First|Metadata from" +column display_name format a30 heading "Target Display|Name" + +select t.target_name + , t.target_type + , t.display_name + --,tt.type_display_name + , t.host_name + , to_char (tlt.last_load_time, 'dd.mm.yyyy hh24:mi') as last_metric_load_time + , to_char ( (select max (mmc.collection_timestamp) + from sysman.mgmt$metric_current mmc + where mmc.target_guid = t.target_guid) + , 'dd.mm.yyyy hh24:mi') + as last_collection + -- , to_char(tlt.first_metadata_load_time,'dd.mm.yyyy hh24:mi') as first_metadata_load_time + from mgmt_targets t, mgmt_targets_load_times tlt, mgmt_target_types tt + where t.target_type = tt.target_type(+) + and t.target_guid = tlt.target_guid + and lower (t.target_name) like lower ('&&TARGET_NAME.%') +/ + +column property_value format a40 heading "Property|Value" +column property_name format a60 heading "Property|Name" + +break on target_name + + select target_name, property_name, property_value + from mgmt$target_properties + where lower (target_name) like lower ('&&TARGET_NAME.%') +order by property_name +/ + +clear break + + + + diff --git a/oem/get_target_info.sql b/oem/get_target_info.sql new file mode 100644 index 0000000..6801752 --- /dev/null +++ b/oem/get_target_info.sql @@ -0,0 +1,31 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get all info over the properties of one target of this type +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + + +define TARGET_TYPE = '&1' + +prompt +prompt get properites of the target types in the OEM Repostiory with a target +prompt Parameter 1 = Target Type => &&TARGET_TYPE. +prompt + +column property_value format a40 heading "Property Target" +column property_name format a40 heading "Property Name" +column target_name format a40 heading "Target Name" + +break on TARGET_GUID + +select target_name + , TARGET_GUID + , property_name + , property_value + from mgmt$target_properties + where target_name = ( select target_name from mgmt$target_properties where lower(target_type) like lower('&&TARGET_TYPE') and rownum =1) +order by property_name +/ + +clear break \ No newline at end of file diff --git a/oem/get_target_oracle_home.sql b/oem/get_target_oracle_home.sql new file mode 100644 index 0000000..6f228dd --- /dev/null +++ b/oem/get_target_oracle_home.sql @@ -0,0 +1,60 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get the Oracle Home of a target +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +define TARGET_NAME = '&1' + +prompt +prompt Parameter 1 = Target Name of the Oracle Home=> &&TARGET_NAME. +prompt + +set verify off + +set long 100 + +column property_name format a11 heading "Property|Name" +column target_name format a35 heading "Target|Name" +column home_dir format a25 heading "OHome|Dir" +column target_dir format a25 heading "Target|Dir" +column oracle_home_target format a60 heading "OHome |T-Name" +column target_guid format a32 heading "Target|Guid" +column ENTITY_TYPE format a16 heading "Target|Type" + + select -- t.entity_guid target_guid + -- , + t.ENTITY_TYPE + , t.ENTITY_NAME as Target_name + --, q.property_name + --, ta.target_name as Target_name + , rtrim (q.property_value, '/') target_dir + , th.target_name as oracle_home_target + , rtrim (p.property_value, '/') home_dir + from em_manageable_entities t + , mgmt_target_properties q + , mgmt_assoc_instances i + , em_manageable_entities h + , mgmt_target_properties p + , mgmt$target ta + , mgmt$target th + where t.manage_status = 2 + and t.broken_reason = 0 + and ta.target_guid(+) = t.entity_guid + and th.target_guid = h.entity_guid + and t.emd_url is not null + and t.entity_type != 'oracle_home' + and t.entity_type != 'host' + and t.entity_guid = q.target_guid + and q.property_name = 'OracleHome' + and i.source_me_guid = t.entity_guid + and i.assoc_type = 'installed_at' + and i.dest_me_guid = h.entity_guid + and h.entity_type = 'oracle_home' + and p.target_guid = h.entity_guid + and p.property_name = 'INSTALL_LOCATION' + and lower (th.target_name) like lower ('&&TARGET_NAME.%') +order by t.ENTITY_NAME +/ + \ No newline at end of file diff --git a/oem/get_target_properties.sql b/oem/get_target_properties.sql new file mode 100644 index 0000000..88caa61 --- /dev/null +++ b/oem/get_target_properties.sql @@ -0,0 +1,25 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get all possible properties of a target Type +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +define TARGET_TYPE = '&1' + +prompt +prompt get properites of the target types in the OEM Repostiory with a target +prompt Parameter 1 = Target Type => &&TARGET_TYPE. +prompt + +column target_type format a40 heading "Target Types" +column property_name format a40 heading "Property | Name" + +select property_name + , target_type + from mgmt$target_properties + where lower(target_type) like lower('&&TARGET_TYPE') +group by property_name + , target_type +order by property_name +/ diff --git a/oem/get_target_types.sql b/oem/get_target_types.sql new file mode 100644 index 0000000..0afe526 --- /dev/null +++ b/oem/get_target_types.sql @@ -0,0 +1,20 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- desc get all deployed target types in the Repository +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +prompt +prompt get all target types in the OEM Repostiory with a target +prompt + +column target_type format a40 heading "Target Types" +column tg_count format 9G999 heading "Count of|targets" + +select target_type + , count(*) as tg_count + from sysman.em_targets + group by target_type +/ + diff --git a/oem/get_upload_status_target.sql b/oem/get_upload_status_target.sql new file mode 100644 index 0000000..bd94b9e --- /dev/null +++ b/oem/get_upload_status_target.sql @@ -0,0 +1,43 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get the upload status of the target on a host +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + + +define HOST_NAME = '&1' + +prompt +prompt Parameter 1 = Host Name => &&HOST_NAME. +prompt + +set verify off + +set long 100 + + +column target_name format a50 heading "Target|Name" +column host_name format a30 heading "Host|Name" +column target_type format a15 heading "Target|Type" +column last_metric_load_time format a18 heading "Last|Metric Load" +column last_collection format a18 heading "Last|Collection" +column diff format 99999 heading "Diff| Time" + +select target_name + , target_type + , host_name + , to_char(last_metric_load_time,'dd.mm.yyyy hh24:mi') as last_metric_load_time + , to_char(last_collection,'dd.mm.yyyy hh24:mi') as last_collection + , last_collection-last_metric_load_time as diff +from ( + select t.target_name + , t.target_type + , t.host_name + , last_metric_load_time + , (select max(mmc.collection_timestamp) from sysman.mgmt$metric_current mmc where mmc.target_guid=t.target_guid) last_collection + from sysman.mgmt$target t + where lower(t.host_name) like lower('&&HOST_NAME.%') +) +order by last_collection +/ \ No newline at end of file diff --git a/oem/help_oem.sql b/oem/help_oem.sql new file mode 100644 index 0000000..85f9525 --- /dev/null +++ b/oem/help_oem.sql @@ -0,0 +1,48 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: OEM SQL Script Overview +-- Date: +--============================================================================== + +DOC +------------------------------------------------------------------------------- + +#The OEM Query Scripts +--================= + +OEM Repository +--============================================================================== + +oem/get_target.sql - get info for a target + +oem/get_target_types.sql - get all deployed target types in the repository +oem/get_target_properties.sql - get the properties of a target - parameter 1 the target type +oem/get_target_info.sql - get the properties of a target with sample values - parameter 1 the target type + +oem/get_host_targets.sql - get all targets on one host +oem/get_upload_status_target.sql - get the upload status of all targets on a host + +oem/get_target_oracle_home.sql - get the targets to an oracle home target name - parameter 1 - part of the oracle home target name + + +oem/get_metric_extension.sql - get all user defined metric extension + +oem/get_all_server_push_alerts.sql - get all metrics that are DB server defined + +oem/get_open_incidents.sql - get all open incidents + +oem/get_credentials.sql - get Credential Information + +oem/get_last_compliance_check_on_target.sql - get the times the compliance rules for a target are checked + + +Oracle Agent on Database side +--============================================================================== + +oem/check_agent.sql - check the internal setting of the Oracle Agent +oem/check_missing_alert_log_rights.sql - check Report to get all DB Instances with missing alert.log +oem/check_oracle_home_integrity.sql - check if the oracle home settings on a snapshot of the target properties are the same as on the target itself +oem/unset_all_metric_thresholds.sql - unset all DB side server metric thresholds + +------------------------------------------------------------------------------- +# \ No newline at end of file diff --git a/oem/remove_alert_from_database.sql b/oem/remove_alert_from_database.sql new file mode 100644 index 0000000..38eb6bd --- /dev/null +++ b/oem/remove_alert_from_database.sql @@ -0,0 +1,58 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- +--============================================================================== +-- http://www.idevelopment.info/data/Oracle/DBA_tips/Advanced_Queuing/AQ_2.shtml#Dequeue Message +--============================================================================== +set verify off +set linesize 130 pagesize 300 recsep off + +SET SERVEROUTPUT ON + +DECLARE + + dequeue_options dbms_aq.dequeue_options_t; + message_properties dbms_aq.message_properties_t; + message_handle RAW(16); + message aq.message_type; + +BEGIN + + -- ------------------------------------------------------- + + dequeue_options.CONSUMER_NAME := NULL; + dequeue_options.DEQUEUE_MODE := DBMS_AQ.REMOVE; + dequeue_options.NAVIGATION := DBMS_AQ.NEXT_MESSAGE; + dequeue_options.VISIBILITY := DBMS_AQ.IMMEDIATE; + dequeue_options.WAIT := DBMS_AQ.FOREVER; + dequeue_options.MSGID := 'xxxxxxxxxxxxxxxxxxxxxxx'; + dequeue_options.CORRELATION := 'TEST MESSAGE'; + + -- ------------------------------------------------------- + + DBMS_AQ.DEQUEUE ( + queue_name => 'SYS.ALERT_QUE' + , dequeue_options => dequeue_options + , message_properties => message_properties + , payload => message + , msgid => message_handle + ); + + -- ------------------------------------------------------- + + dbms_output.put_line('+-----------------+'); + dbms_output.put_line('| MESSAGE PAYLOAD |'); + dbms_output.put_line('+-----------------+'); + dbms_output.put_line('- Message ID := ' || message.message_id); + dbms_output.put_line('- Subject := ' || message.subject); + dbms_output.put_line('- Message := ' || message.text); + dbms_output.put_line('- Dollar Value := ' || message.dollar_value); + + -- ------------------------------------------------------- + + COMMIT; + + -- ------------------------------------------------------- + +END; +/ \ No newline at end of file diff --git a/oem/unset_all_metric_thresholds.sql b/oem/unset_all_metric_thresholds.sql new file mode 100644 index 0000000..ade9b32 --- /dev/null +++ b/oem/unset_all_metric_thresholds.sql @@ -0,0 +1,293 @@ +-- ====================================== +-- GPI - Gunther Pippèrr +-- set all server based metrics to empty values +-- ======================================= +set verify off +set linesize 130 pagesize 300 recsep off + +define INSTANCE_NAME = '&1' + +prompt +prompt Parameter 1 = Instance Name => &&INSTANCE_NAME. +prompt + + +set serveroutput on size 1000000 + +declare + type metrics_idTab is table of varchar2 (2000) + index by binary_integer; + + cursor c_metrics (p_instance_name varchar2) + is + select metrics_id + , object_type + , object_name + , instance_name + from table (dbms_server_alert.view_thresholds) + where instance_name = p_instance_name; + + v_instance varchar2 (32) := '&&INSTANCE_NAME.'; + v_warning_operator binary_integer; + v_warning_operator_text varchar2 (32); + v_warning_value varchar2 (32); + v_critical_operator binary_integer; + v_critical_operator_text varchar2 (32); + v_critical_value varchar2 (32); + v_observation_period binary_integer; + v_consecutive_occurrences binary_integer; + + v_mid metrics_idTab; +begin + + + + + -- create ta with all metric id's + -- if you are a lucky sys user you can use X$KEWMDSM for this stupid typing!! + -- + + v_mid(DBMS_SERVER_ALERT.SQL_SRV_RESPONSE_TIME ):='Service Response (for each execution) Seconds '; + v_mid(DBMS_SERVER_ALERT.BUFFER_CACHE_HIT ):='Buffer Cache Hit (%) % of cache accesses '; +-- v_mid(DBMS_SERVER_ALERT.LIBRARY_CACHE_HIT ):='Library Cache Hit (%) % of cache accesses '; +-- v_mid(DBMS_SERVER_ALERT.LIBRARY_CACHE_MISS ):='Library Cache Miss (%) % of cache accesses '; + v_mid(DBMS_SERVER_ALERT.MEMORY_SORTS_PCT ):='Sorts in Memory (%) % of sorts '; + v_mid(DBMS_SERVER_ALERT.REDO_ALLOCATION_HIT ):='Redo Log Allocation Hit % of redo allocations '; +-- v_mid(DBMS_SERVER_ALERT.TRANSACTION_RATE ):='Number of Transactions (for each second) Transactions for each Second '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_READS_SEC ):='Physical Reads (for each second) Reads for each Second '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_READS_TXN ):='Physical Reads (for each transaction) Reads for each Transaction '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_WRITES_SEC ):='Physical Writes (for each second) Writes for each Second '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_WRITES_TXN ):='Physical Writes (for each transaction) Writes for each Transaction '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_READS_DIR_SEC ):='Direct Physical Reads (for each second) Reads for each Second '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_READS_DIR_TXN ):='Direct Physical Reads (for each transaction) Reads for each Transaction '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_WRITES_DIR_SEC ):='Direct Physical Writes (for each second) Writes for each Second '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_WRITES_DIR_TXN ):='Direct Physical Writes (for each transaction) Writes for each Transaction '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_READS_LOB_SEC ):='Direct LOB Physical Reads (for each second) Reads for each Second '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_READS_LOB_TXN ):='Direct LOB Physical Reads (for each transaction) Reads for each Transaction '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_WRITES_LOB_SEC ):='Direct LOB Physical Writes (for each second) Writes for each Second '; + v_mid(DBMS_SERVER_ALERT.PHYSICAL_WRITES_LOB_TXN ):='Direct LOB Physical Writes (for each transaction) Writes for each Transaction '; + v_mid(DBMS_SERVER_ALERT.REDO_GENERATED_SEC ):='Redo Generated (for each second) Redo Bytes for each Second '; + v_mid(DBMS_SERVER_ALERT.REDO_GENERATED_TXN ):='Redo Generated (for each transaction) Redo Bytes for each Transaction '; + v_mid(DBMS_SERVER_ALERT.DATABASE_WAIT_TIME ):='Database Wait Time (%) % of all database time '; + v_mid(DBMS_SERVER_ALERT.DATABASE_CPU_TIME ):='Database CPU Time (%) % of all database time '; + v_mid(DBMS_SERVER_ALERT.LOGONS_SEC ):='Cumulative Logons (for each second)Logons for each Second '; + v_mid(DBMS_SERVER_ALERT.LOGONS_TXN ):='Cumulative Logons (for each transaction)Logons for each Transaction '; + v_mid(DBMS_SERVER_ALERT.LOGONS_CURRENT ):='Current Number of Logons Number of Logons '; + v_mid(DBMS_SERVER_ALERT.OPEN_CURSORS_SEC ):='Cumulative Open Cursors (for each second) Cursors for each Second '; + v_mid(DBMS_SERVER_ALERT.OPEN_CURSORS_TXN ):='Cumulative Open Cursors (for each transaction) Cursors for each Transaction '; + v_mid(DBMS_SERVER_ALERT.OPEN_CURSORS_CURRENT ):='Current Number of Cursors Number of Cursors '; + v_mid(DBMS_SERVER_ALERT.USER_COMMITS_SEC ):='User Commits (for each second) Commits for each Second '; + v_mid(DBMS_SERVER_ALERT.USER_COMMITS_TXN ):='User Commits (for each transaction) Commits for each Transaction '; + v_mid(DBMS_SERVER_ALERT.USER_ROLLBACKS_SEC ):='User Rollbacks (for each second) rollbacks for each Second '; + v_mid(DBMS_SERVER_ALERT.USER_ROLLBACKS_TXN ):='User Rollbacks (for each transaction) Rollbacks for each Transaction '; + v_mid(DBMS_SERVER_ALERT.USER_CALLS_SEC ):='User Calls (for each second) Calls for each Second '; + v_mid(DBMS_SERVER_ALERT.USER_CALLS_TXN ):='User Calls (for each transaction) Calls for each Transaction '; + v_mid(DBMS_SERVER_ALERT.RECURSIVE_CALLS_SEC ):='Recursive Calls (for each second) Calls for each Second '; + v_mid(DBMS_SERVER_ALERT.RECURSIVE_CALLS_TXN ):='Recursive Calls (for each transaction) Calls for each Transaction '; + v_mid(DBMS_SERVER_ALERT.SESS_LOGICAL_READS_SEC ):='Session Logical Reads (for each second) Reads for each Second '; + v_mid(DBMS_SERVER_ALERT.SESS_LOGICAL_READS_TXN ):='Session Logical Reads (for each transaction) Reads for each Transaction '; + v_mid(DBMS_SERVER_ALERT.DBWR_CKPT_SEC ):='DBWR Checkpoints (for each second) Checkpoints for each Second '; +-- v_mid(DBMS_SERVER_ALERT.LOG_SWITCH_SEC ):='Background Checkpoints (for each second) Checkpoints for each Second '; + v_mid(DBMS_SERVER_ALERT.REDO_WRITES_SEC ):='Redo Writes (for each second) Writes for each Second '; + v_mid(DBMS_SERVER_ALERT.REDO_WRITES_TXN ):='Redo Writes (for each transaction) Writes for each Transaction '; + v_mid(DBMS_SERVER_ALERT.LONG_TABLE_SCANS_SEC ):='Scans on Long Tables (for each second) Scans for each Second '; + v_mid(DBMS_SERVER_ALERT.LONG_TABLE_SCANS_TXN ):='Scans on Long Tables (for each transaction) Scans for each Transaction '; + v_mid(DBMS_SERVER_ALERT.TOTAL_TABLE_SCANS_SEC ):='Total Table Scans (for each second) Scans for each Second '; + v_mid(DBMS_SERVER_ALERT.TOTAL_TABLE_SCANS_TXN ):='Total Table Scans (for each transaction) Scans for each Transaction '; + v_mid(DBMS_SERVER_ALERT.FULL_INDEX_SCANS_SEC ):='Fast Full Index Scans (for each second) Scans for each Second '; + v_mid(DBMS_SERVER_ALERT.FULL_INDEX_SCANS_TXN ):='Fast Full Index Scans (for each transaction) Scans for each Transaction '; + v_mid(DBMS_SERVER_ALERT.TOTAL_INDEX_SCANS_SEC ):='Total Index Scans (for each second) Scans for each Second '; + v_mid(DBMS_SERVER_ALERT.TOTAL_INDEX_SCANS_TXN ):='Total Index Scans (for each transaction) Scans for each Transaction '; + v_mid(DBMS_SERVER_ALERT.TOTAL_PARSES_SEC ):='Total Parses (for each second) Parses for each Second '; + v_mid(DBMS_SERVER_ALERT.TOTAL_PARSES_TXN ):='Total Parses (for each transaction) Parses for each Transaction '; + v_mid(DBMS_SERVER_ALERT.HARD_PARSES_SEC ):='Hard Parses (for each second) Parses for each Second '; + v_mid(DBMS_SERVER_ALERT.HARD_PARSES_TXN ):='Hard Parses (for each transaction) Parses for each Transaction '; + v_mid(DBMS_SERVER_ALERT.PARSE_FAILURES_SEC ):='Parse Failures (for each second) Parses for each Second '; + v_mid(DBMS_SERVER_ALERT.PARSE_FAILURES_TXN ):='Parse Failures (for each transaction) Parses for each Transaction '; + v_mid(DBMS_SERVER_ALERT.DISK_SORT_SEC ):='Sorts to Disk (for each second) Sorts for each Second '; + v_mid(DBMS_SERVER_ALERT.DISK_SORT_TXN ):='Sorts to Disk (for each transaction) Sorts for each Transaction '; + v_mid(DBMS_SERVER_ALERT.ROWS_PER_SORT ):='Rows Processed for each Sort Rows for each Sort '; + v_mid(DBMS_SERVER_ALERT.EXECUTE_WITHOUT_PARSE ):='Executes Performed Without Parsing % of all executes '; + v_mid(DBMS_SERVER_ALERT.SOFT_PARSE_PCT ):='Soft Parse (%) % of all parses '; + v_mid(DBMS_SERVER_ALERT.CURSOR_CACHE_HIT ):='Cursor Cache Hit (%) % of soft parses '; + v_mid(DBMS_SERVER_ALERT.USER_CALLS_PCT ):='User Calls (%) % of all calls '; +-- v_mid(DBMS_SERVER_ALERT.TXN_COMMITTED_PCT ):='Transactions Committed (%) % of all transactions '; + v_mid(DBMS_SERVER_ALERT.NETWORK_BYTES_SEC ):='Network Bytes, for each second Bytes for each Second '; + v_mid(DBMS_SERVER_ALERT.RESPONSE_TXN ):='Response (for each transaction) Seconds for each Transaction '; +-- v_mid(DBMS_SERVER_ALERT.DATA_DICT_HIT ):='Data Dictionary Hit (%) % of dictionary accesses '; +-- v_mid(DBMS_SERVER_ALERT.DATA_DICT_MISS ):='Data Dictionary Miss (%) % of dictionary accesses '; + v_mid(DBMS_SERVER_ALERT.SHARED_POOL_FREE_PCT ):='Shared Pool Free(%) % of shared pool '; +-- v_mid(DBMS_SERVER_ALERT.AVERAGE_FILE_READ_TIME ):='Average File Read Time Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.AVERAGE_FILE_WRITE_TIME ):='Average File Write Time Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.DISK_IO ):='Disk I/O Milliseconds '; + v_mid(DBMS_SERVER_ALERT.PROCESS_LIMIT_PCT ):='Process Limit Usage (%) % of maximum value '; + v_mid(DBMS_SERVER_ALERT.SESSION_LIMIT_PCT ):='Session Limit Usage (%) % of maximum value '; + v_mid(DBMS_SERVER_ALERT.USER_LIMIT_PCT ):='User Limit Usage (%) % of maximum value '; + v_mid(DBMS_SERVER_ALERT.AVG_USERS_WAITING ):='Average Number of Users Waiting on a Class of Wait Events Count of sessions '; + v_mid(DBMS_SERVER_ALERT.DB_TIME_WAITING ):='Percent of Database Time Spent Waiting on a Class of Wait Events % of Database Time'; +-- v_mid(DBMS_SERVER_ALERT.APPL_DESGN_WAIT_SCT ):='Application Design Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.APPL_DESGN_WAIT_TIME ):='Application Design Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.PHYS_DESGN_WAIT_SCT ):='Physical Design Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.PHYS_DESGN_WAIT_TIME ):='Physical Design Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.CONTENTION_WAIT_SCT ):='Internal Contention Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.CONTENTION_WAIT_TIME ):='Internal Contention Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.PSERVICE_WAIT_SCT ):='Process Service Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.PSERVICE_WAIT_TIME ):='Process Service Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.NETWORK_MSG_WAIT_SCT ):='Network Message Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.NETWORK_MSG_WAIT_TIME ):='Network Message Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.DISK_IO_WAIT_SCT ):='Disk I/O Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.OS_SERVICE_WAIT_SCT ):='Operating System Service Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.OS_SERVICE_WAIT_TIME ):='Operating System Service Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.DBR_IO_LIMIT_WAIT_SCT ):='Resource Mgr I/O Limit Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.DBR_IO_LIMIT_WAIT_TIME ):='Resource Mgr I/O Limit Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.DBR_CPU_LIMIT_WAIT_SCT ):='Resource Mgr CPU Limit Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.DBR_CPU_LIMIT_WAIT_TIME ):='Resource Mgr CPU Limit Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.DBR_USR_LIMIT_WAIT_SCT ):='Resource Mgr User Limit Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.DBR_USR_LIMIT_WAIT_TIME ):='Resource Mgr User Limit Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.OS_SCHED_CPU_WAIT_SCT ):='Operating System Scheduler CPU Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.OS_SCHED_CPU__WAIT_TIME ):='Operating System Scheduler CPU Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.CLUSTER_MSG_WAIT_SCT ):='Cluster Messaging Wait (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.CLUSTER_MSG_WAIT_TIME ):='Cluster Messaging Wait (by time) Microseconds '; +-- v_mid(DBMS_SERVER_ALERT.OTHER_WAIT_SCT ):='Other Waits (by session count) Count of sessions '; +-- v_mid(DBMS_SERVER_ALERT.OTHER_WAIT_TIME ):='Other Waits (by time) Microseconds '; + v_mid(DBMS_SERVER_ALERT.ENQUEUE_TIMEOUTS_SEC ):='Enqueue Timeouts (for each second) Timeouts for each Second '; + v_mid(DBMS_SERVER_ALERT.ENQUEUE_TIMEOUTS_TXN ):='Enqueue Timeouts (for each transaction) Timeouts for each Transaction '; + v_mid(DBMS_SERVER_ALERT.ENQUEUE_WAITS_SEC ):='Enqueue Waits (for each second) Waits for each Second '; + v_mid(DBMS_SERVER_ALERT.ENQUEUE_WAITS_TXN ):='Enqueue Waits (for each transaction) Waits for each Transaction '; + v_mid(DBMS_SERVER_ALERT.ENQUEUE_DEADLOCKS_SEC ):='Enqueue Deadlocks (for each second) Deadlocks for each Second '; + v_mid(DBMS_SERVER_ALERT.ENQUEUE_DEADLOCKS_TXN ):='Enqueue Deadlocks (for each transaction) Deadlocks for each Transaction '; + v_mid(DBMS_SERVER_ALERT.ENQUEUE_REQUESTS_SEC ):='Enqueue Requests (for each second) Requests for each Second '; + v_mid(DBMS_SERVER_ALERT.ENQUEUE_REQUESTS_TXN ):='Enqueue Requests (for each transaction) Requests for each Transaction '; + v_mid(DBMS_SERVER_ALERT.DB_BLKGETS_SEC ):='DB Block Gets (for each second) Gets for each Second '; + v_mid(DBMS_SERVER_ALERT.DB_BLKGETS_TXN ):='DB Block Gets (for each transaction) Gets for each Transaction '; + v_mid(DBMS_SERVER_ALERT.CONSISTENT_GETS_SEC ):='Consistent Gets (for each second) Gets for each Second '; + v_mid(DBMS_SERVER_ALERT.CONSISTENT_GETS_TXN ):='Consistent Gets (for each transaction) Gets for each Transaction '; + v_mid(DBMS_SERVER_ALERT.DB_BLKCHANGES_SEC ):='DB Block Changes (for each second) Changes for each Second '; + v_mid(DBMS_SERVER_ALERT.DB_BLKCHANGES_TXN ):='DB Block Changes (for each transaction) Changes for each Transaction '; + v_mid(DBMS_SERVER_ALERT.CONSISTENT_CHANGES_SEC ):='Consistent Changes (for each second) Changes for each Second '; + v_mid(DBMS_SERVER_ALERT.CONSISTENT_CHANGES_TXN ):='Consistent Changes (for each transaction) Changes for each Transaction '; + v_mid(DBMS_SERVER_ALERT.SESSION_CPU_SEC ):='Database CPU (for each second) Microseconds for each Second '; + v_mid(DBMS_SERVER_ALERT.SESSION_CPU_TXN ):='Database CPU (for each transaction) Microseconds for each Transaction '; + v_mid(DBMS_SERVER_ALERT.CR_BLOCKS_CREATED_SEC ):='CR Blocks Created (for each second) Blocks for each Second '; + v_mid(DBMS_SERVER_ALERT.CR_BLOCKS_CREATED_TXN ):='CR Blocks Created (for each transaction) Blocks for each Transaction '; + v_mid(DBMS_SERVER_ALERT.CR_RECORDS_APPLIED_SEC ):='CR Undo Records Applied (for each second) Records for each Second '; + v_mid(DBMS_SERVER_ALERT.CR_RECORDS_APPLIED_TXN ):='CR Undo Records Applied (for each transaction) Records for each Transaction '; + v_mid(DBMS_SERVER_ALERT.RB_RECORDS_APPLIED_SEC ):='Rollback Undo Records Applied (for each second) Records for each Second '; + v_mid(DBMS_SERVER_ALERT.RB_RECORDS_APPLIED_TXN ):='Rollback Undo Records Applied (for each transactionRecords for each Transaction '; + v_mid(DBMS_SERVER_ALERT.LEAF_NODE_SPLITS_SEC ):='Leaf Node Splits (for each secondSplits for each Second '; + v_mid(DBMS_SERVER_ALERT.LEAF_NODE_SPLITS_TXN ):='Leaf Node Splits (for each transaction) Splits for each Transaction '; + v_mid(DBMS_SERVER_ALERT.BRANCH_NODE_SPLITS_SEC ):='Branch Node Splits (for each second) Splits for each Second '; + v_mid(DBMS_SERVER_ALERT.BRANCH_NODE_SPLITS_TXN ):='Branch Node Splits (for each transaction) Splits for each Transaction '; + v_mid(DBMS_SERVER_ALERT.GC_BLOCKS_CORRUPT ):='Global Cache Blocks Corrupt Blocks '; + v_mid(DBMS_SERVER_ALERT.GC_BLOCKS_LOST ):='Global Cache Blocks Lost Blocks '; + v_mid(DBMS_SERVER_ALERT.GC_AVG_CR_GET_TIME ):='Global Cache CR Request Milliseconds '; + v_mid(DBMS_SERVER_ALERT.GC_AVG_CUR_GET_TIME ):='Global Cache Current Request Milliseconds '; +-- v_mid(DBMS_SERVER_ALERT.PX_DOWNGRADED_SEC ):='Downgraded Parallel Operations (for each second) Operations for each Second '; + v_mid(DBMS_SERVER_ALERT.PX_DOWNGRADED_25_SEC ):='Downgraded to 25% and more (for each second) Operations for each Second '; + v_mid(DBMS_SERVER_ALERT.PX_DOWNGRADED_50_SEC ):='Downgraded to 50% and more (for each second) Operations for each Second '; + v_mid(DBMS_SERVER_ALERT.PX_DOWNGRADED_75_SEC ):='Downgraded to 75% and more (for each second) Operations for each Second '; +-- v_mid(DBMS_SERVER_ALERT.PX_DOWNGRADED_SER_SEC ):='Downgraded to serial (for each second) Operations for each Second '; + v_mid(DBMS_SERVER_ALERT.BLOCKED_USERS ):='Number of Users blocked by some Session Number of Users '; + v_mid(DBMS_SERVER_ALERT.PGA_CACHE_HIT ):='PGA Cache Hit (%) % bytes processed in PGA '; + v_mid(DBMS_SERVER_ALERT.ELAPSED_TIME_PER_CALL ):='Elapsed time for each user call for each service Microseconds for each call '; + v_mid(DBMS_SERVER_ALERT.CPU_TIME_PER_CALL ):='CPU time for each user call for each service Microseconds for each call '; + v_mid(DBMS_SERVER_ALERT.TABLESPACE_PCT_FULL ):='Tablespace space usage% full '; + v_mid(DBMS_SERVER_ALERT.TABLESPACE_BYT_FREE ):='Tablespace bytes space usage Kilobytes free '; + + -- read all metrics for the instance and set to null + + for rec in c_metrics (p_instance_name => upper (v_instance)) + loop + dbms_output.put_line ('-- Info ' || rpad (' ', 80, '-')); + dbms_output.put_line ('-- Info - Metric for Instance ::' || rec.instance_name); + dbms_output.put_line ( + '-- Info - Metric ID (' || rec.metrics_id || ') O. Type(' || rec.object_type || ') O. Name(' || rec.object_name || ')'); + + begin + dbms_output.put_line ('-- Info - Metrik Name :: ' || v_mid (rec.metrics_id)); + exception + when others + then + dbms_output.put_line ('-- Info - Metrik Name not found for :: ' || rec.metrics_id); + end; + + dbms_server_alert.get_threshold (metrics_id => rec.metrics_id + , warning_operator => v_warning_operator + , warning_value => v_warning_value + , critical_operator => v_critical_operator + , critical_value => v_critical_value + , observation_period => v_observation_period + , consecutive_occurrences => v_consecutive_occurrences + , instance_name => rec.instance_name + , object_type => rec.object_type + , object_name => rec.object_name); + + --- + select decode (v_warning_operator + , 0, 'GT' + , 1, 'EQ' + , 2, 'LT' + , 3, 'LE' + , 4, 'GE' + , 5, 'CONTAINS' + , 6, 'NE' + , 7, 'DO_NOT_CHECK' + , 'NONE') + into v_warning_operator_text + from dual; + + --- + select decode (v_critical_operator + , 0, 'GT' + , 1, 'EQ' + , 2, 'LT' + , 3, 'LE' + , 4, 'GE' + , 5, 'CONTAINS' + , 6, 'NE' + , 7, 'DO NOT CHECK' + , 'NONE') + into v_critical_operator_text + from dual; + + --- + dbms_output.put_line ( + '-- Info - Warning OP :: ' + || rpad (v_warning_operator_text, 20, ' ') + || 'Warning Value :: ' + || v_warning_value); + dbms_output.put_line ( + '-- Info - Critical OP :: ' + || rpad (v_critical_operator_text, 20, ' ') + || 'Critical Value :: ' + || v_critical_value); + dbms_output.put_line ( + '-- Info - Observation Period :: ' + || rpad (v_observation_period, 20, ' ') + || 'Consecutive Occurrences :: ' + || v_consecutive_occurrences); + + --- + + if v_warning_value is not null + then + dbms_output.put_line ('-- Info -'); + dbms_output.put_line ('-- Info - Unset the thresholds for this Metric : ' || rec.metrics_id); + + dbms_server_alert.set_threshold (metrics_id => rec.metrics_id + , warning_operator => null + , warning_value => null + , critical_operator => null + , critical_value => null + , observation_period => null + , consecutive_occurrences => null + , instance_name => rec.instance_name + , object_type => rec.object_type + , object_name => rec.object_name); + commit; + end if; + + dbms_output.put_line ('-- Info ' || rpad (' ', 80, '-')); + end loop; +end; +/ \ No newline at end of file diff --git a/open_trans.sql b/open_trans.sql new file mode 100644 index 0000000..5d6d75c --- /dev/null +++ b/open_trans.sql @@ -0,0 +1,47 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show open transactions in the database +-- Date: September 2013 +-- +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Report DB transactions longer open " SKIP 1 + +column sessionid format a8 heading "DB|Session" +column inst_id format 99 heading "In|id" +column username format a14 heading "DB|user" +column osuser format a9 heading "OS|Benutzer" +column machine format a16 heading "OS|Maschine" +column program format a10 heading "OS|Programm" +column action format a10 heading "Action" +column status format a6 heading "Status" +column logon_time format a18 heading "Login|Time" +column start_time format a14 heading "Start|Time" +column last_call_et format 999G999G999 heading "Last Sql|Time s" +column xid format a15 heading "Transaction|id" +column name format a15 + +select n.inst_id + , n.sid + , n.serial# + , n.username + , n.osuser + , n.machine + , n.program + , n.action + , to_char(n.logon_time,'dd.mm.yyyy hh24:mi') as logon_time + , n.last_call_et + , n.status + --, t.name + , t.xidusn||'.'||t.xidslot||'.'||t.xidsqn as xid + from gv$session n + , gv$transaction t +where n.taddr = t.addr + and n.INST_ID = t.INST_ID + and to_date(t.start_time, 'MM/DD/YY HH24:MI:SS') < sysdate - (2 / 24) + and sysdate - (n.last_call_et / (60 * 60 * 24)) < sysdate - (2 / 24) + and n.status != 'ACTIVE' +/ + +ttitle off diff --git a/ords.sql b/ords.sql new file mode 100644 index 0000000..a2ed34f --- /dev/null +++ b/ords.sql @@ -0,0 +1,47 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the ORDS REST data service settings +-- Date: 03.2017 +--============================================================================== +-- Source: +--https://oracle-base.com/articles/misc/oracle-rest-data-services-ords-create-basic-rest-web-services-using-plsql +--============================================================================== + +set linesize 130 pagesize 300 + +column source_type format a15 +column source format a35 +column uri_template format a20 +column name format a20 +column uri_prefix format a20 +column method format a10 +column id format 9999999 + +ttitle left "ORDS Modules" skip 2 + +select id + , name + , uri_prefix + from user_ords_modules +order by name +/ + +ttitle left "ORDS Templates" skip 2 +select id + , module_id + , uri_template +from user_ords_templates +order by module_id +/ + + +ttitle left "ORDS Handlers" skip 2 +select id + , template_id + , source_type + , method, source +from user_ords_handlers +order by id +/ + +ttitle off \ No newline at end of file diff --git a/parallel.sql b/parallel.sql new file mode 100644 index 0000000..f4ecbf3 --- /dev/null +++ b/parallel.sql @@ -0,0 +1,139 @@ +--============================================================================== +-- Desc: parallel SQL informations +--============================================================================== +-- see also: +-- Oracle Support Document 444164.1 (Tracing Parallel Execution with _px_trace. Part I) +-- can be found at: https://support.oracle.com/epmos/faces/DocumentDisplay?id=444164.1 +-- https://docs.oracle.com/cd/E18283_01/server.112/e16541/parallel006.htm#CIHGJFFC +--============================================================================== +set linesize 130 pagesize 300 + + +column username format a12 +column "QC SID" format A6 +column "SID" format A6 +column "QC/Slave" format A8 +column "Req. DOP" format 9999 +column "Actual DOP" format 9999 +column "Slaveset" format A8 +column "Slave INST" format A9 +column "QC INST" format A6 +column wait_event format a30 + +ttitle left "User and his Parallel sessions" skip 2 + + +select decode (px.qcinst_id + , null, username + , ' - ' + || lower (substr (pp.SERVER_NAME + , length (pp.SERVER_NAME) + - 4 + , 4))) + "Username" + , decode (px.qcinst_id, null, 'QC', '(Slave)') "QC/Slave" + , to_char (px.server_set) "SlaveSet" + , to_char (s.sid) "SID" + , to_char (px.inst_id) "Slave INST" + , decode (sw.state, 'WAITING', 'WAIT', 'NOT WAIT') as STATE + , case sw.state when 'WAITING' then substr (sw.event, 1, 30) else null end as wait_event + , decode (px.qcinst_id, null, to_char (s.sid), px.qcsid) "QC SID" + , to_char (px.qcinst_id) "QC INST" + , px.req_degree "Req. DOP" + , px.degree "Actual DOP" + from gv$px_session px + , gv$session s + , gv$px_process pp + , gv$session_wait sw + where px.sid = s.sid(+) + and px.serial# = s.serial#(+) + and px.inst_id = s.inst_id(+) + and px.sid = pp.sid(+) + and px.serial# = pp.serial#(+) + and sw.sid = s.sid + and sw.inst_id = s.inst_id +order by decode (px.QCINST_ID, null, px.INST_ID, px.QCINST_ID) + , px.QCSID + , decode (px.SERVER_GROUP, null, 0, px.SERVER_GROUP) + , px.SERVER_SET + , px.INST_ID +/ + + +column wait_event format a30 + +select sw.SID as RCVSID + , decode (pp.server_name, null, 'A QC', pp.server_name) as RCVR + , sw.inst_id as RCVRINST + , case sw.state when 'WAITING' then substr (sw.event, 1, 30) else null end as wait_event + , decode (bitand (p1, 65535), 65535, 'QC', 'P' || to_char (bitand (p1, 65535), 'fm000')) as SNDR + , bitand (p1, 16711680) + - 65535 + as SNDRINST + , decode (bitand (p1, 65535) + , 65535, ps.qcsid + , (select sid + from gv$px_process + where server_name = 'P' || to_char (bitand (sw.p1, 65535), 'fm000') + and inst_id = bitand (sw.p1, 16711680) + - 65535)) + as SNDRSID + , decode (sw.state, 'WAITING', 'WAIT', 'NOT WAIT') as STATE + from gv$session_wait sw, gv$px_process pp, gv$px_session ps + where sw.sid = pp.sid(+) + and sw.inst_id = pp.inst_id(+) + and sw.sid = ps.sid(+) + and sw.inst_id = ps.inst_id(+) + and p1text = 'sleeptime/senderid' + and bitand (p1, 268435456) = 268435456 +order by decode (ps.QCINST_ID, null, ps.INST_ID, ps.QCINST_ID) + , ps.QCSID + , decode (ps.SERVER_GROUP, null, 0, ps.SERVER_GROUP) + , ps.SERVER_SET + , ps.INST_ID +/ + + +column "Username" format a12 +column "QC/Slave" format A8 +column "Slaveset" format A8 +column "Slave INST" format A9 +column "QC SID" format A6 +column "QC INST" format A6 +column "operation_name" format A30 +column "target" format A30 + +select decode (px.qcinst_id + , null, username + , ' - ' + || lower (substr (pp.SERVER_NAME + , length (pp.SERVER_NAME) + - 4 + , 4))) + "Username" + , decode (px.qcinst_id, null, 'QC', '(Slave)') "QC/Slave" + , to_char (px.server_set) "SlaveSet" + , to_char (px.inst_id) "Slave INST" + , substr (opname, 1, 30) operation_name + , substr (target, 1, 30) target + , sofar + , totalwork + , units + , start_time + , timestamp + , decode (px.qcinst_id, null, to_char (s.sid), px.qcsid) "QC SID" + , to_char (px.qcinst_id) "QC INST" + from gv$px_session px, gv$px_process pp, gv$session_longops s + where px.sid = s.sid + and px.serial# = s.serial# + and px.inst_id = s.inst_id + and px.sid = pp.sid(+) + and px.serial# = pp.serial#(+) +order by decode (px.QCINST_ID, null, px.INST_ID, px.QCINST_ID) + , px.QCSID + , decode (px.SERVER_GROUP, null, 0, px.SERVER_GROUP) + , px.SERVER_SET + , px.INST_ID +/ + +ttitle off \ No newline at end of file diff --git a/parallel_dbms.sql b/parallel_dbms.sql new file mode 100644 index 0000000..d301afe --- /dev/null +++ b/parallel_dbms.sql @@ -0,0 +1,29 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: DBMS_PARALLEL chunks in work +--============================================================================== +set linesize 130 pagesize 300 + +ttitle left "DBMS_PARALLEL chunks in Work" skip 2 + +column "Chunks" format a20 +column Status format a20 + +select to_char (count (*)) as "Chunks", status + from dba_parallel_execute_chunks +group by status +/ + +ttitle left "DBMS_PARALLEL Errors" skip 2 + +column error_message format a100 + +select task_name + , status + , error_code + , error_message + from dba_parallel_execute_chunks + where error_message is not null +/ + +ttitle off \ No newline at end of file diff --git a/partition.sql b/partition.sql new file mode 100644 index 0000000..54fc81e --- /dev/null +++ b/partition.sql @@ -0,0 +1,30 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Analyse the partitions of the tables of a user +-- Parameter 1: Name of the User +-- in work +--============================================================================== +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +prompt +prompt Parameter 1 = Owner Name => &&USER_NAME. +prompt + +column owner format a12 heading "Owner" +column name format a30 heading "Name" +column object_type format a6 heading "Object|Type" +column column_name format a20 heading "Column|Name" +column column_position format 99 heading "Pos" + +-- dba_partition_columns +select c.owner + , c.name + , c.object_type + , c.column_name + , c.column_position + from dba_part_key_columns c +where c.owner like upper('&&USER_NAME.') +order by c.name,c.column_position +/ diff --git a/patch.sql b/patch.sql new file mode 100644 index 0000000..66fecbf --- /dev/null +++ b/patch.sql @@ -0,0 +1,20 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Patch info 12c +-- Date: November 2017 +-- +--============================================================================== + +set verify off +set linesize 130 pagesize 300 +set long 64000 + + + +select * + from dba_registry_sqlpatch +order by PATCH_ID +/ + + +-------------------------------------------------------------------------------- \ No newline at end of file diff --git a/pga.sql b/pga.sql new file mode 100644 index 0000000..d8dc66d --- /dev/null +++ b/pga.sql @@ -0,0 +1,76 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Informations about the pga usage in the database +-- Date: 08.2013 +-- +--============================================================================== +set linesize 130 pagesize 300 + +-- sga infos + +ttitle left "PGA DB Parameter" skip 2 + +show parameter pga_aggregate_target + +ttitle off + +show parameter workarea_size_policy +prompt +prompt ... must be "auto" for the use of the pga feature + +ttitle left "" skip 2 + +ttitle left "Sorts in Memory percentage" skip 2 +select round((mem.value/(mem.value+dsk.value))*100,2) "Sorts in Mem" + from v$sysstat mem, v$sysstat dsk +where mem.name='sorts (memory)' + and dsk.name='sorts (disk)' +/ + +ttitle left "PGA Usage" skip 2 + +select p.inst_id + , count(*) sess_cnt + , s.username + , round(sum(pga_used_mem/(1024*1024)),0) pga_used_mem_mb + , round(sum(pga_alloc_mem/(1024*1024)),0) pga_alloc_mem_mb + , round(sum(pga_freeable_mem/(1024*1024)),0) pga_freeable_mem_mb + , round(sum(pga_max_mem/(1024*1024)),0) pga_max_mem_mb + from gv$process p + , gv$session s +where p.addr=s.paddr + and p.inst_id = s.inst_id + and s.username is not null + and s.username not in ('SYS') +group by s.username + , p.inst_id +order by pga_alloc_mem_mb + , pga_used_mem_mb +/ + +column name format a38 +column inst_id format 99 +column value format 999G999G999G999G999 heading "Values" + +ttitle left "PGA Statistic" skip 2 +select inst_id + , name + , value + , unit + from gv$pgastat +order by inst_id,name +/ + +ttitle left "PGA Advisory" skip 2 + +column c1 heading 'PGA Target(M)' +column c2 heading 'Estimated|Cache Hit %' +column c3 heading 'Estimated|Over-Alloc.' + +select pga_target_for_estimate/(1024*1024) c1 + , estd_pga_cache_hit_percentage c2 + , estd_overalloc_count c3 + from v$pga_target_advice +/ + +ttitle off \ No newline at end of file diff --git a/plsql/create_default_plsql_user.sql b/plsql/create_default_plsql_user.sql new file mode 100644 index 0000000..f9ba1c0 --- /dev/null +++ b/plsql/create_default_plsql_user.sql @@ -0,0 +1,29 @@ +-- ============================ +-- Create a default user for plsql development +-- ============================ + +create user &&USERNAME. +identified by &&USERNAME.2013 + default tablespace USERS + temporary tablespace TEMP + profile DEFAULT +/ + +-- Grant/Revoke system privileges +grant unlimited tablespace to &&USERNAME. + + +-- Roles +-- +grant connect to &&USERNAME. +grant resource to &&USERNAME. + + +-- direct grants for pl/sql +-- +grant create view to &&USERNAME. +grant create table to &&USERNAME. +grant create sequence to &&USERNAME. + +-- Object grant in the database +-- \ No newline at end of file diff --git a/plsql/gpi_log.pkb b/plsql/gpi_log.pkb new file mode 100644 index 0000000..fab3cd8 --- /dev/null +++ b/plsql/gpi_log.pkb @@ -0,0 +1,149 @@ +CREATE OR REPLACE package body gpi_log as + +-- +============================================================================ +-- NAME: gpi_log +-- PURPOSE: Provides error monitoring functionality for procedures and functions +-- +-- +============================================================================ + + +-- +-- INTERNAL DECLARATIONS +-- + c_pck constant varchar2( 30 ) := 'gpi_log'; +-- +-- PROCEDURES +-- + +-- +=====================================================================+ +-- Server Side Trace with control of the output via Trace Level +-- The Trace views will be realised through the view v$session: +-- In the column ACTION the information . is visibale +-- In the column CLIENT_INFO runtime information +-- If a error occured: CLIENT_INFO = error code +-- Trace-Level +-- Level = 1 : Exception occourd +-- Level = 2 : Start, Ende of a Routine +-- Level = 3 : Steps in a Routine +-- +=====================================================================+ + + procedure trace_line( + p_routine_name in varchar2 + , p_trace_level in number + , p_trace_msg in varchar2 + , p_used_ids in varchar2 default null + ) + is + c_routine_name constant varchar2( 50 ) := c_pck || '.trace_line '; + -- + begin + -- + -- Ist trace eingeschaltet ? + if gpi_log.c_trace_on then + -- setzen Aktion=Routine + DBMS_APPLICATION_INFO.set_action( p_routine_name ); + -- setzen Client Info + DBMS_APPLICATION_INFO.set_client_info( SUBSTR( SUBSTR( p_trace_msg, 1, gpi_log.c_message_offset ) || p_used_ids + , 1 + , 64 + ) + ); + end if; + -- + exception + when others then + gpi_log.seterror( p_message => 'Error trace Client ' || p_routine_name || ' :: ' || p_routine_name + , p_modul => c_routine_name + ); + end trace_line; + + +-- +=====================================================================+ +-- seterror +-- fill error table +-- +=====================================================================+ + + procedure seterror( + p_message varchar2 + , p_modul varchar2 + ) + as + pragma autonomous_transaction; + + v_sqlcode varchar2( 255 ) := SQLCODE; + v_sqlerrm varchar2( 2000 ) := SQLERRM; + v_sql_text varchar2(2000); + begin + -- using dynamic sql -table may not exists at package creation time + v_sql_text:=' insert into gpi$logerrors + ( errorid + , code + , modul + , text + , error_time + ) + values ( seq_gpi$logerrors.nextval + , :1 + , :2 + , :3 + , sysdate + )'; + + execute immediate v_sql_text using v_sqlcode, p_modul, p_message; + + commit; + + end seterror; + +-- +=====================================================================+ +-- create_error_tab +-- create the error tab +-- +=====================================================================+ + + procedure create_error_tab + as + + v_sql_tab1 varchar2(2000):='create table gpi$logerrors ( + errorid number(19) + , code varchar(8) + , modul varchar2(120) + , text varchar2(4000) + , error_time date default sysdate + )'; + + v_sql_tab2 varchar2(2000):='create unique index idx_gpi$logerrors_pk on gpi$logerrors(errorid)'; + + v_sql_tab3 varchar2(2000):='alter table gpi$logerrors add constraint pk_gpi$logerrors primary key (errorid) enable validate'; + + v_sql_seq varchar2(1000):='create sequence seq_gpi$logerrors'; + + v_count pls_integer; + + begin + + -- check if table exists + select count(*) into v_count from user_tables where table_name = 'GPI$LOGERRORS' ; + + -- create the error log table + if v_count < 1 then + execute immediate v_sql_tab1; + execute immediate v_sql_tab2; + execute immediate v_sql_tab3; + end if; + + -- check for the sequence + select count(*) into v_count from user_sequences where sequence_name = 'SEQ_GPI$LOGERRORS' ; + if v_count < 1 then + execute immediate v_sql_seq; + end if; + + end create_error_tab; + +begin + -- check at start-up of package if error table exists + -- if not create the table and the sequence + gpi_log.create_error_tab; + +end gpi_log; +/ + diff --git a/plsql/gpi_log.pks b/plsql/gpi_log.pks new file mode 100644 index 0000000..aa138cd --- /dev/null +++ b/plsql/gpi_log.pks @@ -0,0 +1,71 @@ +CREATE OR REPLACE package gpi_log as + +-- +============================================================================ +-- NAME: gpi_log +-- PURPOSE: Provides error monitoring functionality for procedures and functions +-- +-- +============================================================================ + + -- constant for Error code (Routine return value) + c_ok constant number( 1 ) := 0; + c_fatal_error constant number( 1 ) := -1; + c_validation_error constant number( 1 ) := -2; + + -- constant for raise_application_error + c_application_error constant number( 5 ) := -20000; + + -- Error message offset + c_message_offset constant number( 2 ) := 11; + + -- constant for character flags + c_true constant varchar2( 1 ) := 'T'; + c_false constant varchar2( 1 ) := 'F'; + + -- constant for Yes/No-Flag + c_yes constant varchar2( 1 ) := 'Y'; + c_no constant varchar2( 1 ) := 'N'; + + -- constant fuer standard trace level (used in exception handler tracing) + c_trace_lvl_1 constant number( 1 ) := 1; + c_trace_lvl_2 constant number( 1 ) := 2; + c_trace_lvl_3 constant number( 1 ) := 3; + + -- standard trace schalter ein/aus + c_trace_on constant boolean := true; + + -- constant for Identifikation from DML-statement + c_dml_statement_insert constant varchar2( 3 ) := 'INS'; + c_dml_statement_update constant varchar2( 3 ) := 'UPD'; + c_dml_statement_delete constant varchar2( 3 ) := 'DEL'; + + -- variable for error-messages + v_errcode NUMBER; + v_errmsg VARCHAR2(1000); + v_errtrc VARCHAR2(1000); + +-- +=====================================================================+ +-- Error monitoring +-- +=====================================================================+ + procedure seterror( + p_message varchar2 + , p_modul varchar2 + ); + +-- +=====================================================================+ +-- tracing with the v$session view +-- +=====================================================================+ + procedure trace_line( + p_routine_name in varchar2 + , p_trace_level in number + , p_trace_msg in varchar2 + , p_used_ids in varchar2 default null + ); + + +-- +=====================================================================+ +-- create the error log tab +-- +=====================================================================+ +procedure create_error_tab; + +END gpi_log; +/ \ No newline at end of file diff --git a/plsql/gpi_template.pkb b/plsql/gpi_template.pkb new file mode 100644 index 0000000..8cf67d2 --- /dev/null +++ b/plsql/gpi_template.pkb @@ -0,0 +1,44 @@ +create or replace package body gpi$template is + + -- +===========================================================+ + -- Procedure : procedure one + -- +===========================================================+ + procedure one; + is + v_routine_name VARCHAR2 (50) := g_pck || '.one'; + + begin + gpi_log.trace_line (v_routine_name, gpi_log.c_trace_lvl_2, 'proc start'); + + -- do something + + gpi_log.trace_line (v_routine_name, gpi_log.c_trace_lvl_2, 'proc end'); + + exception + when ex_emerrors + then + raise_application_error (-20100, g_emerrors); + when others + then + gpi_log.v_errcode := gpi_log.c_application_error; + gpi_log.v_errmsg := + '@' + || v_routine_name + || ': ' + || sqlerrm; + gpi_log.v_errtrc := sqlerrm; + + gpi_log.seterror (p_message => gpi_log.v_errmsg, p_modul => v_routine_name); + + gpi_log.trace_line (v_routine_name, gpi_log.c_trace_lvl_1, gpi_log.v_errtrc); + raise_application_error (-20100, g_emerrors|| gpi_log.v_errmsg); + + end one; + +begin + + -- Initialization + null; + +end gpi$template ; +/ diff --git a/plsql/gpi_template.pks b/plsql/gpi_template.pks new file mode 100644 index 0000000..1711414 --- /dev/null +++ b/plsql/gpi_template.pks @@ -0,0 +1,25 @@ +create or replace package gpi$template is + +-- +============================================================================ +-- NAME: gpi$template +-- PURPOSE: template for new packages +-- +-- +============================================================================ + + -- exception handling + g_pck CONSTANT VARCHAR2 (30) := 'gpi$template'; + + EX_GPERRORS EXCEPTION; + PRAGMA EXCEPTION_INIT (EX_GPERRORS, -20100); + g_emerrors VARCHAR2 (100) := 'An error occured. Please view the ERRORS-table for more information.'; + + -- global variables + + + -- +===========================================================+ + -- Procedure : procedure one + -- +===========================================================+ + procedure one; + +end gpi$template; +/ diff --git a/plsql/kill_other_sesion_as_normal_user.prc b/plsql/kill_other_sesion_as_normal_user.prc new file mode 100644 index 0000000..749b20e --- /dev/null +++ b/plsql/kill_other_sesion_as_normal_user.prc @@ -0,0 +1,141 @@ +create or replace procedure kill_other_session( p_sid in number + , p_serial# in number + , p_inst_id in number default null + , p_comment in varchar2 default null + +) +AUTHID DEFINER + +-- ============================================================= +-- Procedure kill_other_session +-- Kill as normal user a session in the oracle database over this procedure +-- User need no special rights to execute this procedure +-- +-- grant rights over role: +-- create role kill_other_session; +-- grant execute on kill_other_session to kill_other_session; +-- grant kill_other_session to ; +-- ============================================================= + +is + + v_user varchar2(512); + v_kill_message varchar2(4000); + + v_sql sys.dbms_sql.varchar2a; + v_cursor number; + v_result pls_integer; + v_sys_user_id number; + +begin + + -- get the sys user id + select user_id into v_sys_user_id + from sys.all_users + where username = 'SYS'; + + + -- get user and remember some details + -- to help to identif the user + v_user :=sys_context('userenv','SESSION_USER') + ||' from the PC '||sys_context('userenv','OS_USER') + ||'('||sys_context('userenv','TERMINAL')||')'; + + + v_kill_message:='User '|| v_user + ||' try to initiate a kill with sys.kill_other_session of this session :: SID:'||p_sid + ||', Serial:'||p_serial# + ||' - InstID:'||nvl(p_inst_id,userenv('instance')) + ||' - Comment:'||nvl(p_comment,'n/a'); + + -- log the kill into the alert file of the database + sys.dbms_system.ksdwrt ( sys.dbms_system.alert_file, '-- Info : '||v_kill_message); + + -- show output + dbms_output.put_line('-- Info : ----------------------------'); + dbms_output.put_line('-- Info : '||v_kill_message ); + + + -- check for RAC + -- check if the session exists + -- and if the session is not a DB Prozess ( BACKGROUND session!) + -- to avoid chrash of the instance! + if p_inst_id is null then + for rec in ( select 'x' + from sys.gv_$session + where sid = p_sid + and serial# = p_serial# + and inst_id = userenv('instance') + and type != 'BACKGROUND') + loop + v_sql(1) := 'alter system kill session ''' || p_sid || ',' || p_serial# || ''''; + end loop; + else + for rec in ( select 'x' + from sys.gv_$session + where sid = p_sid + and serial# = p_serial# + and inst_id = p_inst_id + and type != 'BACKGROUND') + loop + v_sql(1) := 'alter system kill session ''' || p_sid || ',' || p_serial# || ',@' || p_inst_id || ''''; + end loop; + end if; + + -- check if we found the session + if v_sql.count > 0 then + + -- execute the kill command: + + -- get cursor + v_cursor := sys.dbms_sys_sql.open_cursor; + + -- parse the statement + sys.dbms_sys_sql.parse_as_user ( + c => v_cursor + , statement => v_sql + , lb => 1 + , ub => v_sql.count + , lfflg => true + , language_flag => sys.dbms_sys_sql.native + , userid => v_sys_user_id ); + + -- exectute + v_result := sys.dbms_sys_sql.execute(v_cursor); + + -- close the cursor + sys.dbms_sys_sql.close_cursor( v_cursor ); + + dbms_output.put_line('-- Info : Kill of the session is requested - please check status of the session'); + sys.dbms_system.ksdwrt ( sys.dbms_system.alert_file, '-- Info ::kill Session with kill_other_session initiated'); + + else + dbms_output.put_line('-- Error: ----------------------------'); + dbms_output.put_line('-- Error: Session to kill not found or is BACKGROUND session!' ); + dbms_output.put_line('-- Error: ----------------------------'); + sys.dbms_system.ksdwrt ( sys.dbms_system.alert_file, '-- Info : kill Session to kill not extis or is BACKGROUND session (not allowed!)'); + end if; + + + dbms_output.put_line('-- Info : ----------------------------'); +exception + + when others then + + -- check for open cursor + if sys.dbms_sys_sql.is_open(v_cursor) then + sys.dbms_sys_sql.close_cursor(v_cursor); + end if; + + dbms_output.put_line('-- Error: ----------------------------'); + dbms_output.put_line('-- Error: Message :: '||SQLERRM ); + dbms_output.put_line('-- Error: ----------------------------'); + + -- log this error also to the alert log + sys.dbms_system.ksdwrt ( sys.dbms_system.alert_file, '-- Error: kill Session with sys.kill_other_session fails with ::'||SQLERRM); + + raise; + +end kill_other_session; + + diff --git a/plsql/recompile_all.prc b/plsql/recompile_all.prc new file mode 100644 index 0000000..58e2909 --- /dev/null +++ b/plsql/recompile_all.prc @@ -0,0 +1,28 @@ +create or replace procedure recompileAll as + cursor c_objects is + select owner + ,object_name + ,object_type + from dba_objects + where status != 'VALID' + and object_type != 'MATERIALIZED VIEW'; + + v_sql_template varchar2(255) := 'alter ##OBJECTTYPE## ##OWNER##.##OBJECT_NAME## compile'; + v_sql varchar2(512); +begin + + for rec in c_objects + loop + v_sql := replace(v_sql_template, '##OBJECTTYPE##', replace(rec.object_type,'BODY','')); + v_sql := replace(v_sql, '##OWNER##', rec.owner); + v_sql := replace(v_sql, '##OBJECT_NAME##', rec.object_name); + + dbms_output.put_line('-- Info -- call SQL ::' || v_sql); + begin + execute immediate v_sql; + exception + when others then + dbms_output.put_line('-- Info -- call SQL ::' || v_sql || 'Error ::' || sqlerrm); + end; + end loop; +end; \ No newline at end of file diff --git a/plsql_ddl.sql b/plsql_ddl.sql new file mode 100644 index 0000000..8cefa32 --- /dev/null +++ b/plsql_ddl.sql @@ -0,0 +1,101 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: spool a pl/sql object +-- Must be run with dba privileges +--============================================================================== +set verify off +set linesize 300 pagesize 4000 +set trimspool on + +define OWNER = '&1' +define PACKAGE_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Package Name => &&PACKAGE_NAME. +prompt + +col SPOOL_NAME_COL new_val SPOOL_NAME + +select replace (ora_database_name || '_' || to_char (sysdate, 'dd_mm_yyyy_hh24_mi') || '_&&OWNER._&&PACKAGE_NAME..sql', '\', '_') + --' resolve syntax highlight bug FROM my editer .-( + as SPOOL_NAME_COL + from dual +/ + +variable ddllob clob + +set heading off +set echo off + +set long 1000000; + +declare + cursor c_tab_obj + is + select object_name, replace (object_type, ' ', '_') as object_type, owner + from dba_objects + where object_name = upper ('&&PACKAGE_NAME.') + and OWNER = upper ('&&OWNER.') + order by object_type; +begin +-- set the transformation attributes + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'OID', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SEGMENT_ATTRIBUTES', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'TABLESPACE', true ); + + -- + :ddllob := '-- create the DLL for the Object &&OWNER..&&PACKAGE_NAME.'; + + -- get the DDL for this object + for rec in c_tab_obj + loop + :ddllob := :ddllob || chr (10) || chr (10) || '-- DDL for Object : ' || rec.object_name || chr (10); + :ddllob := :ddllob || dbms_metadata.get_ddl (rec.object_type, rec.object_name, rec.owner); + end loop; + + :ddllob := :ddllob || chr (10) || chr (10) || '-- DDL for Grants : ' || chr (10); + + begin + :ddllob := :ddllob || dbms_metadata.GET_DEPENDENT_DDL ('OBJECT_GRANT', upper ('&&PACKAGE_NAME.'), upper ('&&OWNER.')); + exception + when others + then + :ddllob := :ddllob || chr (10) || chr (10) || '-- NO DDL for Grants found : ' || sqlerrm || chr (10); + end; +end; +/ + +spool &&SPOOL_NAME + +column ddllob format a350 word_wrapped + +print ddllob + +spool off + +undefine ddllob + +set heading on + + +----------- +-- OLD Version +-- column command format a300 WORD_WRAPPED +-- +-- set pagesize 0 +-- set long 90000 +-- SELECT DBMS_METADATA.GET_DDL('PACKAGE_BODY','&&PACKAGE_NAME.',upper('&&OWNER.')) as command FROM dual +-- / +-- +-- set pagesize 0 +-- set long 90000 +-- SELECT DBMS_METADATA.GET_DDL('PACKAGE','&&PACKAGE_NAME.',upper('&&OWNER.')) as command FROM dual +-- / + +prompt ... +prompt check &&SPOOL_NAME for the sql +prompt .. diff --git a/plsql_depend.sql b/plsql_depend.sql new file mode 100644 index 0000000..f76cfd8 --- /dev/null +++ b/plsql_depend.sql @@ -0,0 +1,48 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: On which objects this pl/sql code depends +--============================================================================== +set verify off +set linesize 130 pagesize 300 +set trimspool on + +define OWNER = '&1' +define PACKAGE_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Package Name => &&PACKAGE_NAME. +prompt + +column referenced_name format a28 +column referenced_owner format a20 +column status format a10 heading "Status" + +select d.referenced_owner + , d.referenced_name + , d.referenced_type + , o.last_ddl_time + , o.status + from dba_dependencies d + , dba_objects o +where d.name = upper('&&PACKAGE_NAME.') + and d.owner = upper('&&OWNER.') + and o.owner=d.referenced_owner + and o.object_type=d.referenced_type + and o.object_name=d.referenced_name +order by + d.referenced_owner + , d.referenced_name + , d.referenced_type +/ + + +-- +--column hirachie format a40 +-- +--SELECT RPAD (' ', 3*(LEVEL-1)) || d.referenced_name || ' (' || d.type || ') ' as hirachie +-- FROM dba_dependencies d +--CONNECT BY PRIOR RTRIM( d.name || d.owner) = RTRIM(d.referenced_name || d.referenced_owner) +-- START WITH name = upper('&&PACKAGE_NAME.') AND owner = upper('&&OWNER.') +--/ +-- diff --git a/plsql_depend_on.sql b/plsql_depend_on.sql new file mode 100644 index 0000000..9fbcc4e --- /dev/null +++ b/plsql_depend_on.sql @@ -0,0 +1,37 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Which objects depends on this pl/sql code +--============================================================================== +set verify off +set linesize 130 pagesize 300 +set trimspool on + +define OWNER = '&1' +define PACKAGE_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Package Name => &&PACKAGE_NAME. +prompt + +column referenced_name format a28 +column referenced_owner format a20 +column status format a10 heading "Status" + +select d.owner + , d.name + , o.object_type + , o.last_ddl_time + , o.status + from dba_dependencies d + , dba_objects o +where d.referenced_name = upper('&&PACKAGE_NAME.') + and d.referenced_owner = upper('&&OWNER.') + and o.owner=d.referenced_owner + and o.object_type=d.referenced_type + and o.object_name=d.referenced_name +order by + d.referenced_owner + , d.referenced_name + , d.referenced_type +/ diff --git a/plsql_errors.sql b/plsql_errors.sql new file mode 100644 index 0000000..3523e4e --- /dev/null +++ b/plsql_errors.sql @@ -0,0 +1,25 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the errors in the database +-- Must be run with dba privileges +--============================================================================== +set verify off +set linesize 130 pagesize 300 +set trimspool on + +column owner format a30 heading "Owner" +column name format a30 heading "Object|Name" +column type format a20 heading "Object|Type" +column line format 9G999 heading "Line|No." +column text format a100 heading "Error Message" fold_before WORD_WRAPPED NEWLINE + +select owner + , name + , type + , line + , text +from dba_errors +order by owner + , name + , line +/ diff --git a/plsql_info.sql b/plsql_info.sql new file mode 100644 index 0000000..c7525dd --- /dev/null +++ b/plsql_info.sql @@ -0,0 +1,81 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show more informations about a plsql object +-- Must be run with DBA privileges +--============================================================================== +-- http://docs.oracle.com/cd/B28359_01/server.111/b28320/statviews_2009.htm#REFRN20385 +-- http://docs.oracle.com/cd/B28359_01/server.111/b28320/statviews_2013.htm#REFRN20168 +-- http://www.oracle.com/technetwork/issue-archive/2012/12-nov/o62plsql-1851968.html +-- http://docs.oracle.com/cd/E16655_01/network.121/e17607/dr_ir.htm#DBSEG658 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OBJ_NAME = '&1' + +prompt +prompt Parameter 1 = PLSQL NAME => &&OBJ_NAME. +prompt + +column owner format a15 +column name format a15 +column type format a12 +column plsql_optimize_level format 99 heading "OL" +column plsql_code_type format a12 heading "Code|Type" +column plsql_debug format a8 heading "Debug" +column plsql_warnings format a15 heading "Warn" +column nls_length_semantics format a15 +column plsql_ccflags format a10 heading "CC Flag" +column plscope_settings format a18 + +select + owner + , name + , type + , plsql_optimize_level + , plsql_code_type + , plsql_debug + , plsql_warnings + --, nls_length_semantics + , plsql_ccflags + , plscope_settings + from dba_plsql_object_settings +where NAME like upper('&&OBJ_NAME.'); + +column object_name format a20 +column procedure_name format a20 +column overload format a20 +column object_type format a20 +column impltypeowner format a20 +column impltypename format a20 +column authid format a20 + +select owner + , OBJECT_NAME + , PROCEDURE_NAME + --, OVERLOAD + , OBJECT_TYPE + --,AGGREGATE + --,PIPELINED + --,IMPLTYPEOWNER + --,IMPLTYPENAME + --,PARALLEL + --,INTERFACE + , DETERMINISTIC + , AUTHID + from dba_procedures +where object_name like upper('&&OBJ_NAME.') +/ + +prompt ... AUTHID - Indicates whether the procedure/function is declared to execute as DEFINER or CURRENT_USER (invoker) + +select owner +-- , subobject_name + , object_type + , to_char(created,'dd.mm.yyyy hh24:mi') as created + , to_char(last_ddl_time,'dd.mm.yyyy hh24:mi') as last_ddl_time + , timestamp + , status +from dba_objects +where OBJECT_NAME like upper('&&OBJ_NAME.') +/ diff --git a/plsql_running.sql b/plsql_running.sql new file mode 100644 index 0000000..d3167ea --- /dev/null +++ b/plsql_running.sql @@ -0,0 +1,71 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: actual running pl/sql in the database +-- Date: Februar 2018 +--============================================================================== +set verify off +set linesize 140 pagesize 300 + +ttitle left "All running PL/SQL at the moment" skip 2 + +column inst_id format 99 heading "Inst|ID" +column username format a12 heading "DB User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column machine format a15 heading "Remote|pc/server" +column terminal format a14 heading "Remote|terminal" +column program format a15 heading "Remote|program" +column module format a16 heading "Remote|module" +column client_info format a10 heading "Client|info" +column client_identifier format a10 heading "Client|identifier" +column OSUSER format a13 heading "OS|User" +column LOGON_TIME format a12 heading "Logon|Time" +column status format a8 heading "Status" + + + +select 'Top PL/SQL' + ,s.username + ,o.object_name + ,inst_id + ,s.sid + ,s.serial# + ,s.status + ,s.osuser + from dba_objects o inner join gv$session s on (o.object_id = s.plsql_entry_object_id) +union all +select 'Current PL/SQL' ,s.username + ,o.object_name + ,inst_id + ,s.sid + ,s.serial# + ,s.status + ,s.osuser + from dba_objects o inner join gv$session s on (o.object_id = s.plsql_object_id) +union all +select 'Top sub programm PL/SQL' ,s.username + ,o.object_name + ,inst_id + ,s.sid + ,s.serial# + ,s.status + ,s.osuser + from dba_objects o inner join gv$session s on (o.object_id = s.PLSQL_SUBPROGRAM_ID) +union all +select 'Current sub program PL/SQL' ,s.username + ,o.object_name + ,inst_id + ,s.sid + ,s.serial# + ,s.status + ,s.osuser + from dba_objects o inner join gv$session s on (o.object_id = s.PLSQL_ENTRY_SUBPROGRAM_ID) + +/ + +ttitle off + +-- PLSQL_ENTRY_OBJECT_ID - Object ID of the top-most PL/SQL subprogram on the stack; NULL if there is no PL/SQL subprogram on the stack +-- PLSQL_ENTRY_SUBPROGRAM_ID - Subprogram ID of the top-most PL/SQL subprogram on the stack; NULL if there is no PL/SQL subprogram on the stack +-- PLSQL_OBJECT_ID - Object ID of the currently executing PL/SQL subprogram; NULL if executing SQL +-- PLSQL_SUBPROGRAM_ID - Subprogram ID of the currently executing PL/SQL object; NULL if executing SQL diff --git a/plsql_search.sql b/plsql_search.sql new file mode 100644 index 0000000..2456f15 --- /dev/null +++ b/plsql_search.sql @@ -0,0 +1,56 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: search for a plsql function/procedure also in packages - parameter Search String +--============================================================================== +set linesize 130 pagesize 300 + +column object_name format a25 +column procedure_name format a25 +column overload format a20 +column object_type format a20 +column impltypeowner format a20 +column impltypename format a20 +column authid format a20 + + +define OBJ_NAME = '&1' + +prompt +prompt Parameter 1 = PLSQL NAME => &&OBJ_NAME. +prompt + + +select owner + , OBJECT_NAME + , PROCEDURE_NAME + --, OVERLOAD + , OBJECT_TYPE + --,AGGREGATE + --,PIPELINED + --,IMPLTYPEOWNER + --,IMPLTYPENAME + --,PARALLEL + --,INTERFACE + , DETERMINISTIC + , AUTHID + from dba_procedures +where object_name like upper('&&OBJ_NAME.') +/ + + +select owner + , OBJECT_NAME + , PROCEDURE_NAME + --, OVERLOAD + , OBJECT_TYPE + --,AGGREGATE + --,PIPELINED + --,IMPLTYPEOWNER + --,IMPLTYPENAME + --,PARALLEL + --,INTERFACE + , DETERMINISTIC + , AUTHID + from dba_procedures +where PROCEDURE_NAME like upper('&&OBJ_NAME.') +/ \ No newline at end of file diff --git a/plsql_usage.sql b/plsql_usage.sql new file mode 100644 index 0000000..2a67ccd --- /dev/null +++ b/plsql_usage.sql @@ -0,0 +1,38 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Which objects depends on this pl/sql code +--============================================================================== +set verify off +set linesize 130 pagesize 300 +set trimspool on + +-- v$sql has it, program_id is the object_id of the plsql routine. + + +column owner format a20 +column object_type format a20 heading "Object|Type" +column object_name format a30 heading "Object|Name" +column min_first_load format a18 +column max_first_load format a18 + + +select count(*) + , obj.owner + , obj.object_type + , obj.object_name + --, s.PROGRAM_LINE# + --, obj.subobject_name + , min(to_date(s.first_load_time,'YYYY-MM-DD/HH24:MI:SS')) as min_first_load + , max(to_date(s.first_load_time,'YYYY-MM-DD/HH24:MI:SS')) as max_first_load + from dba_objects obj + , v$sql s + where s.program_id = obj.object_id + and s.program_id != 0 + group by obj.owner + , obj.object_type + , obj.object_name + , obj.subobject_name + -- , s.PROGRAM_LINE# + -- , obj.subobject_name +order by obj.owner +/ diff --git a/process.sql b/process.sql new file mode 100644 index 0000000..779b5fd --- /dev/null +++ b/process.sql @@ -0,0 +1,81 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Process List of Oracle sessions +-- Date: 01.September 2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 +define ALL_PROCESS = '&2' + +prompt +prompt Parameter 1 = Username => &&USER_NAME. +prompt Parameter 2 = to Show all use Y => &&ALL_PROCESS. +prompt + +ttitle left "Process List of the Oracle Sessions" skip 2 + +column process_id format a8 heading "Process|ID" +column inst_id format 99 heading "Inst|ID" +column username format a8 heading "DB User|name" +column osusername format a8 heading "OS User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column machine format a14 heading "Remote|pc/server" +column terminal format a14 heading "Remote|terminal" +column program format a17 heading "Remote|program" +column module format a15 heading "Remote|module" +column client_info format a15 heading "Client|info" +column pname format a8 heading "Process|name" +column tracefile format a20 heading "Trace|File" + + select p.inst_id + , to_char (p.spid) as process_id + , vs.sid + , vs.serial# + , nvl (vs.username, 'n/a') as username + , vs.status + , p.username as osusername + , p.pname + , vs.machine + --, p.terminal + , vs.module + , vs.program + , vs.client_info + --, substr(p.tracefile,length(p.tracefile)-REGEXP_INSTR(reverse(p.tracefile),'[\/|\]')+2,1000) as tracefile + --, p.tracefile + --, vs.CREATOR_ADDR + --, vs.CREATOR_SERIAL# + from gv$session vs, gv$process p + where vs.paddr = p.addr + and vs.inst_id = p.inst_id + and ( vs.username like '%&&USER_NAME.%' + or ( nvl ('&ALL_PROCESS.', 'N') = 'Y' + and vs.username is null)) +order by vs.username, p.inst_id, p.spid +/ + +ttitle left "Trace File Locations" skip 2 + +column full_trace_file_loc format a100 heading "Trace|File" + + select p.inst_id, to_char (p.spid) as process_id, p.tracefile as full_trace_file_loc + from gv$session vs, gv$process p + where vs.paddr = p.addr + and vs.inst_id = p.inst_id + and ( vs.username like '%&&USER_NAME.%' + or ( nvl ('&ALL_PROCESS.', 'N') = 'Y' + and vs.username is null)) +order by vs.username, p.inst_id +/ + +prompt +prompt ... to enable trace use "oradebug SETOSPID " +prompt +prompt ... to kill session "ALTER SYSTEM KILL SESSION 'sid,serial#,@inst_id';" +prompt ... to end session "ALTER SYSTEM DISCONNECT SESSION 'sid,serial#' IMMEDIATE;" +prompt + +ttitle off \ No newline at end of file diff --git a/process_get.sql b/process_get.sql new file mode 100644 index 0000000..b53be47 --- /dev/null +++ b/process_get.sql @@ -0,0 +1,73 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Process of Oracle sessions +-- Date: 01.September 2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define PID = &1 + +prompt +prompt Parameter 1 = PID => &&PID + +prompt + +ttitle left "Process List of the Oracle Sessions" skip 2 + +column process_id format a8 heading "Process|ID" +column inst_id format 99 heading "Inst|ID" +column username format a8 heading "DB User|name" +column osusername format a8 heading "OS User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column machine format a14 heading "Remote|pc/server" +column terminal format a14 heading "Remote|terminal" +column program format a17 heading "Remote|program" +column module format a15 heading "Remote|module" +column client_info format a15 heading "Client|info" +column pname format a8 heading "Process|name" +column tracefile format a20 heading "Trace|File" + +select p.inst_id + , to_char (p.spid) as process_id + , vs.sid + , vs.serial# + , nvl (vs.username, 'n/a') as username + , p.username as osusername + , p.pname + , vs.machine + --, p.terminal + , vs.module + , vs.program + , vs.client_info + --, substr(p.tracefile,length(p.tracefile)-REGEXP_INSTR(reverse(p.tracefile),'[\/|\]')+2,1000) as tracefile + --, p.tracefile + , vs.sql_id + from gv$session vs, gv$process p + where vs.paddr = p.addr + and vs.inst_id = p.inst_id + and p.spid = &&PID +order by vs.username, p.inst_id +/ + +ttitle left "Trace File Locations" skip 2 +column full_trace_file_loc format a100 heading "Trace|File" + + select p.inst_id, to_char (p.spid) as process_id, p.tracefile as full_trace_file_loc + from gv$session vs, gv$process p + where vs.paddr = p.addr + and vs.inst_id = p.inst_id + and p.spid = &&PID +order by vs.username, p.inst_id +/ + +prompt +prompt ... to enable trace use "oradebug SETOSPID " +prompt +prompt ... to kill session "ALTER SYSTEM KILL SESSION 'sid,serial#,@inst_id';" +prompt ... to end session "ALTER SYSTEM DISCONNECT SESSION 'sid,serial#' IMMEDIATE;" +prompt + +ttitle off diff --git a/profile.sql b/profile.sql new file mode 100644 index 0000000..f601970 --- /dev/null +++ b/profile.sql @@ -0,0 +1,42 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the profiles of the database +-- Date: September 2013 +-- +--============================================================================== +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +column PROFILE format a26 heading "Profil" +column RESOURCE_NAME format a25 heading "Resource Name" +column RESOURCE_TYPE format a10 heading "Resourcen | Type" +column LIMIT format a20 heading "Limit" + +select PROFILE + , RESOURCE_NAME + , RESOURCE_TYPE + , LIMIT + from dba_profiles +order by PROFILE,RESOURCE_TYPE +/ + +prompt ... +prompt ... example to change: "ALTER PROFILE DEFAULT LIMIT FAILED_LOGIN_ATTEMPTS 50 PASSWORD_LIFE_TIME UNLIMITED;" +prompt ... + +ttitle left "Which Profile is in user" skip 2 + +column username format a24 heading "User Name" +column account_status format a20 heading "Status" + +select username + , profile + , account_status + from dba_users +order by profile,account_status +/ + +ttitle off + +prompt ... to set the profile of the user: alter user profile ; \ No newline at end of file diff --git a/proxy.sql b/proxy.sql new file mode 100644 index 0000000..791e677 --- /dev/null +++ b/proxy.sql @@ -0,0 +1,36 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the proxy user settings +-- Date: Oktober 2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +prompt +prompt Parameter 1 = User Name => &&USER_NAME. +prompt + +ttitle left "Proxy Settings for this database" skip 2 + +column proxy format a15 heading "Proxy" +column client format a15 heading "Client|User" +column authentication format a5 heading "Auth" +column authorization_constraint format a40 heading "Auth|Const" +column role format a15 heading "Role" +column proxy_authority format a10 heading "Proxy|Auth" + +select proxy + , client + , authentication + , authorization_constraint + , role + , proxy_authority + from dba_proxies +where proxy like upper('&&USER_NAME.') +order by 1 +/ + +ttitle off diff --git a/proxy_client.sql b/proxy_client.sql new file mode 100644 index 0000000..8bd0e01 --- /dev/null +++ b/proxy_client.sql @@ -0,0 +1,36 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the proxy user settings +-- Date: Oktober 2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +prompt +prompt Parameter 1 = User Name => &&USER_NAME. +prompt + +ttitle left "Proxy Settings for this database" skip 2 + +column proxy format a15 heading "Proxy" +column client format a15 heading "Client|User" +column authentication format a5 heading "Auth" +column authorization_constraint format a40 heading "Auth|Const" +column role format a15 heading "Role" +column proxy_authority format a10 heading "Proxy|Auth" + +select proxy + , client + , authentication + , authorization_constraint + , role + , proxy_authority + from dba_proxies +where client like upper('&&USER_NAME.') +order by 1 +/ + +ttitle off diff --git a/proxy_to.sql b/proxy_to.sql new file mode 100644 index 0000000..a95e4fa --- /dev/null +++ b/proxy_to.sql @@ -0,0 +1,36 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: All schemas that can be switch to this schema with proxy rights - parameter 1 name of the schema +-- Date: March 2018 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +prompt +prompt Parameter 1 = Schema Name => &&USER_NAME. +prompt + +ttitle left "How can switch to this schema with Proxy rights" skip 2 + +column proxy format a15 heading "Proxy" +column client format a15 heading "Schema|User" +column authentication format a5 heading "Auth" +column authorization_constraint format a40 heading "Auth|Const" +column role format a15 heading "Role" +column proxy_authority format a10 heading "Proxy|Auth" + +select client + , proxy + , authentication + , authorization_constraint + , role + , proxy_authority + from dba_proxies +where client like upper('&&USER_NAME.') +order by 1 +/ + +ttitle off diff --git a/reco.sql b/reco.sql new file mode 100644 index 0000000..028f252 --- /dev/null +++ b/reco.sql @@ -0,0 +1,45 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Recovery Area settings and size +-- Date: 01.September 2012 +-- +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Report Recovery Dest Parameter" SKIP 1 - + center "Sizes in MB" SKIP 2 + +archive log list + +show parameter reco + +column limit format a14 +column used format a14 +column reclaimable format a14 +column number_of_files format a6 heading "Files" +column used format a12 + +select to_char(round(SPACE_LIMIT / 1024 / 1024, 2)) || ' M Limit' as limit + ,to_char(round(SPACE_USED / 1024 / 1024, 2)) || ' M in Use' as used + ,to_char(round(SPACE_RECLAIMABLE / 1024 / 1024, 2)) || ' M' as RECLAIMABLE + ,to_char(NUMBER_OF_FILES) as NUMBER_OF_FILES + ,to_char(round((SPACE_USED * 100) / SPACE_LIMIT, 2), '909D00')||' %' as Used + from V$RECOVERY_FILE_DEST +/ + +ttitle "Report if Archvelogs can be deleted" SKIP 1 - + +SELECT applied + , deleted + , decode(rectype,11,'YES','NO') AS reclaimable + , COUNT(*) + , MIN(SEQUENCE#) + , MAX(SEQUENCE#) + FROM v$archived_log LEFT OUTER JOIN sys.x$kccagf USING(recid) +WHERE is_recovery_dest_file='YES' AND name IS NOT NULL +GROUP BY applied,deleted,decode(rectype,11,'YES','NO') ORDER BY 5 +/ + +prompt ... rman setting see CONFIGURE ARCHIVELOG DELETION POLICY TO APPLIED ON ALL STANDBY; + +ttitle off diff --git a/recreate_index.sql b/recreate_index.sql new file mode 100644 index 0000000..024f142 --- /dev/null +++ b/recreate_index.sql @@ -0,0 +1,248 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: index recreate script +-- Date: 2008 - 2014 +--============================================================================== +set pagesize 1000 +set linesize 130 +set verify off + +define USER_NAME='&1' + +----------------------------- +-- How many parallel jobs? +define PARALLEL_EXEC=4 + +----------------------------- +-- use instance default = default +-- to be on the save side use 1 +define DEF_DEGREE='1' + +----------------------------- +-- define the mode +-- +-- define REBUILD_MODE='PARALLEL &&PARALLEL_EXEC. NOLOGGING' +define REBUILD_MODE='online NOLOGGING' + +prompt +prompt Parameter 1 = User Name => &&USER_NAME. +prompt +prompt Setting PARALLEL_EXEC => &&PARALLEL_EXEC. +prompt Setting DEF_DEGREE => &&DEF_DEGREE. +prompt Setting REBUILD_MODE => &&REBUILD_MODE. +prompt + +-------------------------- +-- get sum of database + +ttitle "MegaByte DB Objects in use" SKIP 2 + +set heading on +set feedback on + +column mb_obj format 999G999G999D90 heading "MegaByte DB Objects of the user &&USER_NAME." +column mb_obj_idx format 999G999G999D90 heading "MegaByte Indexes of the user &&USER_NAME." +column mb_obj_part format 999G999G999D90 heading "MegaByte Part Indexes of the user &&USER_NAME." + +select round(sum(bytes)/1024/1024,3) as mb_obj ,'MB - ALL Segments of the user' as info + from dba_segments + where owner = upper('&&USER_NAME.') +/ + +select round(sum(s.bytes)/1024/1024,3) as mb_obj_idx ,'MB - ALL NOT PART INDEXES' as info + from dba_indexes i, dba_segments s + where i.owner = upper('&&USER_NAME.') + and i.index_type = 'NORMAL' + and s.owner = i.owner + and s.segment_name = i.index_name + and i.index_name not in (select ip.index_name from DBA_IND_PARTITIONS ip where ip.INDEX_OWNER=i.owner) +/ + +select round(sum(s.bytes)/1024/1024,3) as mb_obj_part ,'MB - ALL PART INDEXES' as info + from dba_indexes i , DBA_IND_PARTITIONS p, dba_segments s + where i.OWNER = upper('&&USER_NAME.') + and s.owner = i.OWNER + and s.PARTITION_NAME = p.PARTITION_NAME + and s.SEGMENT_NAME=i.index_name + and p.INDEX_OWNER=i.OWNER + and p.index_name=i.index_name +/ + +ttitle off + +set heading off +set feedback off + +------------------- +-- create spool name +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_index_rebuild_&&USER_NAME..sql','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + + +spool &&SPOOL_NAME + +prompt +prompt spool recreate_&&SPOOL_NAME.log +prompt +prompt +prompt prompt ============ Start ================ +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as start_date from dual +prompt / +prompt prompt =================================== +prompt +prompt +prompt set heading on +prompt set feedback on +prompt +prompt ttitle "MegaByte DB Index for the change in Use" SKIP 2 +prompt +prompt column mb_obj format 999G999G999D90 heading "MegaByte DB Objects of the user &&USER_NAME." +prompt column mb_obj_idx format 999G999G999D90 heading "MegaByte Indexes of the user &&USER_NAME." +prompt column mb_obj_part format 999G999G999D90 heading "MegaByte Part Indexes of the user &&USER_NAME." +prompt +prompt select round(sum(bytes)/1024/1024,3) as mb_obj ,'MB - ALL Segments of the user' as info +prompt from dba_segments +prompt where owner = upper('&&USER_NAME.') +prompt / +prompt +prompt select round(sum(s.bytes)/1024/1024,3) as mb_obj_idx ,'MB - ALL NOT PART INDEXES' as info +prompt from dba_indexes i, dba_segments s +prompt where i.owner = upper('&&USER_NAME.') +prompt and i.index_type = 'NORMAL' +prompt and s.owner = i.owner +prompt and s.segment_name = i.index_name +prompt and i.index_name not in (select ip.index_name from DBA_IND_PARTITIONS ip where ip.INDEX_OWNER=i.owner) +prompt / +prompt +prompt select round(sum(s.bytes)/1024/1024,3) as mb_obj_part ,'MB - ALL PART INDEXES' as info +prompt from dba_indexes i , DBA_IND_PARTITIONS p, dba_segments s +prompt where i.OWNER = upper('&&USER_NAME.') +prompt and s.owner = i.OWNER +prompt and s.PARTITION_NAME = p.PARTITION_NAME +prompt and s.SEGMENT_NAME=i.index_name +prompt and p.INDEX_OWNER=i.OWNER +prompt and p.index_name=i.index_name +prompt / +prompt +prompt ttitle off +prompt +prompt set echo on +prompt set timing on +prompt alter session set ddl_lock_timeout=10; +prompt +prompt prompt +prompt prompt ======================= +prompt prompt non partitioned indexes +prompt prompt +prompt prompt +-------------------------------- +-------- non partitioned indexes + +select 'select to_char(sysdate,''hh24:mi'') from dual;'||chr(13)||chr(10)||'prompt rebuild the '||rownum||' index '||iname||' for table '||itabname||' ('||isize ||' MB)'||chr(13)||chr(10)||'alter index &&USER_NAME..' ||iname||' REBUILD &&REBUILD_MODE. ;'||chr(13)||chr(10)||'alter index &&USER_NAME..' ||iname||' LOGGING PARALLEL (DEGREE &&DEF_DEGREE. instances default);' + from ( + select i.index_name iname + , round (s.bytes / 1024 / 1024, 2) isize + ,i.TABLE_NAME itabname + from dba_indexes i, dba_segments s + where i.owner = upper('&&USER_NAME.') + and i.index_type = 'NORMAL' + and s.owner = i.owner + and s.segment_name = i.index_name + and i.index_name not in (select ip.index_name from DBA_IND_PARTITIONS ip where ip.INDEX_OWNER=i.owner) + ) +order by itabname desc,isize asc +/ +prompt prompt +prompt prompt ======================= +prompt prompt partitioned indexes +prompt prompt +prompt prompt +-------------------------------- +-------- partitioned indexes + +select 'select to_char(sysdate,''hh24:mi'') from dual;'||chr(13)||chr(10)||'prompt rebuild the '||rownum||' index '||iname||' Partition '||PARTITION_NAME ||' for table '||itabname||' ('||isize ||' MB)'||chr(13)||chr(10)||'alter index &&USER_NAME..' ||iname||' REBUILD PARTITION '||PARTITION_NAME||' &&REBUILD_MODE. ;'||chr(13)||chr(10)||'alter index &&USER_NAME..' ||iname||' LOGGING PARALLEL (DEGREE &&DEF_DEGREE. instances default);' +from ( +select i.index_name iname + , round (s.bytes / 1024 / 1024, 2) isize + , i.TABLE_NAME itabname + , p.PARTITION_NAME + from dba_indexes i , DBA_IND_PARTITIONS p, dba_segments s + where i.OWNER = upper('&&USER_NAME.') + and s.owner = i.OWNER + and s.PARTITION_NAME = p.PARTITION_NAME + and s.SEGMENT_NAME=i.index_name + and p.INDEX_OWNER=i.OWNER + and p.index_name=i.index_name +) +order by itabname desc,isize asc +/ + +prompt +prompt set echo off +prompt set timing off +prompt set heading on +prompt set feedback on +prompt +prompt ttitle "MegaByte DB Index for the change in Use" SKIP 2 +prompt +prompt column mb_obj format 999G999G999D90 heading "MegaByte DB Objects of the user &&USER_NAME." +prompt column mb_obj_idx format 999G999G999D90 heading "MegaByte Indexes of the user &&USER_NAME." +prompt column mb_obj_idx format 999G999G999D90 heading "MegaByte Part Indexes of the user &&USER_NAME." +prompt +prompt select round(sum(bytes)/1024/1024,3) as mb_obj ,'MB - ALL Segments of the user' as info +prompt from dba_segments +prompt where owner = upper('&&USER_NAME.') +prompt / +prompt +prompt select round(sum(s.bytes)/1024/1024,3) as mb_obj_idx ,'MB - ALL NOT PART INDEXES' as info +prompt from dba_indexes i, dba_segments s +prompt where i.owner = upper('&&USER_NAME.') +prompt and i.index_type = 'NORMAL' +prompt and s.owner = i.owner +prompt and s.segment_name = i.index_name +prompt and i.index_name not in (select ip.index_name from DBA_IND_PARTITIONS ip where ip.INDEX_OWNER=i.owner) +prompt / +prompt +prompt select round(sum(s.bytes)/1024/1024,3) as mb_obj_part ,'MB - ALL PART INDEXES' as info +prompt from dba_indexes i , DBA_IND_PARTITIONS p, dba_segments s +prompt where i.OWNER = upper('&&USER_NAME.') +prompt and s.owner = i.OWNER +prompt and s.PARTITION_NAME = p.PARTITION_NAME +prompt and s.SEGMENT_NAME=i.index_name +prompt and p.INDEX_OWNER=i.OWNER +prompt and p.index_name=i.index_name +prompt / +prompt +prompt ttitle off +prompt +prompt prompt recreate statistics if missing after index rebuild at +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as finish_date from dual +prompt / +prompt exec dbms_stats.gather_schema_stats (ownname => upper('&&USER_NAME.'), options => 'GATHER', estimate_percent => DBMS_STATS.auto_sample_size, cascade => TRUE , degree => &&PARALLEL_EXEC. ); +prompt +prompt +prompt prompt ============ Finish ================ +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as finish_date from dual +prompt / +prompt prompt =================================== +prompt +prompt prompt to check the log see recreate_&&SPOOL_NAME.log +prompt + +prompt spool off + +spool off + +prompt ..... +prompt to start he recreate scripts use the script: &&SPOOL_NAME +prompt ..... + +set heading on +set feedback on +set verify on + diff --git a/recreate_tables.sql b/recreate_tables.sql new file mode 100644 index 0000000..60489f8 --- /dev/null +++ b/recreate_tables.sql @@ -0,0 +1,179 @@ +-- ============================================================== +-- GPI - Gunther Pippčrr +-- create the script to reorganise the smaller tables of a tablespace with alter table move +-- Work in progress +-- ============================================================== +-- for more Examples see: +-- http://www.doag.org/home/aktuelle-news/article/defragmentierung-von-tablespaces-fuer-arme.html +-- http://www.pythian.com/blog/oracle-file-extent-map-the-old-fashioned-way/ +-- ============================================================== +set verify off +set linesize 130 pagesize 4000 + +define TABLESPACE_NAME = '&1' + +prompt +prompt Parameter 1 = Tablespace Name => &&TABLESPACE_NAME. +prompt + +------------------- +-- create spool name +col SPOOL_NAME_COL new_val SPOOL_NAME + +select replace ( + ora_database_name + || '_' + || sys_context ('USERENV', 'HOST') + || '_' + || to_char (sysdate, 'dd_mm_yyyy_hh24_mi') + || '_table_rebuild_&&TABLESPACE_NAME..sql' + , '\' + , '_') + --' resolve syntax highlight bug FROM my editer .-( + as SPOOL_NAME_COL + from dual +/ + + +spool &&SPOOL_NAME + +prompt +prompt spool recreate_&&SPOOL_NAME.log +prompt +prompt +prompt prompt ============ Start ================ +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as start_date from dual +prompt / +prompt prompt =================================== +prompt +prompt +prompt set heading on +prompt set feedback on +prompt set echo on +prompt + +--------------------------------------------------------------------------------------------------------- +prompt Enable Row movement for all tables +-- Alter Table enable rowmovement; + +select 'alter table ' || owner || '.' || table_name || ' enable rowmovement;' + from dba_tables + where tablespace_name = upper ('&&TABLESPACE_NAME.'); + +prompt Shrink all not partitioned tables +-- Alter Table shrink space cascade; + +select 'alter table ' || owner || '.' || table_name || ' shrink space cascade;' + from dba_tables + where tablespace_name = upper ('&&TABLESPACE_NAME.') + and PARTITIONED = 'NO'; + +--------------------------------------------------------------------------------------------------------- +prompt Shrink all partitioned tables (for each Partition) +-- Alter Table modify partition shrink space + +select 'alter table ' || owner || '.' || table_name || ' modify partition ' || p.PARTITION_NAME || ' shrink space;' + from dba_tables t, dba_tab_partitions p + where t.tablespace_name = upper ('&&TABLESPACE_NAME.') + and t.PARTITIONED = 'YES' + and p.tablespace_name = upper ('&&TABLESPACE_NAME.') + and p.SUBPARTITION_COUNT = 0 + and t.owner = p.table_owner + and t.table_name = p.table_name; + +-------------------------------------------------------------------------------------------------------- +prompt Partionierte Tabelle (mit Subpartitionen) (für jede Subpartition) +--Alter Table modify subpartition shrink space + +select 'alter table ' || owner || '.' || table_name || ' modify subpartition ' || p.PARTITION_NAME || ' shrink space;' + from dba_tables t, dba_tab_subpartitions p + where t.tablespace_name = upper ('&&TABLESPACE_NAME.') + and t.PARTITIONED = 'YES' + and p.tablespace_name = upper ('&&TABLESPACE_NAME.') + and t.owner = p.table_owner + and t.table_name = p.table_name; + + + +--------------------------------------------------------------------------------------------------------- +--------------------------------------------------------------------------------------------------------- +-- move free segments to gether +-- +alter tablespace &&TABLESPACE_NAME. coalesce; +-- + + +--------------------------------------------------------------------------------------------------------- +--------------------------------------------------------------------------------------------------------- + + + +--------------------------------------------------------------------------------------------------------- +--------------------------------------------------------------------------------------------------------- +-- +-- Start to move all the data +-- +--------------------------------------------------------------------------------------------------------- +--------------------------------------------------------------------------------------------------------- + +-- prompt Move all tables > 10MB + + +--Nicht partionierte Tabelle +prompt move all not partitioned tables +-- Alter Table move; + +select 'alter table ' || owner || '.' || table_name || ' move;' + from dba_tables + where tablespace_name = upper ('&&TABLESPACE_NAME.') + and PARTITIONED = 'NO'; + +--Partionierte Tabelle +--Alter Table move partition …; + +select 'alter table ' || owner || '.' || table_name || ' move partition ' || p.PARTITION_NAME || ';' + from dba_tables t, dba_tab_partitions p + where t.tablespace_name = upper ('&&TABLESPACE_NAME.') + and t.PARTITIONED = 'YES' + and p.tablespace_name = upper ('&&TABLESPACE_NAME.') + and p.SUBPARTITION_COUNT = 0 + and t.owner = p.table_owner + and t.table_name = p.table_name; + +--Partionierte Tabelle (mit Subpartitionen) +--Alter Table move subpartition; + +select 'alter table ' || owner || '.' || table_name || ' move subpartition ' || p.PARTITION_NAME || ';' + from dba_tables t, dba_tab_subpartitions p + where t.tablespace_name = upper ('&&TABLESPACE_NAME.') + and t.PARTITIONED = 'YES' + and p.tablespace_name = upper ('&&TABLESPACE_NAME.') + and t.owner = p.table_owner + and t.table_name = p.table_name; + +--LOB nicht partionierte Tabelle +--Alter Table move LOB () store as ; + +--LOB partionierte Tabelle +--Alter Table move partition LOB () store as ; + +--LOB partionierte Tabelle (mit Subpartitionen) +--Alter Table move subpartition LOB () store as ; + +--Nicht partionierter Index +--alter index rebuild; + +--Partionierter Index +--Alter index rebuild partition ; + +-- Partionierter Index (mit Subpartitionen) +-- Alter index rebuild subpartition ; + +--IOT +-- Alter Table move; + + +spool off + + + diff --git a/recycle.sql b/recycle.sql new file mode 100644 index 0000000..7f86584 --- /dev/null +++ b/recycle.sql @@ -0,0 +1,55 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the content summary of the dba recyclebin +-- Date: 02.2014 +--============================================================================== +set linesize 130 pagesize 300 + +set verify off + +column owner format a15 heading "Owner" +column TYPE format a12 heading "Obj|type" + +column max_CREATETIME format a14 heading "Min|Create" +column min_CREATETIME format a14 heading "Max|Create" +column min_DROPTIME format a14 heading "Min Age|Drop" +column max_DROPTIME format a16 heading "Max Age|Drop" +column SPACE_GB format 999G999D99 heading "Space|GB" + +-- +--fix use DB Block size!! +-- +--define BLOCK_SIZE=8192 +define BLOCK_SIZE=16384 + +-- +show parameter recyclebin + + +--- +column DUMMY NOPRINT; +COMPUTE SUM OF SPACE_GB ON DUMMY; +BREAK ON DUMMY; + + +select null dummy + , owner + , count(*) as anzahl + , TYPE + , substr(min(CREATETIME),1,13) as min_CREATETIME + , substr(max(CREATETIME),1,13) as max_CREATETIME + , substr(min(DROPTIME),1,13) as min_DROPTIME + , substr(max(DROPTIME),1,16) as max_DROPTIME + , round(((sum(space)*&&BLOCK_SIZE)/1024/1024/1024),2) as SPACE_GB + from DBA_RECYCLEBIN +group by owner + , type +order by 1,2 +/ + +prompt ..... +prompt ..... -- to clean all: PURGE DBA_RECYCLEBIN ( as sys user!) +prompt ..... -- to clean your bin : PURGE RECYCLEBIN; +prompt ..... + +set verify on \ No newline at end of file diff --git a/redo.sql b/redo.sql new file mode 100644 index 0000000..4082da4 --- /dev/null +++ b/redo.sql @@ -0,0 +1,284 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: redo +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Report Redo Log Configuration " skip 1 - +left "Sizes in MB" skip 2 + +column member format a50 +column THREAD# format 99 +column GROUP# format 99 +column value format 999G999G999 + +ttitle "Redolog Size of each group" skip 1 - +left "Sizes in MB" skip 2 + +select count (*) + , thread# + , to_char (round ( BYTES / 1024 / 1024 , 2))|| 'M' as REDOLOG_SIZE + from v$log +group by thread#, BYTES +/ + +prompt + +ttitle "Redolog Status of each group" skip 1 - +left "Sizes in MB" skip 2 + +select THREAD# + , group# + , status + , to_char (round ( BYTES / 1024 / 1024, 2))|| 'M' as REDOLOG_SIZE + from v$log +order by 1, 2 +/ + +prompt + +ttitle "Redolog Member of the groups" skip 1 - +left "Sizes in MB" skip 2 + + select group# + , member + , status + , type + from v$logfile +order by 1, 2 +/ + +ttitle "Redolog Switch frequency " skip 2 + +--select to_char(FIRST_TIME,'dd.mm.yyyy hh24:mi:ss') as first_time_log +-- , RECID +-- , THREAD# +-- , SEQUENCE# +-- from (select * from v$log_history order by recid desc) +--where rownum <=20 +--order by first_time_log asc +--/ +set linesize 130 + +column T01 format a3 heading "01" justify center +column T02 format a3 heading "02" justify center +column T03 format a3 heading "03" justify center +column T04 format a3 heading "04" justify center +column T05 format a3 heading "05" justify center +column T06 format a3 heading "06" justify center +column T07 format a3 heading "07" justify center +column T08 format a3 heading "08" justify center +column T09 format a3 heading "09" justify center +column T10 format a3 heading "10" justify center +column T11 format a3 heading "11" justify center +column T12 format a3 heading "12" justify center +column T13 format a3 heading "13" justify center +column T14 format a3 heading "14" justify center +column T15 format a3 heading "15" justify center +column T16 format a3 heading "16" justify center +column T17 format a3 heading "17" justify center +column T18 format a3 heading "18" justify center +column T19 format a3 heading "19" justify center +column T20 format a3 heading "20" justify center +column T21 format a3 heading "21" justify center +column T22 format a3 heading "22" justify center +column T23 format a3 heading "23" justify center +column T24 format a3 heading "00" justify center +column slday format a5 heading "Day" justify left + +select to_char (to_date (to_char (slday), 'yyyymmdd'), 'DD.MM') as slday + , decode (nvl (T01, 0), 0, '-', to_char (T01)) T01 + , decode (nvl (T02, 0), 0, '-', to_char (T02)) T02 + , decode (nvl (T03, 0), 0, '-', to_char (T03)) T03 + , decode (nvl (T04, 0), 0, '-', to_char (T04)) T04 + , decode (nvl (T05, 0), 0, '-', to_char (T05)) T05 + , decode (nvl (T06, 0), 0, '-', to_char (T06)) T06 + , decode (nvl (T07, 0), 0, '-', to_char (T07)) T07 + , decode (nvl (T08, 0), 0, '-', to_char (T08)) T08 + , decode (nvl (T09, 0), 0, '-', to_char (T09)) T09 + , decode (nvl (T10, 0), 0, '-', to_char (T10)) T10 + , decode (nvl (T11, 0), 0, '-', to_char (T11)) T11 + , decode (nvl (T12, 0), 0, '-', to_char (T12)) T12 + , decode (nvl (T13, 0), 0, '-', to_char (T13)) T13 + , decode (nvl (T14, 0), 0, '-', to_char (T14)) T14 + , decode (nvl (T15, 0), 0, '-', to_char (T15)) T15 + , decode (nvl (T16, 0), 0, '-', to_char (T16)) T16 + , decode (nvl (T17, 0), 0, '-', to_char (T17)) T17 + , decode (nvl (T18, 0), 0, '-', to_char (T18)) T18 + , decode (nvl (T19, 0), 0, '-', to_char (T19)) T19 + , decode (nvl (T20, 0), 0, '-', to_char (T20)) T20 + , decode (nvl (T21, 0), 0, '-', to_char (T21)) T21 + , decode (nvl (T22, 0), 0, '-', to_char (T22)) T22 + , decode (nvl (T23, 0), 0, '-', to_char (T23)) T23 + --, decode(nvl(T24,0),0,'-',to_char(T24)) T24 + from ( select sum (decode (nvl (to_char (lh.FIRST_TIME, 'yyyymmddhh24'), 0), 0, 0, 1)) as slog, dr.dr as slday, dr.dh as slhour + --, to_char(lh.FIRST_TIME,'yyyymmddhh24') + from v$log_history lh + , (select td.dr || th.hr as dg, th.hr as dh, td.dr as dr + from (select ltrim (to_char (rownum, '09')) as hr + from all_objects + where rownum < 25) th + , (select ltrim (to_char ( sysdate + - ( rownum + - 1) + , 'yyyymmdd')) + as dr + from all_objects + where rownum < 20) td) dr + where dr.dg = to_char (lh.FIRST_TIME(+), 'yyyymmddhh24') + group by to_char (lh.FIRST_TIME, 'yyyymmddhh24') + , dr.dg + , dr.dh + , dr.dr) pivot (sum (slog) + for slhour + in ('01' as T01 + , '02' as T02 + , '03' as T03 + , '04' as T04 + , '05' as T05 + , '06' as T06 + , '07' as T07 + , '08' as T08 + , '09' as T09 + , '10' as T10 + , '11' as T11 + , '12' as T12 + , '13' as T13 + , '14' as T14 + , '15' as T15 + , '16' as T16 + , '17' as T17 + , '18' as T18 + , '19' as T19 + , '20' as T20 + , '21' as T21 + , '22' as T22 + , '23' as T23 + , '24' as T24)) +/ + +ttitle "Archive log size last 7 days" skip 1 + +column SIZE_GB format 999999999 heading "Size GB" +column dest_id format 99 heading "Arch|Dest ID" + + select decode (grouping (trunc (completion_time)), 1, 'Sum:', trunc (completion_time)) days + , round ( sum ( blocks + * block_size) + / 1024 + / 1024 + / 1024 + , 3) + size_gb + , DEST_ID + from v$archived_log + where completion_time > trunc ( sysdate + - 3) +--where completion_time > to_date('13.01.2014 17:13','dd.mm.yyyy hh24:mi') +--group by DEST_ID +group by cube (DEST_ID, trunc (completion_time)) +order by 1, 3 +/ + +prompt .... look at the archive dest id for more then one archive destination +prompt .... + +ttitle "Archive log count on disk days" skip 1 + + select THREAD# as inst_id + , DEST_ID + , trunc (COMPLETION_TIME) as log_day + , substr (name, 1, 10) || '..' as file_name + , count (*) as archvie_count + from v$archived_log + where name is not null +group by trunc (COMPLETION_TIME) + , THREAD# + , substr (name, 1, 10) || '..' + , DEST_ID +order by 2, 3, 1 +/ + +ttitle "Redolog init ora Settings " skip 1 + +show parameter log_buffer + +ttitle left "Trace File Locations" skip 2 +column full_trace_file_loc format a100 heading "Trace|File" + +select p.inst_id, p.pname, p.tracefile as full_trace_file_loc + from gv$session vs, gv$process p + where vs.paddr = p.addr + and vs.inst_id = p.inst_id + and vs.username is null + and p.pname = 'LGWR' +order by vs.username, p.inst_id +/ + +ttitle "Redolog Buffer Contention statistic:" skip 2 + +column r format a50 fold_after + +set heading off + +select rpad ('Name', 20) || ': ' || name as r + , rpad ('Gets', 20) || ': ' || gets as r + , rpad ('Misses', 20) || ': ' || misses as r + , rpad ('Alloc Ratio', 20) + || ': ' + || round ( ( misses + / gets) + * 100 + , 3) + as r + , rpad ('Immediate Gets', 20) || ': ' || immediate_gets as r + , rpad ('Immediate Misses', 20) || ': ' || immediate_misses as r + , rpad ('Miss Ratio', 20) + || ': ' + || decode ( immediate_gets + + immediate_misses + , 0, 0 + , round ( immediate_misses + / ( immediate_gets + + immediate_misses) + , 3)) + as r + , '---' || chr (10) + from v$latch + where name in ('redo allocation', 'redo copy') +/ + +set heading on + +prompt misses/gets (must be < 1%) + +--Redo allocation: (2'534'627 / 277'446'780) * 100 = 0.91 % +--Redo Copy: (27'694 / 33'818) * 100 = 81.8 % +--IMMEDIATE_MISSES/(IMMEDIATE_GETS+IMMEDIATE_MISSES) (must be < 1%) +--Redo Copy: 150'511/(150'511+357'613'861) = 0.04 % + + +ttitle "Waits on Redo Log Buffer" skip 1 + +column value format 999G999G999 + +select name, value + from v$sysstat + where name = 'redo log space requests' +/ + +prompt The value of 'redo log space requests' reflects the number of times a user process waits for space in the redo log buffer. +prompt Optimal is if the value is near 0 + +ttitle "Size of one Redo Log Buffer in Bytes" skip 1 + +select max (l.lebsz) log_block_size + from sys.x$kccle l + where l.inst_id = userenv ('Instance') +/ + +prompt + +ttitle off + +prompt \ No newline at end of file diff --git a/redo10g.sql b/redo10g.sql new file mode 100644 index 0000000..2367627 --- /dev/null +++ b/redo10g.sql @@ -0,0 +1,102 @@ +--============================================================================== +-- Author: Gunther Pippčrr ( http://www.pipperr.de ) +-- Desc: get the user rights and grants +-- Date: 01.September 2012 +-- Site: http://orapowershell.codeplex.com +--============================================================================== + +SET linesize 130 pagesize 300 + +ttitle "Report Redo Log Configuration " SKIP 1 - +left "Sizes in MB" SKIP 2 + +column member format a50 +column THREAD# format 99 +column GROUP# format 99 + +ttitle "Redolog Size of each group" SKIP 1 - +left "Sizes in MB" SKIP 2 + +select count(*) + ,thread# + ,to_char(round(BYTES / 1024 / 1024, 2)) || 'M' as REDOLOG_SIZE + from v$log + group by thread# + ,BYTES +/ + +prompt + +ttitle "Redolog Status of each group" SKIP 1 - +left "Sizes in MB" SKIP 2 + +select THREAD# + ,group# + ,status + ,to_char(round(BYTES / 1024 / 1024, 2)) || 'M' as REDOLOG_SIZE + from v$log + order by 1 + ,2 +/ +prompt + +ttitle "Redolog Member of the groups" SKIP 1 - +left "Sizes in MB" SKIP 2 + +select group# + ,member + ,status + from v$logfile + order by 1 + ,2 +/ + +ttitle "Redolog Switch frequency " SKIP 1 + +select to_char(FIRST_TIME,'dd.mm.yyyy hh24:mi:ss') as first_time_log + , RECID + , THREAD# + , SEQUENCE# + from (select * from v$log_history order by recid desc) +where rownum <=500 +order by first_time_log asc +/ + +ttitle "Redolog Statistik" SKIP 1 +SELECT SUBSTR(name,1,20) "Name",gets,misses,immediate_gets,immediate_misses +FROM v$latch +WHERE name in ('redo allocation', 'redo copy') +/ + +prompt MISSES/GETS (must be < 1%) + +ttitle "Redolog Waits" SKIP 1 +SELECT name,value +FROM v$sysstat +WHERE name = 'redo log space requests'; + + +ttitle "Redolog init ora Settings " SKIP 1 +show parameter log_buffer + +ttitle left "Trace File Locations" skip 2 +column full_trace_file_loc format a100 heading "Trace|File" +select p.inst_id + , p.pname + , p.tracefile as full_trace_file_loc +from gv$session vs + , gv$process p +where vs.paddr=p.addr + and vs.inst_id=p.inst_id + and vs.username is null + and p.pname = 'LGWR' +order by vs.username + , p.inst_id +/ + +ttitle off + +prompt + + + diff --git a/redo_change.sql b/redo_change.sql new file mode 100644 index 0000000..4038cb3 --- /dev/null +++ b/redo_change.sql @@ -0,0 +1,121 @@ +--============================================================================== +-- Desc: who create how much redo per day last 7 in the database +-- Date: November 2013 +--============================================================================== +-- Src: http://www.mydbspace.com/?p=173 +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt +set linesize 130 pagesize 300 + +column mb_day_total format 999G999G999G999D999 +column change_percent format 999D99 +column mb_per_user_change format 999G999G999D99 + +column write_percent format 999D99 +column mb_per_user_write format 999G999G999D99 +column mb_per_user format 999G999G999D99 + +column owner format a20 +column days format a10 + + +define USER_NAME='&1' + +prompt +prompt Parameter 1 = User Name => &&USER_NAME. +prompt + +ttitle "Percent Overview % for this user &&USER_NAME" skip 1 + +with actions + as ( select so.owner as owner + , sum (ss.db_block_changes_delta) changes + , sum (ss.PHYSICAL_WRITES_DELTA) writes + , trunc (begin_interval_time) as days + from dba_hist_seg_stat ss, dba_hist_seg_stat_obj so, dba_hist_snapshot sp + where sp.snap_id = ss.snap_id + and sp.instance_number = ss.instance_number + and ss.obj# = so.obj# + and ss.dataobj# = so.dataobj# + and begin_interval_time > trunc ( sysdate + - 7) + group by so.owner, trunc (begin_interval_time)) + select to_char (a.days, 'dd.mm.yyyy') as days + , r.size_mb mb_day_total + --, round((a.changes / (t.changes_total / 100)), 2) change_percent + --, round(r.size_mb * (a.changes / (t.changes_total / 1000)), 2) mb_per_user_change + --, round((a.writes / (t.writes_total / 100)), 2) write_percent + --, round(r.size_mb * (a.writes / (t.writes_total / 1000)), 2) mb_per_user_write + , round ( ( ( a.writes + + a.changes) + * 100) + / ( t.writes_total + + t.changes_total) + , 2) + write_change_percent + , round ( r.size_mb + * ( ( ( ( a.writes + + a.changes) + * 100) + / ( t.writes_total + + t.changes_total)) + / 100) + , 2) + mb_per_user + , a.owner + from ( select trunc (completion_time) days + , round ( sum ( blocks + * block_size) + / 1024 + / 1024 + , 3) + size_mb + , DEST_ID + from v$archived_log + where completion_time > trunc ( sysdate + - 7) + group by (DEST_ID, trunc (completion_time))) r + , actions a + , ( select sum (ss.db_block_changes_delta) changes_total + , sum (ss.PHYSICAL_WRITES_DELTA) writes_total + , trunc (begin_interval_time) as days + from dba_hist_seg_stat ss, dba_hist_seg_stat_obj so, dba_hist_snapshot sp + where sp.snap_id = ss.snap_id + and sp.instance_number = ss.instance_number + and ss.obj# = so.obj# + and ss.dataobj# = so.dataobj# + and begin_interval_time > trunc ( sysdate + - 7) + group by trunc (begin_interval_time)) t + where r.days = a.days + and t.days = r.days + and a.owner like upper (nvl ('&&USER_NAME', '%')) +order by a.days, a.owner +/ + + +ttitle "Detail Segments Overview for this user &&USER_NAME" skip 1 + +select * + from ( select so.owner as owner + , sum (ss.db_block_changes_delta) changes + , sum (ss.PHYSICAL_WRITES_DELTA) writes + , trunc (begin_interval_time) as days + , so.OBJECT_NAME + from dba_hist_seg_stat ss, dba_hist_seg_stat_obj so, dba_hist_snapshot sp + where sp.snap_id = ss.snap_id + and sp.instance_number = ss.instance_number + and ss.obj# = so.obj# + and ss.dataobj# = so.dataobj# + and begin_interval_time > trunc ( sysdate + - 7) + and so.owner like upper (nvl ('&&USER_NAME', '%')) + group by so.owner, OBJECT_NAME, trunc (begin_interval_time) + order by sum (ss.db_block_changes_delta) desc) + where rownum < 30 +/ + + +ttitle off \ No newline at end of file diff --git a/refresh_group.sql b/refresh_group.sql new file mode 100644 index 0000000..02ba0e8 --- /dev/null +++ b/refresh_group.sql @@ -0,0 +1,24 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Get all refresh groups of the DB for the materialized views +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +column owner format a20 +column mview_name format a25 +column last_refresh_date format a18 +column rname format a20 +column next_date format a18 + + +select mv.owner + , mv.mview_name + , to_char(mv.last_refresh_date,'dd.mm.yyyy hh24:mi') as last_refresh_date + , rc.rname + , to_char(rc.next_date,'dd.mm.yyyy hh24:mi') as next_date +from dba_mviews mv + , dba_refresh_children rc +where mv.owner = rc.owner (+) + and mv.mview_name = rc.name (+) +/ \ No newline at end of file diff --git a/resource_manager.sql b/resource_manager.sql new file mode 100644 index 0000000..9671ad7 --- /dev/null +++ b/resource_manager.sql @@ -0,0 +1,92 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Resoruce Manager settings +--============================================================================== +-- http://docs.oracle.com/cd/E11882_01/server.112/e17120/dbrm.htm#ADMIN027 +-- Script to monitor PX limits from Resource Manager for active sessions (Doc ID 240877.1) +--http://docs.oracle.com/cd/B28359_01/server.111/b28310/dbrm009.htm#ADMIN11906 +--============================================================================== +set linesize 130 pagesize 300 + +prompt .... Viewing Consumer Groups Granted to Users or Roles + +select grantee + , granted_group + , grant_option + , initial_group + from dba_rsrc_consumer_group_privs +order by grantee +/ + +prompt .. Viewing Plan Schema Information + +column plan format a27 heading "Plan" +column status format a10 heading "Status" +column comments format a100 heading "Comment" word_wrapped +column cpu_method format a10 heading "CPU_METHOD" +column mgmt_method format a10 heading "CPU_METHOD" +column parallel format a20 fold_after + +select plan + , status + , cpu_method + , mgmt_method + , parallel_degree_limit_mth as parallel + , comments + from dba_rsrc_plans +order by status +/ + + +prompt .. show user waiting with resource limit + +select inst_id + , sid + , serial# + , username + , resource_consumer_group + from gv$session + where event like 'resmgr%' +/ + + +prompt .. show user resource limits + +select s.inst_id + --, s.SID + --, s.SERIAL# + , count (*) + , s.username + , rpd.plan + , s.RESOURCE_CONSUMER_GROUP + , rpd.PARALLEL_DEGREE_LIMIT_P1 + from Gv$session s + , DBA_RSRC_CONSUMER_GROUPS rcg + , DBA_RSRC_PLAN_DIRECTIVES rpd + , GV$RSRC_CONSUMER_GROUP vcg + where s.RESOURCE_CONSUMER_GROUP is not null + and rcg.CONSUMER_GROUP = s.RESOURCE_CONSUMER_GROUP + --and rcg.status = 'ACTIVE' + and rpd.GROUP_OR_SUBPLAN = rcg.CONSUMER_GROUP + --and rpd.status = 'ACTIVE' + and vcg.name = s.RESOURCE_CONSUMER_GROUP + and s.inst_id = vcg.inst_id +group by s.inst_id + , s.username + , rpd.plan + , s.RESOURCE_CONSUMER_GROUP + , rpd.PARALLEL_DEGREE_LIMIT_P1 +order by 1, 3 +/ + + + + + + + + + + + + diff --git a/resource_manager_sessions.sql b/resource_manager_sessions.sql new file mode 100644 index 0000000..7c5bc62 --- /dev/null +++ b/resource_manager_sessions.sql @@ -0,0 +1,57 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Show the resource manager settings of the running sessions +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +prompt +prompt Parameter 1 = Username => &&USER_NAME. +prompt + +column inst_id format 99 heading "Inst|ID" +column username format a14 heading "DB User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column machine format a30 heading "Remote|pc/server" +column terminal format a13 heading "Remote|terminal" +column program format a16 heading "Remote|program" +column module format a16 heading "Remote|module" +column state format a10 heading "State" +column OSUSER format a13 heading "OS|User" +column LOGON_TIME format a12 heading "Logon|Time" +column status format a8 heading "Status" +column action format a15 heading "Action" +column group_name format a15 heading "Res|Group Name" +column service_name format a20 heading "Service|Name" +column client_info format a10 heading "Client|info" +column cpu_wait_time format 999999 heading "CPU|Wait" +column degree_of_parallelism format 999999 heading "Degree|parallel" +column client_identifier format A10 heading "Client|identifier" + +ttitle left "All User Sessions with resource manager information" skip 2 + +select s.inst_id + , s.username + -- ,s.osuser + -- ,s.program + , s.module + , s.action + , co.name group_name + , s.service_name + , se.state + , se.consumed_cpu_time cpu_time + , se.cpu_wait_time + , se.dop / 2 degree_of_parallelism + from gv$rsrc_session_info se, gv$rsrc_consumer_group co, gv$session s + where se.current_consumer_group_id = co.id + and s.sid = se.sid + and s.inst_id = se.inst_id + and co.name not in ('_ORACLE_BACKGROUND_GROUP_') + and s.username like upper ('%&&USER_NAME.%') +order by s.inst_id, s.username +/ + +ttitle off \ No newline at end of file diff --git a/rman.sql b/rman.sql new file mode 100644 index 0000000..5fe9c01 --- /dev/null +++ b/rman.sql @@ -0,0 +1,157 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: get the RMan settings +-- Date: September 2013 +--============================================================================== +-- Source: http://docs.oracle.com/cd/E11882_01/backup.112/e10643/rcviews001.htm +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "RMan non default settings" SKIP 2 + +column conf# format 9999 +column name format a30 heading "Name" +column value format a70 heading "Value" + +select conf# + , name + , value + from v$rman_configuration +order by conf# +/ + +ttitle "Check Block Change Tracking" SKIP 2 + +column filename format a60 + + +select filename + , status + , bytes + from v$block_change_tracking +/ + +ttitle "Check Usage of the Change Tracking" SKIP 2 + +select round(sum(nvl(BLOCKS_READ,0))/ ( sum(nvl(DATAFILE_BLOCKS,0))/100 ) ,3) as PERCENT_INCREMENT + from v$backup_datafile +where USED_CHANGE_TRACKING = 'YES' +/ + +ttitle "Overview over the last backups of the system tables space" SKIP 2 + +select completion_time + , datafile_blocks + , blocks_read + , blocks + , USED_CHANGE_TRACKING + from v$backup_datafile w +where USED_CHANGE_TRACKING = 'YES' + and file# = 1 +order by 1 +/ + +ttitle "Overview over the last backups of all datafiles" SKIP 2 + +select min(completion_time) First_time + , max(completion_time) last_time + , count(*) total + , sum(decode(USED_CHANGE_TRACKING,'YES',1,0)) as USED_CHANGE_TRACKING + , sum(decode(USED_CHANGE_TRACKING,'NO',1,0)) as NO_CHANGE_TRACKING + from v$backup_datafile w +where USED_CHANGE_TRACKING = 'YES' +order by 1 +/ + + +ttitle "RMan last Backups Sets of the last 3 days" SKIP 2 + +column set_stamp format 9999999999 heading "Set Number" +column start_time format a16 heading "Start Date" +column end_time format a16 heading "End Date" +column backup_type format a3 heading "Type" +column incremental_level format 99 heading "I" +column backup_byte_mb format 999G999G999D999 heading "Backup |Volume" +column backup_duration format 999G999G999 heading "Backup|Times s" +column tag format a35 heading "Backup|Tag" +column handle format a35 heading "Backup|Directory" + +select to_char( s.start_time ,'dd.mm.yyyy hh24:mi') as start_time + , to_char(max(pd.completion_time),'dd.mm.yyyy hh24:mi') as end_time + , round(sum(p.bytes)/1024/1024,3) as backup_byte_mb + , sum(p.elapsed_seconds) as backup_duration + , sd.incremental_level + , pd.tag + from v$backup_set s + , v$backup_piece p + , v$backup_piece_details pd + , v$backup_set_details sd +where s.completion_time > sysdate - 5 + and p.set_stamp = s.set_stamp + and sd.SET_STAMP=s.set_stamp + and pd.SET_STAMP=p.set_stamp +group by to_char(s.start_time ,'dd.mm.yyyy hh24:mi') + , to_char(s.completion_time ,'dd.mm.yyyy hh24:mi') + , s.backup_type + , sd.incremental_level + , pd.tag +order by to_char(s.completion_time ,'dd.mm.yyyy hh24:mi') desc +/ + +ttitle "RMan last Backups Jobs of the last 3 days" SKIP 2 +-- +-- http://docs.oracle.com/cd/E11882_01/server.112/e40402/dynviews_2142.htm#REFRN30391 +-- + +column backup_read_byte_mb format 999G999G999D999 heading "Backup Read|Volume" +column backup_byte_mb format 999G999G999D999 heading "Backup Write|Volume" +column STATUS format a20 heading "Backup Status" +column backup_type format a10 heading "Backup type" + +select + to_char(d.start_time ,'dd.mm.yyyy hh24:mi') as start_time + , to_char(d.end_time ,'dd.mm.yyyy hh24:mi') as end_time + , round((d.input_bytes)/1024/1024,3) as backup_read_byte_mb + , round((d.output_bytes)/1024/1024,3) as backup_byte_mb + , d.input_type as backup_type + , d.status + from v$rman_backup_job_details d +where end_time > sysdate - 5 +order by d.start_time desc +/ + +----- to get more details ---------------------------------------- + +-- ttitle "RMan last Backups jobs details" SKIP 2 + +-- select output +-- from gv$rman_output +-- where session_recid in (select session_recid from v$rman_backup_job_details where session_recid in (select max(i.session_recid) from v$rman_backup_job_details i)) +-- and session_stamp in (select session_stamp from v$rman_backup_job_details where session_recid in (select max(i.session_recid) from v$rman_backup_job_details i)) +-- order by recid; +-- / + +-- column handle format a30 heading "Backup File" +-- column elapsed_seconds format 99999 heading "Seconds" +-- column size_bytes_display format a10 heading "Size" +-- column piece# format 99 heading "PC" +-- +-- select to_char(p.start_time ,'dd.mm.yyyy hh24:mi') as start_time +-- ,pd.piece# +-- ,pd.tag +-- ,pd.elapsed_seconds +-- ,pd.handle +-- ,pd.size_bytes_display +-- from v$backup_piece p +-- , v$backup_piece_details pd +-- where pd.set_stamp=p.set_stamp +-- and pd.stamp=p.stamp +-- and p.start_time > sysdate -1 +-- order by p.start_time desc,pd.piece# asc +-- / +-- + +----------------------------------------------------------------- + +ttitle off + diff --git a/rman_process.sql b/rman_process.sql new file mode 100644 index 0000000..444248d --- /dev/null +++ b/rman_process.sql @@ -0,0 +1,72 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: Process List of RMAN Oracle sessions +-- Date: 01.September 2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +ttitle left "Process List of the RMAN Sessions" skip 2 + +column process_id format a8 heading "Process|ID" +column inst_id format 99 heading "Inst|ID" +column username format a8 heading "DB User|name" +column osusername format a8 heading "OS User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column machine format a14 heading "Remote|pc/server" +column terminal format a14 heading "Remote|terminal" +column program format a17 heading "Remote|program" +column module format a15 heading "Remote|module" +column client_info format a15 heading "Client|info" +column pname format a8 heading "Process|name" +column tracefile format a20 heading "Trace|File" +column LOGON_TIME format a5 heading "Logon|time" + +select p.inst_id + , to_char(p.spid) as process_id + , vs.sid + , vs.serial# + , nvl(vs.username,'n/a') as username + , p.username as osusername + --, p.pname + ,to_char(vs.logon_time,'hh24:mi') as LOGON_TIME + , vs.machine + --, p.terminal + , vs.module + , vs.program + , vs.client_info + --, substr(p.tracefile,length(p.tracefile)-REGEXP_INSTR(reverse(p.tracefile),'[\/|\]')+2,1000) as tracefile + --, p.tracefile +from gv$session vs + , gv$process p +where vs.paddr=p.addr + and vs.inst_id=p.inst_id + and vs.program like '%rman%' +order by vs.logon_time + , p.inst_id +/ + +ttitle left "Trace File Locations" skip 2 +column full_trace_file_loc format a100 heading "Trace|File" +select p.inst_id + , to_char(p.spid) as process_id + , p.tracefile as full_trace_file_loc +from gv$session vs + , gv$process p +where vs.paddr=p.addr + and vs.inst_id=p.inst_id + and vs.program like '%rman%' +order by vs.logon_time + , p.inst_id +/ + + +prompt +prompt ... to enable trace use "oradebug SETOSPID " +prompt +prompt ... to kill session "ALTER SYSTEM KILL SESSION 'sid,serial#,@inst_id';" +prompt ... to end session "ALTER SYSTEM DISCONNECT SESSION 'sid,serial#' IMMEDIATE;" +prompt + +ttitle off diff --git a/rman_status.sql b/rman_status.sql new file mode 100644 index 0000000..c92b32d --- /dev/null +++ b/rman_status.sql @@ -0,0 +1,125 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the status of the last backup in the database +--============================================================================== +set linesize 130 pagesize 300 + +column input_type format a30 +column status format a12 +column time_taken_display format a10 heading "Time|used" +column output_bytes_display format a10 heading "Byte|output" +column btatus format a20 heading "Metric|Status" +column btype format a20 heading "Backup|Type" +column CONTROLFILE_INCLUDED format 99 heading "Controlf.|Count" +column start_time heading "Start|Time" +column INCREMENTAL_LEVEL format 99 heading "Le|vel" +column session_recid heading "Session|recid" + + +alter session set nls_date_format='dd.mm.yyyy hh24:mi' +/ + +--break on session_recid + +select input_type + , status + , start_time + , time_taken_display + , output_bytes_display + , case + when ( (input_type in ('ARCHIVELOG')) + and ( trunc (sysdate) + - trunc (start_time) > 0)) + then + 'ERROR' + else + case + when ( trunc (sysdate) + - trunc (start_time) between 7 + and 14) + then + case when (input_type like ('CONTROLFILE%')) then 'OK' else 'ERROR' end + when ( trunc (sysdate) + - trunc (start_time) > 14) + then + case when (input_type like ('CONTROLFILE%')) then 'OK' else 'WARNING' end + else + case when (status in ('COMPLETED')) then 'OK' when (status in ('FAILED')) then 'ERROR' else 'WARNING' end + end + end + as BStatus + , '-' as backup_type + , controlfile_included + , input_type_text || ' ' || INCREMENTAL_LEVEL as input_type_text + from ( select jd.SESSION_KEY + , trim (jd.input_type || ' ' || ' Key: ' || jd.SESSION_KEY) as input_type + , trim (jd.input_type) as input_type_text + , max (sd.INCREMENTAL_LEVEL) as INCREMENTAL_LEVEL + , sum (decode (sd.CONTROLFILE_INCLUDED, 'YES', 1, 'NO', 0, 0)) as controlfile_included + , jd.status + , jd.start_time + , ltrim (rtrim (jd.time_taken_display)) as time_taken_display + , ltrim (rtrim (jd.output_bytes_display)) as output_bytes_display + , rank () over (partition by trim (jd.input_type) order by jd.SESSION_KEY desc) as rang + from v$rman_backup_job_details jd, v$backup_set_details sd + where sd.SESSION_KEY = jd.SESSION_KEY + and sd.SESSION_RECID = jd.SESSION_RECID + and sd.SESSION_STAMP = jd.SESSION_STAMP + --and 1 = (select count(inst_id) from gv$instance) + group by jd.SESSION_KEY + , trim (jd.input_type) + , trim (jd.input_type || ' ' || ' Key: ' || jd.SESSION_KEY) + , jd.status + , jd.start_time + , jd.time_taken_display + , jd.output_bytes_display) + where rang < 4 +order by SESSION_KEY +/ + +--clear break + + +prompt ... Errors: + +select session_key + , start_time + , end_time + , status + , input_type + , time_taken_display + , output_bytes_display + from v$rman_backup_job_details + where start_time >= sysdate - 8 + and ( status like '%fail%' + or status like '%error%%') +order by start_time +/ + + +--============================================================================== +-- variante A +-- select jd.session_recid +-- , jd.input_type ||' '||sd.INCREMENTAL_LEVEL as input_type +-- , sd.INCREMENTAL_LEVEL +-- , BACKUP_TYPE +-- , jd.status +-- , jd.start_time +-- , jd.time_taken_display +-- , jd.output_bytes_display +-- , sum(decode(sd.CONTROLFILE_INCLUDED,'YES',1,0)) as CONTROLFILE_INCLUDED +-- , sum(PIECES) as PIECES +-- , rank() over (partition by jd.input_type ||' '||sd.INCREMENTAL_LEVEL order by jd.start_time desc) as rang +-- from v$rman_backup_job_details jd +-- ,v$backup_set_details sd +-- where sd.SESSION_KEY = jd.SESSION_KEY +-- -- and 1=(select count(inst_id) from gv$instance) +-- group by jd.session_recid +-- , jd.input_type ||' '||sd.INCREMENTAL_LEVEL +-- , sd.INCREMENTAL_LEVEL +-- , BACKUP_TYPE +-- , jd.status +-- , jd.start_time +-- , jd.time_taken_display +-- , jd.output_bytes_display +--============================================================================== \ No newline at end of file diff --git a/role.sql b/role.sql new file mode 100644 index 0000000..6da0c77 --- /dev/null +++ b/role.sql @@ -0,0 +1,63 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the rights on a DB role +-- Date: November 2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define ROLENAME = '&1' + +prompt +prompt Parameter 1 = Role Name => &&ROLENAME. +prompt + +column role format a32 +column grantee format a20 +column GRANTOR format a20 +column PRIVILEGE format a20 +column cnt format 9999 +column TABLE_NAME format a20 + +ttitle left "Role Info" skip 2 + +select lpad(' ', 2 * level) || granted_role "Role, his roles and privileges" + from ( + /* THE USERS */ + select null grantee + ,role granted_role + from dba_roles + where upper(role) like upper('&&ROLENAME.') + /* THE ROLES TO ROLES RELATIONS */ + union + select grantee + ,granted_role + from dba_role_privs + /* THE ROLES TO PRIVILEGE RELATIONS */ + union + select grantee + ,privilege + from dba_sys_privs) + start with grantee is null +connect by grantee = prior granted_role +/ + + +ttitle left "Object rights on this Role &&ROLENAME." skip 2 + +select GRANTOR + ,grantee + ,PRIVILEGE + ,table_name + ,count(*) as cnt + from DBA_TAB_PRIVS + where grantee like upper('&&ROLENAME.') + group by owner + ,grantee + ,GRANTOR + ,PRIVILEGE + ,table_name +order by owner,table_name, PRIVILEGE +/ + +ttitle off \ No newline at end of file diff --git a/role_ddl.sql b/role_ddl.sql new file mode 100644 index 0000000..ac941d1 --- /dev/null +++ b/role_ddl.sql @@ -0,0 +1,91 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get DDL of a role +--============================================================================== +set verify off +set linesize 130 pagesize 4000 + +define ROLENAME = '&1' + +prompt +prompt Parameter 1 = Role Name => &&ROLENAME. +prompt + +variable ddllob clob + +set heading off +set echo off + +set long 1000000; + +spool create_role_script_&&ROLENAME..sql + +declare + cursor c_role + is + select role + from dba_roles + where upper (role) like upper ('&&ROLENAME.'); + + v_role varchar2 (32); +begin +-- set the transformation attributes + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'OID', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SEGMENT_ATTRIBUTES', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'TABLESPACE', true ); + + for o_rec in c_role + loop + v_role := o_rec.role; + + :ddllob := dbms_metadata.get_ddl ('ROLE', v_role); + + :ddllob := :ddllob || chr (10) || chr (10) || '-- Role Grants : ' || chr (10); + + begin + :ddllob := :ddllob || dbms_metadata.get_granted_ddl ('ROLE_GRANT', v_role); + exception + when others + then + :ddllob := :ddllob || chr (10) || chr (10) || '-- NO DDL for Role Grants found' || chr (10); + end; + + :ddllob := :ddllob || chr (10) || chr (10) || '-- System Grants : ' || chr (10); + + begin + :ddllob := :ddllob || dbms_metadata.get_granted_ddl ('SYSTEM_GRANT', v_role); + exception + when others + then + :ddllob := :ddllob || chr (10) || chr (10) || '-- NO DDL for Sytem Grants found' || chr (10); + end; + + :ddllob := :ddllob || chr (10) || chr (10) || '-- Object Grants : ' || chr (10); + + begin + :ddllob := :ddllob || dbms_metadata.get_granted_ddl ('OBJECT_GRANT', v_role); + exception + when others + then + :ddllob := :ddllob || chr (10) || chr (10) || '-- NO DDL for Object Grants found' || chr (10); + end; + end loop; +end; +/ + +print ddllob + +undefine ddllob + +spool off; + +set head on +set pages 1000 + +prompt ... +prompt ... to create the user call create_role_script_&&ROLENAME..sql in the target DB +prompt ... check the script and add the ; ! +prompt ... diff --git a/roles.sql b/roles.sql new file mode 100644 index 0000000..09bc089 --- /dev/null +++ b/roles.sql @@ -0,0 +1,22 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get DB roles +-- Date: November 2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define ROLENAME = '&1' + +prompt +prompt Parameter 1 = Role Name => &&ROLENAME. +prompt + +column role format a32 + +select role + from dba_roles +where upper(role) like upper('&&ROLENAME.') +order by role asc +/ + diff --git a/scn.sql b/scn.sql new file mode 100644 index 0000000..ecf7b62 --- /dev/null +++ b/scn.sql @@ -0,0 +1,63 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Get the Redo Log scn information +-- Date: 01.November 2013 +--============================================================================== +set linesize 130 pagesize 300 + +set serveroutput on size 1000000 + +prompt + +declare + v_scn number; +begin + v_scn := dbms_flashback.GET_SYSTEM_CHANGE_NUMBER; + dbms_output.PUT_LINE ('current SCN: ' || v_scn); +end; +/ + + +ttitle "Report Redo Log SCN History per Day" skip 1 - + +column min_scn format 999999999999999 +column max_scn format 999999999999999 + + select trunc (FIRST_TIME) as days + , thread# + , min (FIRST_CHANGE#) as min_scn + , max (FIRST_CHANGE#) as max_scn + , count (*) as archive_count + from V$LOG_HISTORY + where FIRST_TIME > trunc ( sysdate + - 14) +group by trunc (FIRST_TIME), thread# +order by 1, 2 +/ + +ttitle off + +ttitle "Report LOGS with this SCN" skip 1 - + + +accept SCN prompt "search for SCN:" + +column NAME format a40 heading "Archivelog|Name" +column THREAD_NR format a2 heading "I" +column SEQUENCE# format 999999 heading "Arch|seq" + +set numwidth 14 + + select to_char (THREAD#) as THREAD_NR + , SEQUENCE# + , NAME + , to_char (FIRST_TIME, 'dd.mm hh24:mi') as first_time + , NEXT_TIME + , FIRST_CHANGE# + , NEXT_CHANGE# + from v$archived_log + where to_number ('&&SCN.') between FIRST_CHANGE# and NEXT_CHANGE# +order by THREAD#, SEQUENCE# +/ + +undefine SCN \ No newline at end of file diff --git a/select.sql b/select.sql new file mode 100644 index 0000000..fa70844 --- /dev/null +++ b/select.sql @@ -0,0 +1,140 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: query some records from the table as list +-- Parameter 1: Name of the table +-- +-- Source see http://docs.oracle.com/cd/B28359_01/appdev.111/b28419/d_sql.htm#i996897 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define TAB_NAME = '&1' + +prompt +prompt Parameter 1 = Tab Name => &&TAB_NAME. +prompt + +set serveroutput on + +/* +from DBA_TAB_COLS +decode(c.type#, 1, decode(c.charsetform, 2, 'NVARCHAR2', 'VARCHAR2'), + 2, decode(c.scale, null, + decode(c.precision#, null, 'NUMBER', 'FLOAT'), + 'NUMBER'), + 8, 'LONG', + 9, decode(c.charsetform, 2, 'NCHAR VARYING', 'VARCHAR'), + 12, 'DATE', + 23, 'RAW', 24, 'LONG RAW', + 58, nvl2(ac.synobj#, (select o.name from obj$ o + where o.obj#=ac.synobj#), ot.name), + 69, 'ROWID', + 96, decode(c.charsetform, 2, 'NCHAR', 'CHAR'), + 100, 'BINARY_FLOAT', + 101, 'BINARY_DOUBLE', + 105, 'MLSLABEL', + 106, 'MLSLABEL', + 111, nvl2(ac.synobj#, (select o.name from obj$ o + where o.obj#=ac.synobj#), ot.name), + 112, decode(c.charsetform, 2, 'NCLOB', 'CLOB'), + 113, 'BLOB', 114, 'BFILE', 115, 'CFILE', + 121, nvl2(ac.synobj#, (select o.name from obj$ o + where o.obj#=ac.synobj#), ot.name), + 122, nvl2(ac.synobj#, (select o.name from obj$ o + where o.obj#=ac.synobj#), ot.name), + 123, nvl2(ac.synobj#, (select o.name from obj$ o + where o.obj#=ac.synobj#), ot.name), + 178, 'TIME(' ||c.scale|| ')', + 179, 'TIME(' ||c.scale|| ')' || ' WITH TIME ZONE', + 180, 'TIMESTAMP(' ||c.scale|| ')', + 181, 'TIMESTAMP(' ||c.scale|| ')' || ' WITH TIME ZONE', + 231, 'TIMESTAMP(' ||c.scale|| ')' || ' WITH LOCAL TIME ZONE', + 182, 'INTERVAL YEAR(' ||c.precision#||') TO MONTH', + 183, 'INTERVAL DAY(' ||c.precision#||') TO SECOND(' || + c.scale || ')', + 208, 'UROWID', + 'UNDEFINED'), + decode(c.type#, 111, 'REF'), + +*/ + +declare + type curtype is ref cursor; + + src_cur curtype; + v_cursor_id number; + v_colType_var varchar2 (50); + v_colType_num number; + v_colType_date date; + v_colType_interval interval day to second; + + v_tab_desc dbms_sql.desc_tab; + + + v_col_count number; + + + v_sql varchar2 (1000) := 'select * from ( &&TAB_NAME. ) where rownum < 4'; +begin + dbms_output.put_line (rpad ('=', 40, '=')); + dbms_output.put_line (rpad (rpad ('-', 10, '-') || ' &&tab_name ', 40, '-')); + dbms_output.put_line (rpad ('=', 40, '=')); + + -- open cursor for the sql statement + open src_cur for v_sql; + + -- switch from native dynamic sql to dbms_sql package. + v_cursor_id := dbms_sql.to_cursor_number (src_cur); + dbms_sql.describe_columns (v_cursor_id, v_col_count, v_tab_desc); + + -- define columns. + for i in 1 .. v_col_count + loop + if v_tab_desc (i).col_type = 2 + then + dbms_sql.define_column (v_cursor_id, i, v_colType_num); + elsif v_tab_desc (i).col_type = 12 + then + dbms_sql.define_column (v_cursor_id, i, v_colType_date); + else + dbms_sql.define_column (v_cursor_id + , i + , v_colType_var + , 50); + end if; + end loop; + + -- fetch rows with dbms_sql package. + while dbms_sql.fetch_rows (v_cursor_id) > 0 + loop + for i in 1 .. v_col_count + loop + dbms_output.put (rpad (v_tab_desc (i).col_name, 30) || ' => '); + + if (v_tab_desc (i).col_type = 1) + then + dbms_sql.column_value (v_cursor_id, i, v_colType_var); + dbms_output.put_line (v_colType_var); + elsif (v_tab_desc (i).col_type = 2) + then + dbms_sql.column_value (v_cursor_id, i, v_colType_num); + dbms_output.put_line (v_colType_num); + elsif (v_tab_desc (i).col_type in (12)) + then --, 178, 179, 180, 181, 231 + dbms_sql.column_value (v_cursor_id, i, v_colType_date); + dbms_output.put_line (v_colType_date); + -- elsif (v_tab_desc(i).col_type = 183) then + -- dbms_sql.column_value(v_cursor_id, i, v_colType_interval); + -- dbms_output.put_line(to_char(v_colType_interval)); + else + dbms_output.put_line ('unsupported Datatype ::' || v_tab_desc (i).col_type); + end if; + end loop; + + dbms_output.put_line (rpad ('=', 40, '=')); + end loop; + + -- Close the cursor + dbms_sql.close_cursor (v_cursor_id); +end; +/ \ No newline at end of file diff --git a/sequence.sql b/sequence.sql new file mode 100644 index 0000000..8b07155 --- /dev/null +++ b/sequence.sql @@ -0,0 +1,41 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: search the table in the database +-- Parameter 1: Name of the sequence +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define SEQ_NAME = '&1' + +prompt +prompt Parameter 1 = SEQ Name => &&SEQ_NAME. +prompt + +column SEQUENCE_OWNER format a14 heading "Qwner" +column SEQUENCE_NAME format a24 heading "Sequence|Name" +column CACHE_SIZE format 9999999 heading "Cache|Size" +column INCREMENT_BY format 999999 heading "Inc|val" +column MIN_VALUE format 999G999G999G999G999 heading "Min|val" +column MAX_VALUE format 999G999G999G999G999 heading "Max|val" +column CYCLE_FLAG format a3 heading "CYC|LE" +column ORDER_FLAG format a3 heading "ORD|ER" +column LAST_NUMBER format 999G999G999G999G999 heading "Last|number" + + select SEQUENCE_OWNER + , SEQUENCE_NAME + , MIN_VALUE + , to_char(MAX_VALUE,'09D99EEEE') as MAX_VALUE + , INCREMENT_BY + , CYCLE_FLAG + , ORDER_FLAG + , CACHE_SIZE + , LAST_NUMBER + from dba_sequences +where upper(SEQUENCE_NAME) like upper('%&&SEQ_NAME.%') +/ + \ No newline at end of file diff --git a/service_session.sql b/service_session.sql new file mode 100644 index 0000000..80a414b --- /dev/null +++ b/service_session.sql @@ -0,0 +1,57 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: sessions per service over all instances +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = '&1' + +prompt +prompt Parameter 1 = USER_NAME Name => &&USER_NAME. +prompt + +column inst_id format 99 heading "SI" +column user_inst_id format 99 heading "UI" +column username format a14 heading "User|Name" +column machine format a20 heading "Machine" +column service_name format a18 heading "Service|Name" +column osuser format a16 heading "OS|User" +column RESOURCE_CONSUMER_GROUP format a15 heading "Resource|Manager" +column session_count format 9G999 heading "Sess|Cnt" +column status format a15 heading "Status" + +break on inst_id skip 2 +compute sum of session_count on inst_id + + select sv.inst_id + , sv.name as service_name + , s.inst_id as user_inst_id + , s.username + , s.machine + , s.osuser + , s.RESOURCE_CONSUMER_GROUP + , status + , count (*) as session_count + from gv$session s, gv$active_services sv + where --s.service_name like 'S\_%' escape '\' + -- and + sv.name = s.service_name(+) + --and s.username not in ('SYS', 'DBSNMP') + and upper (s.username) like upper('&&USER_NAME') +group by s.username + , s.machine + , s.inst_id + , sv.name + , s.osuser + , s.RESOURCE_CONSUMER_GROUP + , sv.inst_id + , status +order by inst_id + , service_name + , username + , status +/ + +clear break +clear computes diff --git a/ses_statistic.sql b/ses_statistic.sql new file mode 100644 index 0000000..05afbbe --- /dev/null +++ b/ses_statistic.sql @@ -0,0 +1,21 @@ +--============================================================================== +-- in work +-- Desc: get the statistic information of a session +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +select n.name + , s.value + , ses.username + , ses.program + , ses.osuser + , ses.machine +from v$statname n + , v$sesstat s + , v$session ses +where n.statistic# = s.statistic# + and s.sid = ses.sid + and s.statistic# not in (13, 14) +order by value desc +/ \ No newline at end of file diff --git a/session_history.sql b/session_history.sql new file mode 100644 index 0000000..7a14728 --- /dev/null +++ b/session_history.sql @@ -0,0 +1,71 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get information about the last session in the database +-- +--============================================================================== +-- see +-- http://www.nocoug.org/download/2008-08/a-tour-of-the-awr-tables.nocoug-Aug-21-2008.abercrombie.html +-- +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +prompt +prompt ... get the periods with more then 5 active sessions from the database +prompt + +select * + from ( + select sample_id + , sample_time + , inst_id + , count(*) as active_sessions + , sum(decode(session_state, 'ON CPU', 1, 0)) as cpu + , sum(decode(session_state, 'WAITING', 1, 0)) as waiting + from gv$active_session_history + where sample_time > sysdate - 10 --((1/24)) + group by sample_id + , sample_time + , inst_id + order by sample_id,inst_id +) +where active_sessions > 32 +/ + + +----- + +column sample_hour format a17 + + +prompt +prompt ... show the activity of the last sessions +prompt + +select to_char(round(sub1.sample_time, 'HH24'), 'MM.DD.YYYY HH24:MI') as sample_hour + ,instance_number + ,round(avg(sub1.on_cpu),1) as cpu_avg + ,round(avg(sub1.waiting),1) as wait_avg + ,round(avg(sub1.active_sessions),1) as act_avg + ,round( (variance(sub1.active_sessions)/avg(sub1.active_sessions)),1) as act_var_mean +from + ( + select sample_id + ,sample_time + ,sum(decode(session_state, 'ON CPU', 1, 0)) as on_cpu + ,sum(decode(session_state, 'WAITING', 1, 0)) as waiting + ,count(*) as active_sessions + ,INSTANCE_NUMBER + from dba_hist_active_sess_history + where sample_time > sysdate - ((1/24)) + --sample_time between to_date('27.03.2014 14:30','MM.DD.YYYY HH24:MI') and to_date('27.03.2014 14:32','MM.DD.YYYY HH24:MI') + group by sample_id + ,sample_time + ,INSTANCE_NUMBER + ) sub1 +group by round(sub1.sample_time, 'HH24'),instance_number +order by round(sub1.sample_time, 'HH24'),instance_number +/ + +-------- \ No newline at end of file diff --git a/session_long_active.sql b/session_long_active.sql new file mode 100644 index 0000000..eb34c4a --- /dev/null +++ b/session_long_active.sql @@ -0,0 +1,42 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: Check for long active sessions longer then one hour +--============================================================================== +set linesize 130 pagesize 300 + +column session_info format a20 heading "Session|Info" +column last_call_et format 999G999G999 heading "Query|Runtime sec" +column inst_id format 99 heading "In|Id" +column machine format a13 heading "Remote|pc/server" +column terminal format a13 heading "Remote|terminal" +column program format a16 heading "Remote|program" +column module format a16 heading "Remote|module" +column client_info format a10 heading "Client|info" +column sql_id format a14 heading "SQL|id" +column OSUSER format a15 heading "OS|User" + +break on sql_id + +select inst_id + , username||'(sid:'||sid||')' as session_info + , sql_id + , machine + --, terminal + , program + , module + --, client_info + , osuser + , last_call_et +from gv$session +where status='ACTIVE' + and type='USER' + and username not in ('SYS','AQ','STRMADMIN') + and last_call_et > (60*60) -- longer then one hour +order by sql_id,inst_id +/ + +prompt ... +prompt ... use session_longops.sql to see what the session is doing +prompt ... + +clear break diff --git a/session_longops.sql b/session_longops.sql new file mode 100644 index 0000000..637e3fc --- /dev/null +++ b/session_longops.sql @@ -0,0 +1,46 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get Information about long running sessions +-- Src: see http://docs.oracle.com/cd/B19306_01/server.102/b14237/dynviews_2092.htm +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +prompt +prompt Parameter 1 = Username => &&USER_NAME. +prompt + + +ttitle left "All Long Running Sessions on this DB" skip 2 + +column inst_id format 99 heading "Inst|ID" +column username format a20 heading "DB User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column START_TIME format a16 heading "Start|Time" +column LAST_UPDATE_TIME format a16 heading "Last Update|Time" +column TIMESTAMP format a16 heading "Timestamp" +column ELAPSED_SECONDS format 99G999 heading "Elapsed|Seconds" +column TIME_REMAINING format 99G999 heading "Time|Renaming" +column MESSAGE format a80 heading "Message" FOLD_BEFORE +column MESSAGE format 9G999D00 heading "% Done" + + select inst_id + , sid + , serial# + , username + , to_char (START_TIME, 'dd.mm.yyyy hh24:mi') as START_TIME + , to_char (LAST_UPDATE_TIME, 'dd.mm.yyyy hh24:mi') as LAST_UPDATE_TIME + --, to_char(TIMESTAMP,'dd.mm.yyyy hh24:mi') as TIMESTAMP + , ELAPSED_SECONDS + , TIME_REMAINING + , message + , (sofar/totalwork)*100 as DONE + from gv$session_longops + where username like upper ('%&&USER_NAME.%') and username not in ('SYS') + -- and TIME_REMAINING > 0 + -- and TOTALWORK > SOFAR +order by username, inst_id, TIME_REMAINING desc +/ diff --git a/session_opt_settings.sql b/session_opt_settings.sql new file mode 100644 index 0000000..52ba6a7 --- /dev/null +++ b/session_opt_settings.sql @@ -0,0 +1,60 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the optimizer settings of user sessions +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +prompt +prompt Parameter 1 = User Name => &&USER_NAME. +prompt + + +column stat_name format a36 heading "OptFeature|Name" +column sql_feature format a20 heading "SQL|Feature" +column isdefault format a4 heading "DEF|AULT" +column value format a15 heading "Session|Value" +column sid format 9999 heading "My|SID" +column session_count format 9999 heading "Ses|Cnt" +column inst_id format 99 heading "Inst|ID" +column username format a14 heading "DB User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column inst_value format a15 heading "Instance|Value" +column is_session_changed format a2 heading "ch" + +break on stat_name; + + select o.name as stat_name + , o.sql_feature + , o.isdefault + , decode (upper (o.value), upper (pv.value), '-', '>>') as is_session_changed + , o.value + , pv.value as inst_value + , s.inst_id + , s.username + , count (*) as session_count + from gv$ses_optimizer_env o, gv$session s, gv$parameter pv + where s.sid = o.sid + and s.inst_id = o.inst_id + and s.inst_id = pv.inst_id(+) + and upper (o.name) = upper (pv.name) + and s.username like upper ('&&USER_NAME.%') +group by s.inst_id + , s.username + , o.NAME + , o.SQL_FEATURE + , o.ISDEFAULT + , decode (upper (o.value), upper (pv.value), '-', '>>') + , o.value + , pv.value +order by o.isdefault + , o.NAME + , s.inst_id + , s.username +/ + +clear break + diff --git a/session_user_env.sql b/session_user_env.sql new file mode 100644 index 0000000..a887eec --- /dev/null +++ b/session_user_env.sql @@ -0,0 +1,95 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show all enviroments settings with SYS_CONTEXT +-- +-- +--============================================================================== +set linesize 130 pagesize 300 +set serveroutput on + +declare + + TYPE settings_tab IS TABLE OF VARCHAR2(2000) INDEX BY BINARY_INTEGER; + v_settings settings_tab; + +begin + + v_settings(1):='ACTION'; + v_settings(2):='AUDITED_CURSORID'; + v_settings(3):='AUTHENTICATED_IDENTITY'; + v_settings(4):='AUTHENTICATION_DATA'; + v_settings(5):='AUTHENTICATION_METHOD'; + v_settings(6):='BG_JOB_ID'; + v_settings(7):='CLIENT_IDENTIFIER'; + v_settings(8):='CLIENT_INFO'; + v_settings(9):='CURRENT_BIND'; + v_settings(10):='CURRENT_EDITION_ID'; + v_settings(11):='CURRENT_EDITION_NAME'; + v_settings(12):='CURRENT_SCHEMA'; + v_settings(13):='CURRENT_SCHEMAID'; + v_settings(14):='CURRENT_SQL'; + v_settings(15):='CURRENT_SQL1'; + v_settings(16):='CURRENT_SQL2'; + v_settings(17):='CURRENT_SQL3'; + v_settings(18):='CURRENT_SQL_LENGTH'; + v_settings(19):='CURRENT_USER'; + v_settings(20):='CURRENT_USERID'; + v_settings(21):='DATABASE_ROLE'; + v_settings(22):='DB_DOMAIN'; + v_settings(23):='DB_NAME'; + v_settings(24):='DB_UNIQUE_NAME'; + v_settings(25):='DBLINK_INFO'; + v_settings(26):='ENTRYID'; + v_settings(27):='ENTERPRISE_IDENTITY'; + v_settings(28):='FG_JOB_ID'; + v_settings(29):='GLOBAL_CONTEXT_MEMORY'; + v_settings(30):='GLOBAL_UID'; + v_settings(31):='HOST'; + v_settings(32):='IDENTIFICATION_TYPE'; + v_settings(33):='INSTANCE'; + v_settings(34):='INSTANCE_NAME'; + v_settings(35):='IP_ADDRESS'; + v_settings(36):='ISDBA'; + v_settings(37):='LANG'; + v_settings(38):='LANGUAGE'; + v_settings(39):='MODULE'; + v_settings(40):='NETWORK_PROTOCOL'; + v_settings(41):='NLS_CALENDAR'; + v_settings(42):='NLS_CURRENCY'; + v_settings(43):='NLS_DATE_FORMAT'; + v_settings(44):='NLS_DATE_LANGUAGE'; + v_settings(45):='NLS_SORT'; + v_settings(46):='NLS_TERRITORY'; + v_settings(47):='OS_USER'; + v_settings(48):='POLICY_INVOKER'; + v_settings(49):='PROXY_ENTERPRISE_IDENTITY'; + v_settings(50):='PROXY_USER'; + v_settings(51):='PROXY_USERID'; + v_settings(52):='SERVER_HOST'; + v_settings(53):='SERVICE_NAME'; + v_settings(54):='SESSION_EDITION_ID'; + v_settings(55):='SESSION_EDITION_NAME'; + v_settings(56):='SESSION_USER'; + v_settings(57):='SESSION_USERID'; + v_settings(58):='SESSIONID'; + v_settings(59):='SID'; + v_settings(60):='STATEMENTID'; + v_settings(61):='TERMINAL'; + + + dbms_output.put_line('--'); + dbms_output.put_line('-- Check the Setting for your SYS Context of the USERENV'); + dbms_output.put_line('-- -----------------------------------------------------'); + + FOR i IN v_settings.FIRST .. v_settings.LAST + loop + begin + dbms_output.put_line('-- Setting for '||rpad(v_settings(i),24)||' is :: '||SYS_CONTEXT ('USERENV',v_settings(i))); + exception + when others then + dbms_output.put_line('-- Setting for '||rpad(v_settings(i),24)||' ERROR :: '||SQLERRM); + end; + end loop; + dbms_output.put_line('-- -----------------------------------------------------'); +end; +/ \ No newline at end of file diff --git a/session_user_nls_lang.sql b/session_user_nls_lang.sql new file mode 100644 index 0000000..11c3bd9 --- /dev/null +++ b/session_user_nls_lang.sql @@ -0,0 +1,35 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show all enviroments settings with SYS_CONTEXT +-- +-- +--============================================================================== +set linesize 130 pagesize 300 +set serveroutput on + +set serveroutput on + +DECLARE + v_tns VARCHAR2 (100); +BEGIN + + SYS.DBMS_SYSTEM.get_env ('TNS_ADMIN', v_tns); + DBMS_OUTPUT.put_line ( RPAD('TNS_ADMIN',20,' ')||' :: '||v_tns); + + SYS.DBMS_SYSTEM.get_env ('ORACLE_HOME', v_tns); + DBMS_OUTPUT.put_line ( RPAD('ORACLE_HOME',20,' ')||' :: '||v_tns); + + SYS.DBMS_SYSTEM.get_env ('ORACLE_BASE', v_tns); + DBMS_OUTPUT.put_line ( RPAD('ORACLE_BASE',20,' ')||' :: '||v_tns); + + SYS.DBMS_SYSTEM.get_env ('NLS_LANG', v_tns); + DBMS_OUTPUT.put_line ( RPAD('NLS_LANG',20,' ')||' :: '||v_tns); + + SYS.DBMS_SYSTEM.get_env ('TEMP', v_tns); + DBMS_OUTPUT.put_line ( RPAD('TEMP',20,' ')||' :: '||v_tns); + + SYS.DBMS_SYSTEM.get_env ('OS', v_tns); + DBMS_OUTPUT.put_line ( RPAD('OS',20,' ')||' :: '||v_tns); + +END; +/ \ No newline at end of file diff --git a/sessions.sql b/sessions.sql new file mode 100644 index 0000000..4bc41b5 --- /dev/null +++ b/sessions.sql @@ -0,0 +1,85 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: actual connections to the database +-- Date: 01.September 2012 +--============================================================================== +set verify off +set linesize 140 pagesize 300 + +define USER_NAME = &1 +define ALL_PROCESS = '&2' + +prompt +prompt Parameter 1 = Username => &&USER_NAME. +prompt Parameter 2 = to Show all use Y => &&ALL_PROCESS. +prompt + +ttitle left "All User Sessions on this DB" skip 2 + +column inst_id format 99 heading "Inst|ID" +column username format a12 heading "DB User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column machine format a15 heading "Remote|pc/server" +column terminal format a14 heading "Remote|terminal" +column program format a15 heading "Remote|program" +column module format a16 heading "Remote|module" +column client_info format a10 heading "Client|info" +column client_identifier format A10 heading "Client|identifier" +column OSUSER format a13 heading "OS|User" +column LOGON_TIME format a12 heading "Logon|Time" +column status format a8 heading "Status" + + select inst_id + , sid + , serial# + , status + , username + , machine + --, terminal + , program + , OSUSER + , module + , to_char (LOGON_TIME, 'dd.mm hh24:mi') as LOGON_TIME + , client_identifier + , client_info + from gv$session + where ( username like upper ('%&&USER_NAME.%') + or ( nvl ('&ALL_PROCESS.', 'N') = 'Y' + and username is null)) +order by program, inst_id +/ + +ttitle left "User Sessions Summary on this DB" skip 2 + +column cs format 9999 +column program format A60 +column username format A20 + +column DUMMY noprint; +compute sum of cs on DUMMY +break on DUMMY; + + select null dummy + , count (*) as cs + , username + , program + from gv$session + where username is not null +group by username, program +order by username +/ + +clear break + +ttitle off + +show parameter processes +show parameter sessions + +prompt +prompt ... to kill session "ALTER SYSTEM KILL SESSION 'sid,serial#,@inst_id';" +prompt ... to end session "ALTER SYSTEM DISCONNECT SESSION 'sid,serial#' IMMEDIATE;" +prompt ... +prompt ... On MS Windows you can use "orakill ORACLE_SID spid" to kill from the OS the session +prompt \ No newline at end of file diff --git a/sessions_killed.sql b/sessions_killed.sql new file mode 100644 index 0000000..6c7105f --- /dev/null +++ b/sessions_killed.sql @@ -0,0 +1,47 @@ +-- =================================================================== +-- GPI - Gunther Pippèrr +-- get the process of a session marked for killed +-- =================================================================== +-- +-- see How To Find The Process Identifier (pid, spid) After The Corresponding Session Is Killed? (Doc ID 387077.1) +-- =================================================================== + +set verify off +set linesize 130 pagesize 300 + +ttitle left "Processes without entries in the v$session" skip 2 + +column process_id format a8 heading "Process|ID" +column inst_id format 99 heading "Inst|ID" +column username format a8 heading "DB User|name" +column osusername format a8 heading "OS User|name" +column pname format a8 heading "Process|name" + +select --p.inst_id + to_char(p.spid) as process_id + , p.username as osusername + , p.pname + , p.program +from v$process p + where p.program!= 'PSEUDO' + and p.addr not in (select gv.paddr from v$session gv) + and p.addr not in (select bg.paddr from v$bgprocess bg) + and p.addr not in (select ss.paddr from v$shared_server ss) + --order by p.inst_id +/ + +-- new column creator_addr in v$session! + +ttitle left "get the prozess of a killed session with the help of the creator_addr" skip 2 + +select --p.inst_id + to_char(p.spid) as process_id + , p.username as osusername + , p.pname + , p.program +from v$process p + where p.addr in (select gv.creator_addr from v$session gv where status in ('KILLED') ) +/ + +ttitle off + diff --git a/set_bg_color_ps.sql b/set_bg_color_ps.sql new file mode 100644 index 0000000..2416cf3 --- /dev/null +++ b/set_bg_color_ps.sql @@ -0,0 +1,6 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: only for ms powerschell +--============================================================================== + +$ (get-host).UI.RawUI.Backgroundcolor="DarkRed" \ No newline at end of file diff --git a/set_linux_title.sql b/set_linux_title.sql new file mode 100644 index 0000000..86ef4ca --- /dev/null +++ b/set_linux_title.sql @@ -0,0 +1,9 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: set the title of the xterm +-- not in use at the moment +--============================================================================== + +-- ! settitle "Server :: &2 ++ Database :: &1" + +DEFINE _EDITOR=vi diff --git a/set_no_titel.sql b/set_no_titel.sql new file mode 100644 index 0000000..49b2047 --- /dev/null +++ b/set_no_titel.sql @@ -0,0 +1,4 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Script do do nothing +--============================================================================== \ No newline at end of file diff --git a/set_windows_title.sql b/set_windows_title.sql new file mode 100644 index 0000000..8fccaa6 --- /dev/null +++ b/set_windows_title.sql @@ -0,0 +1,7 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: set the title +--============================================================================== + +$ title DB :: &1 ++ Server :: &2 +DEFINE _EDITOR=notepad \ No newline at end of file diff --git a/sga.sql b/sga.sql new file mode 100644 index 0000000..e39d72e --- /dev/null +++ b/sga.sql @@ -0,0 +1,70 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Informations about sga usage in the database +-- Date: 08.2013 +-- +-- http://docs.oracle.com/cd/B28359_01/server.111/b28320/dynviews_2058.htm#REFRN30463 +--============================================================================== +set linesize 130 pagesize 300 + +-- sga infos + +ttitle left "SGA Pools" skip 2 + +show sga + +ttitle left "Dynamic SGA Componentes" skip 2 + +column component format a20 heading "Component" WORD_WRAPPED +column current_size format 99G999D99 heading "Cur|Size MB" +column min_size format 99G999D99 heading "Min|Size MB" +column max_size format 99G999D99 heading "Max|Size MB" +column user_specified_size format 99G999D99 heading "UserDef|Size MB" +column oper_count format 9999999 heading "OP|count" +column last_oper_type format a12 heading "OP|type" +column last_oper_mode format a15 heading "OP|mode" +column last_oper_time format a18 heading "OP|time" +column granule_size format 999999 heading "Granule|size KB" + +select component + , round(current_size/1024/1024,2) as current_size + , round(min_size/1024/1024,2) as min_size + , round(max_size/1024/1024,2) as max_size + , round(user_specified_size/1024/1024,2) as user_specified_size + , oper_count + , nvl(last_oper_type,'-') as last_oper_type + , nvl(last_oper_mode,'-') as last_oper_mode + , nvl(to_char(last_oper_time,'dd.mm.yyyy hh24:mi'),'never') as last_oper_time + , round(granule_size/1024,2) as granule_size + from v$memory_dynamic_components +order by 1 desc + / + +ttitle left "SGA Advisory" skip 2 + +select * from v$sga_target_advice + order by 1 +/ + + +ttitle left "Library Cache hits" skip 2 + +select sum(pins) "hits" + , sum(reloads) "misses" + , round((sum(pins)/(sum(reloads)+sum(pins)))*100, 2) "hit ratio, %" +from v$librarycache +/ + + +ttitle left "Buffer Cache hit statistic" skip 2 + +select round((1-(pr.value/(bg.value+cg.value)))*100,2) "Buffer Cache Hit Ratio" + from v$sysstat pr + , v$sysstat bg + , v$sysstat cg +where pr.name='physical reads' + and bg.name='db block gets' + and cg.name='consistent gets' +/ + +ttitle off \ No newline at end of file diff --git a/space_tablespace.sql b/space_tablespace.sql new file mode 100644 index 0000000..08b15de --- /dev/null +++ b/space_tablespace.sql @@ -0,0 +1,116 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: SQL Script to check the size of a table +-- thanks to Christian Gärber for create alter database file statement +-- Date: 08.2013 +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + + +define TABLESPACE = "&1" + + +prompt +prompt Parameter 1 = Tablespace Name => '&TABLESPACE' +prompt + + +ttitle left "Space of the the table space" skip 2 + +-- get the free size in the tablespace +-- +column tablespace_name format a20 heading "Table space|name" +column SIZE_MB format 99G999G999D99 heading "Size MB|total" +column max_used_mb format 99G999G999D99 heading "Size MB|used" +column freeable_mb format 99G999G999D99 heading "Size MB|freeable" +column file_id format 99 heading "File|id" +column file_name format a23 heading "File|name" + +select sum(freeable_mb)from ( +select s.tablespace_name + , s.bytes / 1024 / 1024 as SIZE_MB + , (e.max_data_block_id * et.BLOCK_SIZE / 1024 / 1024) as max_used_mb + , (s.bytes - e.max_data_block_id * et.BLOCK_SIZE) / 1024 / 1024 as freeable_mb + , s.file_id + , '..'||substr(s.file_name,length(s.file_name)-20,20) file_name + from dba_data_files s + , (select file_id + , max(block_id + blocks) + 1 max_data_block_id + , tablespace_name + from dba_extents + where tablespace_name like upper('&TABLESPACE.') + group by file_id,tablespace_name) e + , dba_tablespaces et + where s.FILE_ID = e.file_id + and s.TABLESPACE_NAME = et.TABLESPACE_NAME + and e.TABLESPACE_NAME =et.TABLESPACE_NAME + and et.TABLESPACE_NAME like upper('&TABLESPACE.') +) +/ + +-- to slow ..... + +--ttitle left "The last 5 Objects inside the tablespace" skip 2 +-- +--column owner format a15 heading "Owner" +--column segment_name format a25 heading "Segment|name" +--column partition_name format a20 heading "Partition|name" +--column segment_type format a10 heading "Segment|type" +--column file_id format 99 heading "File|id" +--column block_id format 9999999 heading "Block|id" +-- +-- get the last Object in this tablespace +-- +--select e.owner +-- ,e.segment_name +-- ,nvl(e.partition_name,'n/a') as partition_name +-- ,e.segment_type +-- ,e.block_id +-- ,e.file_id +-- from dba_extents e +--where tablespace_name like upper('&TABLESPACE.') +-- and (file_id,block_id) in (select file_id,block_id +-- from ( +-- select file_id +-- , block_id +-- , rank() over (order by block_id desc) as row_rank +-- from dba_extents +-- where tablespace_name like upper('&TABLESPACE.') +-- group by file_id,block_id +-- ) +-- where row_rank between 1 and 5 ) +--order by block_id desc +--/ + + +ttitle left "DLL to shrink the the table space" skip 2 +-- create the alter script +-- +column command format a100 + +select 'alter database datafile ''' || s.file_name || ''' resize ' ||round(e.max_data_block_id * et.BLOCK_SIZE / 1024 / 1024 + 1, 0) || 'M;' as command + from dba_data_files s + , (select file_id + ,max(block_id + blocks) + 1 max_data_block_id + ,tablespace_name + from dba_extents + where tablespace_name like upper('&TABLESPACE.') + group by file_id,tablespace_name) e + , dba_tablespaces et + where s.FILE_ID = e.file_id + and s.TABLESPACE_NAME = et.TABLESPACE_NAME + and e.TABLESPACE_NAME =et.TABLESPACE_NAME + and et.TABLESPACE_NAME like upper('&TABLESPACE.') + and (s.bytes - e.max_data_block_id * et.BLOCK_SIZE) / 1024 / 1024 > 10 +/ + +ttitle off + + + + + + + \ No newline at end of file diff --git a/space_tablespace_auto.sql b/space_tablespace_auto.sql new file mode 100644 index 0000000..1ad3cf6 --- /dev/null +++ b/space_tablespace_auto.sql @@ -0,0 +1,65 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script to shrink the tablespace +-- Doku: http://www.pipperr.de/dokuwiki/doku.php?id=dba:sql_groesse_tabelle +-- Date: 08.2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +set feedback OFF +set heading OFF +set trimspool on + +--------------------------------------- +-- create the spool file +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_shrink_database.sql','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ +--------------------------------------- + +spool &&SPOOL_NAME + +prompt spool &&SPOOL_NAME._log + +--------------------------------------- +-- create the alter script +-- +column command format a100 + +select '-- Info -- try to free:: '||round((s.bytes - e.max_data_block_id * et.BLOCK_SIZE) / 1024 / 1024,3) ||' MB'||chr(13)||chr(10)||'alter database datafile ' ||chr(13)||chr(10)||''''||s.file_name||''''||chr(13)||chr(10)||'resize ' ||round(e.max_data_block_id * et.BLOCK_SIZE / 1024 / 1024 + 1, 0) || 'M;' as command + from dba_data_files s + , (select file_id + ,max(block_id + blocks) + 1 max_data_block_id + ,tablespace_name + from dba_extents + group by file_id,tablespace_name) e + , dba_tablespaces et + where s.FILE_ID = e.file_id + and s.TABLESPACE_NAME = et.TABLESPACE_NAME + and e.TABLESPACE_NAME =et.TABLESPACE_NAME + and (s.bytes - e.max_data_block_id * et.BLOCK_SIZE) / 1024 / 1024 > 10 +/ +--------------------------------------- + +prompt spool off + +spool off +--------------------------------------- +-- call the script +@&&SPOOL_NAME +--------------------------------------- + +set verify ON +set feedback ON +set heading ON +set trimspool OFF +set recsep WRAP + + + + \ No newline at end of file diff --git a/sql_baseline.sql b/sql_baseline.sql new file mode 100644 index 0000000..56aacb4 --- /dev/null +++ b/sql_baseline.sql @@ -0,0 +1,38 @@ +--============================================================================== +-- +-- get all Baselines in the database +-- see +-- +-- http://oracle-base.com/articles/11g/sql-plan-management-11gr1.php +-- https://blogs.oracle.com/optimizer/entry/what_is_the_different_between +-- https://blogs.oracle.com/optimizer/entry/sql_plan_management_part_1_of_4_creating_sql_plan_baselines +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +column SQL_TEXT format a23 +column SQL_HANDLE format a20 +column PARSING_SCHEMA_NAME format a14 +column PLAN_NAME format a30 +column ORIGIN format a16 +column CREATED_TEXT format a18 +column ENABLED format a3 heading "Ena|bld" +column ACCEPTED format a3 heading "Ac|ted" + + + select SQL_HANDLE + , replace (replace (substr (SQL_TEXT, 1, 20) || ' ..', chr (10), ''), ' ', ' ') as SQL_TEXT + , PARSING_SCHEMA_NAME + , PLAN_NAME + , ORIGIN + , to_char (CREATED, 'dd.mm.yyyy hh24:mi') as CREATED_TEXT + , ENABLED + , ACCEPTED + from DBA_SQL_PLAN_BASELINES +order by CREATED +/ + + + + diff --git a/sql_baseline_evolve.sql b/sql_baseline_evolve.sql new file mode 100644 index 0000000..722771f --- /dev/null +++ b/sql_baseline_evolve.sql @@ -0,0 +1,28 @@ +--============================================================================== +-- +-- Test all execution Plans of a baseline and try to find the best plan +--============================================================================== +-- +-- https://blogs.oracle.com/optimizer/entry/sql_plan_management_part_3_of_4_evolving_sql_plan_baselines_1 +-- +-- Non-accepted plans can be verified by executing the evolve_sql_plan_baseline function. +-- This function will execute the non-accepted plan and compare its performance to the best accepted plan. +-- The execution is performed using the conditions (e.g., bind values, parameters, etc.) in effect at the time the non-accepted plan was added to the plan history. +-- If the non-accepted plan's performance is better, the function will make it accepted, thus adding it to the SQL plan baseline. +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +set long 10000 + +define SQL_HANDEL=&1 + +prompt +prompt Parameter 1 = SQL_HANDEL => &&SQL_HANDEL. +prompt + +select dbms_spm.evolve_sql_plan_baseline(sql_handle => '&&SQL_HANDEL.') + from dual +/ + diff --git a/sql_baseline_plan.sql b/sql_baseline_plan.sql new file mode 100644 index 0000000..5136939 --- /dev/null +++ b/sql_baseline_plan.sql @@ -0,0 +1,28 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- get the plan of a plan in a baseline +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +set long 10000 + +define SQL_BASELINE_PLAN=&1 + +prompt +prompt Parameter 1 = SQL_BASELINE_PLAN => &&SQL_BASELINE_PLAN. +prompt +-- +--select * +-- from table(dbms_xplan.display_sql_plan_baseline( plan_name=>'&&SQL_BASELINE_PLAN.' +-- ,format =>'BASIC ROWS BYTES COST') +-- ) +--/ +-- + +select * + from table(dbms_xplan.display_sql_plan_baseline( plan_name=>'&&SQL_BASELINE_PLAN.' + ,format =>'outline') + ) +/ diff --git a/sql_find.sql b/sql_find.sql new file mode 100644 index 0000000..bc6ea9c --- /dev/null +++ b/sql_find.sql @@ -0,0 +1,48 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: find the sql statement in the sql cache +-- Date: September 2013 +-- +--=============================================================================== +set verify off +set linesize 130 pagesize 800 + +define SQL_STATEMENT = &1 + + +prompt +prompt Parameter 1 = SQL_STATEMENT => &&SQL_STATEMENT. +prompt + +ttitle left "Search SQL from Cursor Cache for this text string : &SQL_STATEMENT." skip 2 + +column sql_text format a35 heading "SQL|Text" +column sql_id format a13 heading "SQL|ID" +column INST_ID format 99 heading "In|st" +column parsing_user_name format a10 heading "Parsing|Schema" +column executions format 999G999G999 heading "Exec" +column buffer_gets format 999G999G999 heading "Buffer|Gets" +column disk_reads format 999G999G999 heading "Disks|Reads" +column cpu_time format 999G999G999 heading "Cpu|Time" +column sorts format 999G999G999 heading "Sorts" + +select SQL_ID + , INST_ID + , (select username from dba_users where user_id=parsing_user_id) as parsing_user_name + , sorts + , executions + , buffer_gets + , disk_reads + , cpu_time + , sql_text + , LAST_LOAD_TIME + /* GPI SQL Analyse */ + from gv$sqlarea +where upper(sql_text) like upper('%&&SQL_STATEMENT.%') + and sql_text not like '%GPI SQL Analyse%' +order by SQL_ID,INST_ID +/ + +prompt ... to get the execution plan call awr_sql.sql with the sql_id + +ttitle off diff --git a/sql_kill_session.sql b/sql_kill_session.sql new file mode 100644 index 0000000..d0001ce --- /dev/null +++ b/sql_kill_session.sql @@ -0,0 +1,26 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: create the command to kill all sessions running this SQL at the moment +-- parameter 1 - SQL ID +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define SQL_ID='&1' + +prompt +prompt Parameter 1 = SQL ID => &&SQL_ID. +prompt + +select 'ALTER SYSTEM KILL SESSION '''||sid||','||serial#||',@'||inst_id||''';' + from gv$session + where SQL_ID in ('&&SQL_ID.') + and status ='ACTIVE' +/ + +select 'ALTER SYSTEM DISCONNECT SESSION '''||sid||','||serial#||''' IMMEDIATE;' + from v$session + where sql_id='&&SQL_ID.' +/ + + diff --git a/sql_opt_settings.sql b/sql_opt_settings.sql new file mode 100644 index 0000000..50d2769 --- /dev/null +++ b/sql_opt_settings.sql @@ -0,0 +1,26 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Show the optimizer settings for this statement +-- parameter 1 - SQL ID +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define SQL_ID='&1' + +prompt +prompt Parameter 1 = SQL ID => &&SQL_ID. +prompt + +break on child_number skip 1 + +select child_number + , name + , value + from v$sql_optimizer_env + where sql_id = '&&SQL_ID.' +order by child_number + , name +/ + +clear break \ No newline at end of file diff --git a/sql_parallel.sql b/sql_parallel.sql new file mode 100644 index 0000000..51d9c22 --- /dev/null +++ b/sql_parallel.sql @@ -0,0 +1,167 @@ +--============================================================================== +-- see also: +-- Oracle Support Document 444164.1 (Tracing Parallel Execution with _px_trace. Part I) +-- can be found at: https://support.oracle.com/epmos/faces/DocumentDisplay?id=444164.1 +-- https://docs.oracle.com/cd/E18283_01/server.112/e16541/parallel006.htm#CIHGJFFC +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define SQL_ID='&1' + +prompt +prompt Parameter 1 = SQL ID => &&SQL_ID. +prompt + +column username format a12 +column "QC SID" format A6 +column "SID" format A6 +column "QC/Slave" format A8 +column "Req. DOP" format 9999 +column "Actual DOP" format 9999 +column "Slaveset" format A8 +column "Slave INST" format A9 +column "QC INST" format A6 +column wait_event format a30 + +ttitle left "User and his Parallel sessions" skip 2 + + +select decode (px.qcinst_id + , null, username + , ' - ' + || lower (substr (pp.server_name + , length (pp.server_name) + - 4 + , 4))) + "Username" + , decode (px.qcinst_id, null, 'QC', '(Slave)') "QC/Slave" + , to_char (px.server_set) "SlaveSet" + , to_char (s.sid) "SID" + , to_char (px.inst_id) "Slave INST" + , decode (sw.state, 'WAITING', 'WAIT', 'NOT WAIT') as state + , case sw.state when 'WAITING' then substr (sw.event, 1, 30) else null end as wait_event + , decode (px.qcinst_id, null, to_char (s.sid), px.qcsid) "QC SID" + , to_char (px.qcinst_id) "QC INST" + , px.req_degree "Req. DOP" + , px.degree "Actual DOP" + , s.sql_id + from gv$px_session px + , gv$session s + , gv$px_process pp + , gv$session_wait sw + where px.sid = s.sid(+) + and px.serial# = s.serial#(+) + and px.inst_id = s.inst_id(+) + and px.sid = pp.sid(+) + and px.serial# = pp.serial#(+) + and sw.sid = s.sid + and sw.inst_id = s.inst_id + and s.sql_id like '&&SQL_ID.' +order by decode (px.qcinst_id, null, px.inst_id, px.qcinst_id) + , px.qcsid + , decode (px.server_group, null, 0, px.server_group) + , px.server_set + , px.inst_id +/ + + +column wait_event format a30 + +ttitle left "Waits this SQL &&SQL_ID. " skip 2 + +select sw.sid as rcvsid + , decode (pp.server_name, null, 'A QC', pp.server_name) as rcvr + , sw.inst_id as rcvrinst + , case sw.state when 'WAITING' then substr (sw.event, 1, 30) else null end as wait_event + , decode (bitand (sw.p1, 65535), 65535, 'QC', 'P' || to_char (bitand (sw.p1, 65535), 'fm000')) as sndr + , bitand (sw.p1, 16711680) + - 65535 + as sndrinst + , decode (bitand (sw.p1, 65535) + , 65535, ps.qcsid + , (select sid + from gv$px_process + where server_name = 'P' || to_char (bitand (sw.p1, 65535), 'fm000') + and inst_id = bitand (sw.p1, 16711680) + - 65535)) + as sndrsid + , decode (sw.state, 'WAITING', 'WAIT', 'NOT WAIT') as state + from gv$session_wait sw + , gv$px_process pp + , gv$px_session ps + , gv$session s + where sw.sid = pp.sid(+) + and sw.inst_id = pp.inst_id(+) + and sw.sid = ps.sid(+) + and sw.inst_id = ps.inst_id(+) + and sw.p1text = 'sleeptime/senderid' + and bitand (sw.p1, 268435456) = 268435456 + and s.sql_id like '&&SQL_ID.' + and sw.sid = s.sid + and sw.inst_id = s.inst_id +order by decode (ps.qcinst_id, null, ps.inst_id, ps.qcinst_id) + , ps.qcsid + , decode (ps.server_group, null, 0, ps.server_group) + , ps.server_set + , ps.inst_id +/ + + +column "Username" format a12 heading "Username" +column "QC/Slave" format A8 heading "QCSlave" +column "Slaveset" format A8 heading "Slave|set" +column "Slave INST" format A9 heading "Slave|INST" +column "QC SID" format A6 heading "QC|SID" +column "QC INST" format A6 heading "QC|INST" +column "operation_name" format A25 heading "Operation|name" +column "target" format A20 heading "Target" + + +ttitle left "Long Ops for this SQL &&SQL_ID. " skip 2 + + +select decode (px.qcinst_id + , null, s.username + , ' - ' + || lower (substr (pp.server_name + , length (pp.server_name) + - 4 + , 4))) + "Username" + , decode (px.qcinst_id, null, 'QC', '(Slave)') "QC/Slave" + , to_char (px.server_set) "SlaveSet" + , to_char (px.inst_id) "Slave INST" + , substr (s.opname, 1, 30) operation_name + , substr (s.target, 1, 30) target + , s.sofar + , s.totalwork + , s.totalwork + - s.sofar + as openwork + , s.units + , s.start_time + , s.timestamp + , decode (px.qcinst_id, null, to_char (s.sid), px.qcsid) "QC SID" + , to_char (px.qcinst_id) "QC INST" + from gv$px_session px + , gv$px_process pp + , gv$session_longops s + , gv$session se + where px.sid = s.sid + and px.serial# = s.serial# + and px.inst_id = s.inst_id + and px.sid = pp.sid(+) + and px.serial# = pp.serial#(+) + and pp.inst_id = s.inst_id + and se.sql_id like '&&SQL_ID.' + and s.sid = se.sid + and s.inst_id = se.inst_id +order by decode (px.qcinst_id, null, px.inst_id, px.qcinst_id) + , px.qcsid + , decode (px.server_group, null, 0, px.server_group) + , px.server_set + , px.inst_id +/ + +ttitle off diff --git a/sql_plan.sql b/sql_plan.sql new file mode 100644 index 0000000..131ce1f --- /dev/null +++ b/sql_plan.sql @@ -0,0 +1,49 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: get the sql execution plan for this sql id from Cursor Cache +-- Date: September 2013 +-- +--============================================================================== +-- http://psoug.org/reference/dbms_xplan.html +-- +-- http://docs.oracle.com/cd/B19306_01/appdev.102/b14258/d_xplan.htm +-- +-- format +-- +-- Controls the level of details for the plan. It accepts four values: +-- +-- BASIC: Displays the minimum information in the plan—the operation ID, the operation name and its option. +-- TYPICAL: This is the default. Displays the most relevant information in the plan (operation id, name and option, #rows, #bytes and optimizer cost). Pruning, parallel and predicate information are only displayed when applicable. Excludes only PROJECTION, ALIAS and REMOTE SQL information (see below). +-- SERIAL: Like TYPICAL except that the parallel information is not displayed, even if the plan executes in parallel. +-- ALL: Maximum user level. Includes information displayed with the TYPICAL level with additional information (PROJECTION, ALIAS and information about REMOTE SQL if the operation is distributed). +-- +-- For finer control on the display output, the following keywords can be added to the above three standard format options to customize their default behavior. Each keyword either represents a logical group of plan table columns (such as PARTITION) or logical additions to the base plan table output (such as PREDICATE). Format keywords must be separated by either a comma or a space: +-- ROWS - if relevant, shows the number of rows estimated by the optimizer +-- BYTES - if relevant, shows the number of bytes estimated by the optimizer +-- COST - if relevant, shows optimizer cost information +-- PARTITION - if relevant, shows partition pruning information +-- PARALLEL - if relevant, shows PX information (distribution method and table queue information) +-- PREDICATE - if relevant, shows the predicate section +-- PROJECTION -if relevant, shows the projection section +-- ALIAS - if relevant, shows the "Query Block Name / Object Alias" section +-- REMOTE - if relevant, shows the information for distributed query (for example, remote from serial distribution and remote SQL) +-- NOTE - if relevant, shows the note section of the explain plan +-- +-- For RAC see https://carlos-sierra.net/2013/06/17/using-dbms_xplan-to-display-cursor-plans-for-a-sql-in-all-rac-nodes/ +-- +--============================================================================== + +define SQL_ID = &1 + +set verify off +set linesize 190 pagesize 300 + +ttitle left "SQL Plan from Cursor Cache ID: &SQL_ID." skip 2 + +column out_put format a190 heading "SQL Plan Output" + +select PLAN_TABLE_OUTPUT as out_put + from TABLE(DBMS_XPLAN.DISPLAY_CURSOR('&SQL_ID.',null,'TYPICAL')) +/ + +ttitle off diff --git a/sql_profile.sql b/sql_profile.sql new file mode 100644 index 0000000..6fae6d4 --- /dev/null +++ b/sql_profile.sql @@ -0,0 +1,82 @@ +-- ============================================================================== +-- GPI - Gunther Pippèrr +-- show all created sql profiles in this database +-- Must be run with dba privileges +-- see +-- ============================================================================== +-- +-- desc dba_sql_profiles +-- ------------------------------------ +-- NAME NOT NULL VARCHAR2(30) +-- CATEGORY NOT NULL VARCHAR2(30) +-- SIGNATURE NOT NULL NUMBER +-- SQL_TEXT NOT NULL CLOB +-- CREATED NOT NULL TIMESTAMP(6) +-- LAST_MODIFIED TIMESTAMP(6) +-- DESCRIPTION VARCHAR2(500) +-- TYPE VARCHAR2(7) +-- STATUS VARCHAR2(8) +-- FORCE_MATCHING VARCHAR2(3) +-- TASK_ID NUMBER +-- TASK_EXEC_NAME VARCHAR2(30) +-- TASK_OBJ_ID NUMBER +-- TASK_FND_ID NUMBER +-- TASK_REC_ID NUMBER +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +column name format a30 heading "Profile|Name" +column category format a12 heading "Category|Name" +column description format a12 heading "Description" +column type format a6 heading "Type" +column status format a7 heading "Status" +column force_matching format a3 heading "For|Mch" +column sql_text format a30 word_wrapped + +set long 64000 + +ttitle "All Profiles in the database" skip 2 + + select name + , category + -- , signature + , substr (sql_text, 1, 100) as sql_text + -- , to_char(created,'dd.mm.RR hh24:mi') as created + , to_char (last_modified, 'dd.mm.RR hh24:mi') as created + , description + , type + , status + , force_matching + --, TASK_ID + -- , TASK_EXEC_NAME + -- , TASK_OBJ_ID + -- , TASK_FND_ID + -- , TASK_REC_ID + from dba_sql_profiles +order by last_modified desc, name +/ + + +ttitle "check the SQL Profiles in use" skip 2 + +select vs.inst_id + , vs.sql_id + , pf.name + --, substr(pf.sql_text,1,100) as sql_text + , to_char (last_modified, 'dd.mm.RR hh24:mi') as created + from gv$sql vs, dba_sql_profiles pf + where pf.name = vs.sql_profile + and SQL_PROFILE is not null +--order by substr(to_char(pf.sql_text),1,100) +/ + +prompt ... +prompt to delete a profile use exec dbms_sqltune.drop_sql_profile( name => 'SYS_SQLPROF_xxx'); +prompt to rename a profile use exec dbms_sqltune.alter_sql_profile( name => 'SYS_SQLPROF_xxx', attribute_name => 'NAME', VALUE => 'GPI_BUG_1078' ); +prompt ... + +ttitle off + diff --git a/sql_profile_details.sql b/sql_profile_details.sql new file mode 100644 index 0000000..afc7e03 --- /dev/null +++ b/sql_profile_details.sql @@ -0,0 +1,56 @@ +-- ============================================================================== +-- Show the detail hints from +-- Must be run with dba privileges +-- see +-- http://antognini.ch/2008/08/sql-profiles-in-data-dictionary/ +-- http://antognini.ch/papers/SQLProfiles_20060622.pdf +-- +-- ============================================================================== +set verify off +set linesize 130 pagesize 300 + +define PROF_NAME = '&1' + +prompt +prompt Parameter 1 = Tab Name => &&PROF_NAME. +prompt + +column hint format a120 WORD_WRAPPED + +SELECT extractValue(value(h),'.') AS hint + FROM sys.sqlobj$data od + , sys.sqlobj$ so + , table(xmlsequence(extract(xmltype(od.comp_data),'/outline_data/hint'))) h + WHERE upper(so.name) like upper('&&PROF_NAME.') + AND so.signature = od.signature + AND so.category = od.category + AND so.obj_type = od.obj_type + AND so.plan_id = od.plan_id +/ + + +/* 10g + +select h.attr_val as outline_hints + from dba_sql_profiles p + ,sys.sqlprof$attr h + where p.signature = h.signature + and p.category = h.category + and p.name like upper('&&PROF_NAME.') + order by h.attr# + / + +-- aus AWR +-- muss aber im AWR sein! + +SELECT plan_table_output FROM TABLE(dbms_xplan.display_awr('SQL_ID','PLAN_HASH',NULL,'OUTLINE')) + +DBMS_SQLTUNE.IMPORT_SQL_PROFILE( + SQL_TEXT => SQL_FTEXT, + PROFILE => SQLPROF_ATTR('FULL(@"SEL$1" "OBJECTS"@"SEL$1") FULL(@"SEL$1" "SEGMENTS"@"SEL$1")'), + NAME => 'PROFILE_gy6fj888vt27y', + REPLACE => TRUE, + FORCE_MATCH => TRUE +); + +*/ \ No newline at end of file diff --git a/sql_purge_cursor.sql b/sql_purge_cursor.sql new file mode 100644 index 0000000..71e028d --- /dev/null +++ b/sql_purge_cursor.sql @@ -0,0 +1,90 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: purge the cursor out of the cache - parameter 1 - SQL ID +--============================================================================== +-- http://kerryosborne.oracle-guy.com/2008/09/flush-a-single-sql-statement/ +-- http://www.oracle.com/webfolder/technetwork/de/community/dbadmin/tipps/cursor_invalidieren/index.html +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define SQL_ID='&1' + +prompt +prompt Parameter 1 = SQL ID => &&SQL_ID. +prompt + +set pagesize 100 +set linesize 130 + +select address + , hash_value + , executions + , invalidations + , parse_calls + , substr(sql_text,1,20)||'...' as sql_text + from v$sqlarea + where sql_id like '&&SQL_ID.' +/ + +set serveroutput on + +declare + v_name varchar2(30); +begin + + select address||','||hash_value into v_name + from gv$sqlarea + where sql_id like '&&SQL_ID.'; + +dbms_output.put_line('Info -- invalidate Cursor of this statement &&SQL_ID. :: '||v_name); + +sys.dbms_shared_pool.purge(name => v_name + , flag => 'C' + , heaps => 1); + +end; +/ + + +select address + , hash_value + , executions + , invalidations + , parse_calls + , substr(sql_text,1,20)||'...' as sql_text + from v$sqlarea + where sql_id like '&&SQL_ID.' +/ + + +--============================================================================== +-- +-- see http://docs.oracle.com/cd/B28359_01/appdev.111/b28419/d_shared_pool.htm#CHDCBEBB +-- Parameter Description +-- name +-- Name of the object to purge. +-- +-- The value for this identifier is the concatenation of the address and hash_value columns from the v$sqlarea view. This is displayed by the SIZES procedure. +-- +-- Currently, TABLE and VIEW objects may not be purged. +-- +-- flag +-- (Optional) If this is not specified, then the package assumes that the first parameter is the name of a package/procedure/function and resolves the name. +-- +-- Set to 'P' or 'p' to fully specify that the input is the name of a package/procedure/function. +-- +-- Set to 'T' or 't' to specify that the input is the name of a type. +-- +-- Set to 'R' or 'r' to specify that the input is the name of a trigger. +-- +-- Set to 'Q' or 'q' to specify that the input is the name of a sequence. +-- +-- In case the first argument is a cursor address and hash-value, the parameter should be set to any character except 'P' or 'p' or 'Q' or 'q' or 'R' or 'r' or 'T' or 't'. +-- +-- heaps +-- Heaps to be purged. For example, if heap 0 and heap 6 are to be purged: +-- +-- 1<<0 | 1<<6 => hex 0x41 => decimal 65, so specify heaps =>65.Default is 1, that is, heap 0 which means the whole object would be purged +-- +--============================================================================== diff --git a/sql_session_stat.sql b/sql_session_stat.sql new file mode 100644 index 0000000..379447e --- /dev/null +++ b/sql_session_stat.sql @@ -0,0 +1,64 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get statistics from running session for this SQL +-- Work in progress +--============================================================================== +set linesize 130 pagesize 300 + +define SQL_STATEMENT = &1 + +prompt +prompt Parameter 1 = SQL_STATEMENT => &&SQL_STATEMENT. +prompt + +ttitle "Report sessions statistic for this SQL &&SQL_STATEMENT." skip 2 + +column client_info format a30 +column MODULE format a20 +column username format a10 heading "User|name" +column program format a20 +column state format a20 +column event format a15 +column last_sql format a20 +column sec format 99999 heading "Wait|sec" +column inst format 9 heading "Inst" +column ss format a10 heading "SID:Ser#" +column name format a30 + +break on ss + +select inst + , ss + , username + , name + , value + , round ( (ratio_to_report (sum (value)) over (partition by ss))* 100, 3) as prozent + from (select /* gpi script lib session_stat.sql */ + sw.inst_id as inst + , s.sid || ',' || s.serial# as ss + --, s.client_info + --, s.MODULE + , s.username + --, s.program + , sn.name + , sw.value + from gv$sesstat sw, v$statname sn, gv$session s + where sw.STATISTIC# = sn.STATISTIC# + and sn.NAME in ('table fetch continued row', 'table fetch by rowid') + -- + and sw.inst_id = s.inst_id + and sw.sid = s.sid + -- + and s.sql_id = '&&SQL_STATEMENT.') +group by inst + , ss + , username + , name + , value +order by inst, ss +/ + +clear break + +ttitle off + diff --git a/sql_show_bind.sql b/sql_show_bind.sql new file mode 100644 index 0000000..ce50ff6 --- /dev/null +++ b/sql_show_bind.sql @@ -0,0 +1,87 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Show the bind variables of the SQL statement from the cursor Cache +--============================================================================== +-- traditional http://tech.e2sn.com/oracle/troubleshooting/how-to-read-errorstack-output +-- http://tech.e2sn.com/oracle/troubleshooting/oracle-s-real-time-sql-monitoring-feature-v-sql_monitor +-- http://tech.e2sn.com/oracle/troubleshooting/oracle-s-real-time-sql-monitoring-feature-v-sql_monitor + +-- only uses if you have a licence!! +-- show parameter control_management_pack_access +-- check also parameter _sqlmon_binds_xml_format +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set verify off +set linesize 130 pagesize 300 + +define SQL_ID='&1' + +prompt +prompt Parameter 1 = SQL ID => &&SQL_ID. +prompt + + +column session_info format a30 heading "Session|Info" +column inst_id format 99 heading "In|Id" +column program format a16 heading "Remote|program" +column module format a16 heading "Remote|module" +column action format a16 heading "Remote|action" +column client_info format a10 heading "Client|info" FOLD_AFTER +column client_identifier format a10 heading "Client|Ident" +column sql_id format a14 heading "SQL|id" +column bind_var format a140 heading "Bind XML" WORD_WRAPPED FOLD_BEFORE FOLD_AFTER + +select inst_id + , username||'(sid:'||sid||')' as session_info + , program + , module + , action + , client_identifier + , client_info + , replace(replace(to_char(binds_xml),'<',chr(10)||'<'),'>','>'||chr(10)) as bind_var + -- problem Error LPX-00216: invalid character 1 (0x1) bei speziellen Werten in den Bind Variablen + --, XMLQuery( 'for $i in /binds return $i/bind' PASSING BY VALUE XMLType(binds_xml) RETURNING CONTENT ) as pure_bind + from gv$sql_monitor +where sql_id = '&&SQL_ID.' +/ + +--============================================================================== +-- +-- http://dioncho.wordpress.com/2009/05/07/tracking-the-bind-value/ +-- http://docs.oracle.com/cd/B19306_01/server.102/b14237/dynviews_2114.htm +-- +-- from the AWR +-- select sql_id,name, position, value_string +-- from (select sql_id,bind_data +-- from dba_hist_sqlstat +-- where bind_data is not null +-- and rownum <= 1) x +-- table(dbms_sqltune.extract_binds(x.bind_data)) xx; +-- +-- over gv$sql_bind_capture +-- 11g this is not working!! +-- select sb.value_string +-- , ss.username +-- , ss.sid||','||ss.serial#||',@'||ss.inst_id +-- , sb.sql_id +-- from --gv$sql_bind_capture sb +-- , DBA_HIST_SQLBIND sb +-- , gv$SQLAREA sa +-- , gv$session ss +-- where sa.inst_id=sb.inst_id +-- and ss.inst_id=sb.inst_id +-- +-- and ss.SQL_HASH_VALUE = sb.HASH_VALUE +-- and ss.SQL_ADDRESS = sb.ADDRESS +-- +-- and ss.SQL_HASH_VALUE = sa.HASH_VALUE +-- and ss.SQL_ADDRESS = sa.ADDRESS +-- +-- and sb.sql_id = '&&sql_id.' +-- order by ss.username +-- , sb.sql_id +-- +--============================================================================== \ No newline at end of file diff --git a/sql_temp.sql b/sql_temp.sql new file mode 100644 index 0000000..84e6a22 --- /dev/null +++ b/sql_temp.sql @@ -0,0 +1,35 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: check usage of temp tablespace +-- Date: November 2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +select s.inst_id + , s.username + , u."USER" as user_name + , u.tablespace + , u.contents + , u.extents + , u.blocks + , u.segtype + , s.client_info + , sq.sql_text + , sq.disk_reads + , sq.buffer_gets + , sq.fetches + , sq.executions +from sys.gv$session s + , sys.gv$sort_usage u + , sys.gv$sql sq +where s.saddr = u.session_addr + and s.inst_id = u.inst_id + and sq.address = s.sql_address + and sq.hash_value = s.sql_hash_value + and sq.inst_id = s.inst_id + and u.sqladdr = sq.address + and u.sqlhash = sq.hash_value + and u.inst_id = sq.inst_id +order by u.blocks desc +/ diff --git a/sql_user_report.sql b/sql_user_report.sql new file mode 100644 index 0000000..deea540 --- /dev/null +++ b/sql_user_report.sql @@ -0,0 +1,73 @@ +--============================================================================== +-- Author: Gunther Pippčrr +-- Desc: : HTML Report for SQL queries executed by one user +--============================================================================== +define DB_USER_NAME = &1 + + +prompt +prompt Parameter 1 = DB_USER_NAME => &&DB_USER_NAME. +prompt + + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_user_&&DB_USER_NAME._sql.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + + +set verify off +set linesize 250 pagesize 3000 + +column sql_text format a35 heading "SQL|Text" +column sql_id format a13 heading "SQL|ID" +column parsing_user_name format a10 heading "Parsing|Schema" +column executions format 999G999G999G999 heading "Exec" +column buffer_gets format 999G999G999G999 heading "Buffer|Gets" +column disk_reads format 999G999G999G999 heading "Disks|Reads" +column cpu_time format 999G999G999G999 heading "CpuTime|microseconds" +column sorts format 999G999G999G999 heading "Sorts" +column avg_bufferget_per_ex format 999G999G999D99 heading "AVG Buffer gets|Executions" +column avg_disk_reads_per_ex format 999G999G999D99 heading "AVG Disk reads|Executions" +column avg_sort_per_ex format 999G999G999D99 heading "AVG Sorts|Executions" +column avg_cpu_per_ex format 999G99G999G999D99 heading "AVG CPU|Executions" + +spool &&SPOOL_NAME + + +set markup html on + +ttitle center "SQL Statements in the SGA Cache for this user on this instance" SKIP 2 + +select s.SQL_ID + , u.username as "Parsing User" + , s.executions + , s.loads + , s.buffer_gets + , s.disk_reads + , trunc(s.buffer_gets/(s.executions),2) avg_bufferget_per_ex + , trunc(s.disk_reads/(s.executions),2) avg_disk_reads_per_ex + , s.FIRST_LOAD_TIME + , to_char(s.LAST_LOAD_TIME,'dd.mm.yyyy hh24:mi') LAST_LOAD_TIME + , to_char(s.LAST_ACTIVE_TIME,'dd.mm.yyyy hh24:mi') LAST_ACTIVE_TIME + , s.sql_text + from v$sqlarea s + , dba_users u + where u.user_id=s.parsing_user_id + and u.username like upper('&&DB_USER_NAME.') + --and s.LAST_ACTIVE_TIME between to_date('14.11.2014 08:00','dd.mm.yyyy hh24:mi') and to_date('14.11.2014 09:00','dd.mm.yyyy hh24:mi') + and s.executions>1 +order by s.LAST_ACTIVE_TIME desc +/ + +set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window +host &&SPOOL_NAME \ No newline at end of file diff --git a/sqlcl/addLsListener.js b/sqlcl/addLsListener.js new file mode 100644 index 0000000..3f2ee74 --- /dev/null +++ b/sqlcl/addLsListener.js @@ -0,0 +1,63 @@ +//=============================================================================== +// GPI - Gunther Pippèrr +// DOAG Konferenz NĂĽrnberg November 2016 +// Vortrag Gunther Pippèrr - SQLcl +// see also https://github.com/oracle/oracle-db-tools/blob/master/sqlcl/examples/customCommand.js +//=============================================================================== + + +// Refernz to the SQLcl Command Registry Class +var CommandRegistry = Java.type("oracle.dbtools.raptor.newscriptrunner.CommandRegistry"); + +// CommandListener for creating new any command Listener +var CommandListener = Java.type("oracle.dbtools.raptor.newscriptrunner.CommandListener") + +var ResultSet= Java.type("java.sql.ResultSet") + +// Java Script object to hold the new methodes +var extCommand = {}; + + +// fired before ANY command +extCommand.beginEvent = function (conn,ctx,sqlcl) { + // Get the actual command + if ( sqlcl.getSql().indexOf("ls") > 0 ){ + ctx.putProperty("gpi.command.ls",true); + ctx.write("\n -- Debug sqlcl: " + sqlcl.getSql()+ " read GPI command \n"); + //remember the time + ctx.putProperty("gpi.startTiming",new Date()); + } +} + +// Called to attempt to handle any command +extCommand.handleEvent = function (conn,ctx,sqlcl) { + // ls commmand to the database + sqlcl.setSql("select t.table_name, t.num_rows, round(s.bytes/1024/1024,3) as size_MB from user_tables t , user_segments s where t.table_name = s.segment_name(+) order by t.table_name;"); + // return FALSE to indicate the command was not handled + return true; +} + +// fired after ANY Command +extCommand.endEvent = function (conn,ctx,sqlcl) { + if ( ctx.getProperty("gpi.showTiming") ) { + var end = new Date().getTime(); + var start = ctx.getProperty("gpi.startTiming"); + start = start.getTime(); + // print out elapsed time of all commands + ctx.write("Command elapsed time :: " + (end - start) + " ms \n"); + //unset + ctx.putProperty("gpi.showTiming",false); + } +} + +// Actual Extend of the Java CommandListener + +var ShowTimingCmd = Java.extend(CommandListener, { + handleEvent: extCommand.handleEvent , + beginEvent: extCommand.beginEvent , + endEvent: extCommand.endEvent +}); + +// Registering the new Command +CommandRegistry.addForAllStmtsListener(ShowTimingCmd.class); + diff --git a/sqlnet.sql b/sqlnet.sql new file mode 100644 index 0000000..995589a --- /dev/null +++ b/sqlnet.sql @@ -0,0 +1,24 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQLNet Infos +-- Date: 30.05 2019 +--============================================================================== +set verify off +set linesize 140 pagesize 300 + + + +ttitle left "Get list of sqlnet adapters in use for this connections" skip 2 + +select sid + , network_service_banner + from V$SESSION_CONNECT_INFO + where sid = sys_context('USERENV','SID') + / + + +ttitle left "Check if this Session is connected via TCP with SSL TCPS or TCP" skip 2 + +SELECT SYS_CONTEXT('USERENV','NETWORK_PROTOCOL') AS connect_protocol FROM dual; + +ttitle off \ No newline at end of file diff --git a/sqn.sql b/sqn.sql new file mode 100644 index 0000000..c3d7efb --- /dev/null +++ b/sqn.sql @@ -0,0 +1,61 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Get the Redo Log scn information +-- Date: 01.November 2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +SET SERVEROUTPUT ON SIZE 1000000 + +prompt + +DECLARE + v_scn NUMBER; +BEGIN + v_scn:= DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER; + DBMS_OUTPUT.PUT_LINE('current SCN: ' || v_scn); +END; +/ + + +ttitle "Report Redo Log SCN History per Day" SKIP 1 - + +column min_sqn format 999999999999999 +column max_sqn format 999999999999999 + +select trunc(FIRST_TIME) as days + , thread# + , min(SEQUENCE#) as min_sqn + , max(SEQUENCE#) as max_sqn + , count(*) as archive_count + from V$LOG_HISTORY +where FIRST_TIME > trunc(sysdate - 14) +group by trunc(FIRST_TIME),thread# +order by 1,2 +/ + +ttitle "Report LOGS with this SQN" SKIP 1 - + +ACCEPT SQN prompt "search for SQN:" + +column NAME format a40 heading "Archivelog|Name" +column THREAD_NR format a2 heading "I" +column SEQUENCE# format 999999 heading "Arch|seq" + +set numwidth 14 + +select to_char(THREAD#) as THREAD_NR + , SEQUENCE# + , NAME + , to_char(FIRST_TIME,'dd.mm hh24:mi') as first_time + , NEXT_TIME + , FIRST_CHANGE# + , NEXT_CHANGE# +from v$archived_log +where to_number('&&SQN.') between SEQUENCE# and SEQUENCE# +order by THREAD#,SEQUENCE# +/ + +undefine SCN +ttitle off \ No newline at end of file diff --git a/ssl.sql b/ssl.sql new file mode 100644 index 0000000..0e68a3f --- /dev/null +++ b/ssl.sql @@ -0,0 +1,66 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: actual connections to the database +-- Date: 01.September 2012 +--============================================================================== +set verify off +set linesize 140 pagesize 300 + +define USER_NAME = &1 + +prompt +prompt Parameter 1 = Username => &&USER_NAME. +prompt + + +ttitle left "Check if this Session is connected via TCP with SSL TCPS or TCP" skip 2 + + +SELECT SYS_CONTEXT('USERENV','NETWORK_PROTOCOL') AS connect_protocol FROM dual; + + +ttitle left "Check connection information of all sesssions" skip 2 + +column inst_id format 99 heading "Inst|ID" +column username format a12 heading "DB User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column machine format a15 heading "Remote|pc/server" +column terminal format a14 heading "Remote|terminal" +column program format a15 heading "Remote|program" +column module format a16 heading "Remote|module" +column client_info format a10 heading "Client|info" +column client_identifier format A10 heading "Client|identifier" +column OSUSER format a13 heading "OS|User" +column LOGON_TIME format a12 heading "Logon|Time" +column status format a8 heading "Status" +column network_service_banner format a100 format "Network|Info" + + +select s.inst_id + , s.sid + , s.serial# + , s.status + , s.username + , s.machine + , s.terminal + , s.program + , s.OSUSER + , s.module + --, s.to_char (LOGON_TIME, 'dd.mm hh24:mi') as LOGON_TIME + , s.client_identifier + , s.client_info + , c.network_service_banner + --, c.client_charset + -- , c.client_oci_library + , c.authentication_type + from gv$session_connect_info c + , gv$session s + where c.sid = s.sid + -- and c.serial#=s.serial# + and c.inst_id=s.inst_id + and s.username is not null + order by 1 +/ + +ttitle off diff --git a/standby_status.sql b/standby_status.sql new file mode 100644 index 0000000..038fc2b --- /dev/null +++ b/standby_status.sql @@ -0,0 +1,161 @@ +-- ====================================================== +-- GPI - Gunther Pippèrr +-- Desc : Check the status of the standby DB for Gaps +-- ====================================================== +-- http://arjudba.blogspot.de/2011/03/scripts-to-monitor-data-guard.html +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +set serveroutput on size 1000000 + +column dest_name format a20 +column process format a10 +column status format a10 +column error format a20 +column state format a10 +column log_sequence format 999999999 + +prompt ... Check the DB enviroment + + select dest_name + , process + , status + , error + from v$archive_dest + where status != 'INACTIVE' +order by status +/ + +column process format 999999999 + + select process + , status + , log_sequence + , state + from v$archive_processes + where status != 'STOPPED' +order by status +/ + +prompt ... +prompt ... check Status of the Standby processes + +column process format a10 + +select process + , status + , client_process + , sequence# + , block# + , active_agents + , known_agents + from v$managed_standby +/ + +--============================================================================== +-- Where the types of PROCESS may be, +-- - RFS - Remote file server +-- - MRP0 - Detached recovery server process +-- - MR(fg) - Foreground recovery session +-- - ARCH - Archiver process +-- - FGRD +-- - LGWR +-- - RFS(FAL) +-- - RFS(NEXP) +-- - LNS - Network server process +-- +-- The process status may be, +-- UNUSED - No active process +-- ALLOCATED - Process is active but not currently connected to a primary database +-- CONNECTED - Network connection established to a primary database +-- ATTACHED - Process is actively attached and communicating to a primary database +-- IDLE - Process is not performing any activities +-- ERROR - Process has failed +-- OPENING - Process is opening the archived redo log +-- CLOSING - Process has completed archival and is closing the archived redo log +-- WRITING - Process is actively writing redo data to the archived redo log +-- RECEIVING - Process is receiving network communication +-- ANNOUNCING - Process is announcing the existence of a potential dependent archived redo log +-- REGISTERING - Process is registering the existence of a completed dependent archived redo log +-- WAIT_FOR_LOG - Process is waiting for the archived redo log to be completed +-- WAIT_FOR_GAP - Process is waiting for the archive gap to be resolved +-- APPLYING_LOG - Process is actively applying the archived redo log to the standby database +-- +-- The client process may be, +-- Archival - Foreground (manual) archival process (SQL) +-- ARCH - Background ARCn process +-- LGWR - Background LGWR process +--============================================================================== + +------- +prompt ... +prompt Check log last applied to last received log time + + +column info format a120 + +select 'Last Applied : ' || to_char (next_time, 'dd.mm.yyyy hh24:mi') info + from v$archived_log + where sequence# = (select max (sequence#) + from v$archived_log + where applied = 'YES') +union +select 'Last Received : ' || to_char (next_time, 'dd.mm.yyyy hh24:mi') info + from v$archived_log + where sequence# = (select max (sequence#) from v$archived_log) +/ + +------- +prompt ... +prompt Verify the last sequence# received and the last sequence# applied to standby database + +select al.thrd "Thread", almax "Last Seq Received", lhmax "Last Seq Applied" + from ( select thread# thrd, max (sequence#) almax + from v$archived_log + where resetlogs_change# = (select resetlogs_change# from v$database) + group by thread#) al + , ( select thread# thrd, max (sequence#) lhmax + from v$log_history + where first_time = (select max (first_time) from v$log_history) + group by thread#) lh + where al.thrd = lh.thrd +/ + + +------------- +prompt ... +prompt transport lag time, apply lag and apply finish time + +select name, value, unit from v$dataguard_stats +union +select null, null, ' ' from dual +union +select null, null, 'time computed: ' || min (time_computed) from v$dataguard_stats +/ + + +------- Check if that works ------- + +prompt ------- works only with logical or open physical standby ------- +prompt ------- or oracle streams -------------------------------------- +prompt ... +prompt ... check if gap exists + + select thread + , consumer_name + , seq + 1 first_seq_missing + , seq + ( next_seq - seq - 1) last_seq_missing + , next_seq - seq - 1 missing_count + from (select THREAD# thread + , SEQUENCE# seq + , lead (SEQUENCE#, 1, SEQUENCE#) over (partition by thread# order by sequence#) next_seq + , consumer_name + from dba_registered_archived_log + where RESETLOGS_CHANGE# = (select max (RESETLOGS_CHANGE#) from dba_registered_archived_log)) + where next_seq - seq > 1 +order by 1, 2 +/ + +---------------------------------------- \ No newline at end of file diff --git a/starttrace.sql b/starttrace.sql new file mode 100644 index 0000000..7687f33 --- /dev/null +++ b/starttrace.sql @@ -0,0 +1,37 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: start a trace in this session +--============================================================================== +-- see http://docs.oracle.com/cd/E11882_01/appdev.112/e40758/d_monitor.htm#ARPLS67176 +-- +-- If serial_num is NULL but session_id is specified, a session with a given session_id is traced irrespective of its serial number. If both session_id and serial_num are NULL, the current user session is traced. +-- It is illegal to specify NULL session_id and non-NULL serial_num. In addition, the NULL values are default and can be omitted. +-- +-- session_id Client Identifier for which SQL trace is enabled. If omitted (or NULL), the user's own session is assumed. +-- serial_num Serial number for this session. If omitted (or NULL), only the session ID is used to determine a session. +-- waits If TRUE, wait information is present in the trace +-- binds If TRUE, bind information is present in the trace +-- plan_stat Frequency at which we dump row source statistics. Value should be 'NEVER', 'FIRST_EXECUTION' (equivalent to NULL) or 'ALL_EXECUTIONS'. + +-- Start tracing with session_trace_enable => No entry in dba_enabled_traces but Entry in gv$session column SQL_TRACE != 'DISABLED' +--============================================================================== + + +begin + dbms_monitor.session_trace_enable( + session_id => null, + serial_num => null, + waits => true, + binds => true, + plan_stat => null); + end; + / + + +-- set Session identifier and trace over this identifier + +--/ + + + + \ No newline at end of file diff --git a/statistic.sql b/statistic.sql new file mode 100644 index 0000000..af7d993 --- /dev/null +++ b/statistic.sql @@ -0,0 +1,383 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Main statistic information of the database +-- Date: 01.September 2012 +-- +--============================================================================== + +-- 11g: Scheduler Maintenance Tasks or Autotasks [ID 756734.1] +-- Why Auto Optimizer Statistics Collection May Appear to be "Stuck"? (Doc ID 1320246.1) + + +set linesize 130 pagesize 300 + +ttitle left "Workload Statistic Values" skip 2 + +column SNAME format a15 heading "Statistic|Name" +column pname format a12 heading "Parameter" +column PVAL1 format a20 heading "Value 1" +column PVAL2 format a20 heading "Value 2" + +select sname + ,pname + ,to_char(pval1, '999G999G999D99') as pval1 + ,pval2 + from sys.aux_stats$ + order by 1 + ,2 +/ + +prompt .... CPUSPEED Workload CPU speed in millions of cycles/second +prompt .... CPUSPEEDNW Noworkload CPU speed in millions of cycles/second +prompt .... IOSEEKTIM Seek time + latency time + operating system overhead time in milliseconds +prompt .... IOTFRSPEED Rate of a single read request in bytes/millisecond +prompt .... MAXTHR Maximum throughput that the I/O subsystem can deliver in bytes/second +prompt .... MBRC Average multiblock read count sequentially in blocks +prompt .... MREADTIM Average time for a multi-block read request in milliseconds +prompt .... SLAVETHR Average parallel slave I/O throughput in bytes/second +prompt .... SREADTIM Average time for a single-block read request in milliseconds +prompt .... +prompt + +ttitle left "I/O Statistic Values" skip 2 + +column start_time format a21 heading "Start|time" +column end_time format a21 heading "End|time" +column max_iops format 9999999 heading "Block/s|data block" +column max_mbps format 9999999 heading "MB/s|maximum-sized read" +column max_pmbps format 9999999 heading "MB/s|largeI/0" +column latency format 9999999 heading "Latency|data block read" +column num_physical_disks format 999 heading "Disk|Cnt" + +select to_char(START_TIME,'dd.mm.yyyy hh24:mi') as START_TIME + ,to_char(END_TIME,'dd.mm.yyyy hh24:mi') as END_TIME + ,MAX_IOPS + ,MAX_MBPS + ,MAX_PMBPS + ,LATENCY + ,NUM_PHYSICAL_DISKS + from dba_rsrc_io_calibrate +/ + +prompt .... START_TIME Start time of the most recent I/O calibration +prompt .... END_TIME End time of the most recent I/O calibration +prompt .... MAX_IOPS Maximum number of data block read requests that can be sustained per second +prompt .... MAX_MBPS Maximum megabytes per second of maximum-sized read requests that can be sustained +prompt .... MAX_PMBPS Maximum megabytes per second of large I/O requests that can be sustained by a single process +prompt .... LATENCY Latency for data block read requests +prompt .... NUM_PHYSICAL_DISKS Number of physical disks in the storage subsystem (as specified by the user) +prompt .... +prompt + +ttitle left "Last analysed Tables Overview" skip 2 + +column last_an format a18 heading "Last|analysed" +column owner format a18 heading "Tab|Owner" +column tab_count format 9999 heading "Tab|Count" + +select last_an + ,owner + ,tab_count + from (select to_char(last_analyzed, 'dd.mm.yyyy') as last_an + ,owner + ,count(*) as tab_count + ,to_char(last_analyzed, 'yyyymmddhh') as sort + from dba_tables + group by owner + ,to_char(last_analyzed, 'dd.mm.yyyy') + ,to_char(last_analyzed, 'yyyymmddhh')) + order by sort asc + ,owner desc +/ + +prompt... +prompt... if last analyzed is empty there are some tables witout statistics in this schema +prompt... check especially for none sys user +prompt... + + +ttitle left "Stale Statistics overview - Table with more then 10% modifications" skip 2 + + +column owner format a20 +column table_name format a30 + +select t.owner + , t.table_name + , t.last_analyzed + , m.TIMESTAMP as last_accessed + , m.deletes + m.updates + m.inserts as changes + , round ( (m.deletes + m.updates + m.inserts) / t.num_rows * 100) stale_percent + , num_rows +from dba_tables t + , dba_tab_modifications m +where t.owner = m.table_owner + and t.table_name = m.table_name + and t.num_rows > 0 + and round ( (m.deletes + m.updates + m.inserts) / t.num_rows * 100) >= 10 + and owner not in ('SYS' + ,'SYSTEM' + ,'SYSMAN' + ,'APEX_030200' + ,'XDB' + ,'ORDDATA' + ,'MDSYS' + ,'OLAPSYS' + ,'CTXSYS' + ,'SYSMAN_MDS' + ,'EXFSYS' + ,'DBSNMP' + ,'ORDSYS' + ,'WMSYS' + ,'APEX_030200' + ,'PEFSTAT') +order by 1,2 +/ + + +set serveroutput on + +declare + v_list dbms_stats.objecttab; + v_owner varchar2(32):='NULL'; +begin + dbms_stats.gather_database_stats( objlist => v_list + , options => 'LIST STALE'); + dbms_output.put_line('--Info - List of stale Objects with dbms_stats.gather_database_stats'); + for i in v_list.first..v_list.last + loop + if v_list(i).ownname != v_owner then + dbms_output.put_line('--Info '||rpad('-',30,'-')); + end if; + if v_list(i).ownname != 'SYS' then + dbms_output.put_line('--Info Object:: ' || rpad(v_list(i).ownname || '.' || v_list(i).objname,42,' ') || rpad(' Type:: ' || v_list(i).objtype ,20,' ')|| ' Partition:: ' || v_list(i).partname); + end if; + v_owner:=v_list(i).ownname; + end loop; +end; +/ + +prompt... + + +ttitle left "Overview histogram statistic usage for none system user in the database" skip 2 + +column table_name format a25 heading "Table Name" + +select owner + ,count(distinct table_name) as count_tables + --, column_name + ,count(*) as count_hist_buckets + from DBA_TAB_HISTOGRAMS + where owner not in ('SYS' + ,'SYSTEM' + ,'SYSMAN' + ,'APEX_030200' + ,'XDB' + ,'ORDDATA' + ,'MDSYS' + ,'OLAPSYS' + ,'CTXSYS' + ,'SYSMAN_MDS' + ,'EXFSYS' + ,'DBSNMP' + ,'ORDSYS' + ,'WMSYS' + ,'APEX_030200' + ,'PEFSTAT') + group by owner --table_name ,column_name + order by owner +/ + +---------------------------- Check the Scheduler for the statistic job ------------------------------- + + +column job_name format a30 heading "Job|Name" +column run_count format 99999 heading "Run|Count" +column failure_count format 99999 heading "Failure|Count" +column last_start_date format a18 heading "Last|run date" +column next_run_date format a18 heading "Next|run date" +column client_name format a35 heading "Job|Name" +column status format a10 heading "Job|status" +column mean_job_duration format 999G999 heading "Mean|duration" +column mdl7 format 999G999 heading "Max|duration" +column next_start_date format a38 heading "Next|run" +column window_group_name format a18 heading "Window|group" +column job_duration format 999G999 heading "Duration|Minutes" +column job_start_time format a18 heading "Job|Start time" +column log_date format a18 heading 'Log Date' +column owner format a10 heading 'Owner' +column job_name format a30 heading 'Job' +column status format a10 heading 'Status' +column actual_start_date format a32 heading 'Actual|Start|Date' +column error# format 999999 heading 'Error|Nbr' +column window_start_time format a18 heading 'Windows|Start' +column job_status format a10 heading 'Status' +column window_name format a20 heading 'Windows|Name' +column window_next_time format a38 heading 'Window|next Time' + +ttitle left "Job Scheduler Information -- Oracle Statistic Auto Job " skip 2 + +select OWNER + ,JOB_NAME + ,RUN_COUNT + ,FAILURE_COUNT + ,to_char(LAST_START_DATE, 'DD.MM.YYYY HH24:MI') as LAST_START_DATE + ,to_char(NEXT_RUN_DATE, 'DD.MM.YYYY HH24:MI') as NEXT_RUN_DATE + from dba_scheduler_jobs + where job_name like '%STAT%' +/ + +prompt ... GATHER_STATS_JOB 10g job should not run in 11g! +prompt ... to delete use as sys user: exec dbms_scheduler.drop_job(job_name => 'SYS.GATHER_STATS_JOB'); +prompt + +ttitle left "Job Scheduler BSLN_MAINTAIN_STATS_JOB History " skip 2 + + +select log_id + ,to_char(log_date, 'DD.MM.YYYY HH24:MI') as log_date + ,owner + ,job_name + ,status + ,to_char(actual_start_date, 'DD.MM.YYYY HH24:MI') as actual_start_date + ,error# + from dba_scheduler_job_run_details + where JOB_NAME = 'BSLN_MAINTAIN_STATS_JOB' + order by actual_start_date +/ + +ttitle left "Job Scheduler Window Settings " skip 2 + +prompt +prompt check if the window is not activ in the past! +prompt + +column check_active format a10 heading 'Check|if ok' + +select window_name + ,to_char(last_start_date, 'DD.MM.YYYY HH24:MI') as last_start_date + ,enabled + ,active + ,decode(active, 'TRUE', '<==CHECK IF POSSIBLE', '-') as check_active + from dba_scheduler_windows + order by last_start_date +/ + +prompt +prompt ... if a window is still open in the past, close the window manually +prompt ... with : EXECUTE DBMS_SCHEDULER.CLOSE_WINDOW ('SATURDAY_WINDOW'); +prompt .. + +ttitle left "Check Window history" skip 2 +prompt +prompt check Window history +prompt + +select window_name + ,optimizer_stats + ,window_next_time + ,autotask_status + from dba_autotask_window_clients + +/ + +ttitle left "Check Auto tasks " skip 2 + +prompt +prompt if autotask is really enabled +prompt + +select client_name + ,status + from dba_autotask_task +/ + +ttitle left "Check Auto tasks Settings" skip 2 + +select c.client_name + ,c.status + ,w.window_group_name + ,w.next_start_date as next_start_date + ,extract(hour from c.mean_job_duration) * 60 + extract(minute from c.mean_job_duration) as mean_job_duration + ,extract(hour from c.max_duration_last_7_days) * 60 + extract(minute from c.max_duration_last_7_days) as mdl7 + from dba_autotask_client c + ,dba_scheduler_window_groups w + where w.window_group_name = c.window_group + order by 1 +/ + +prompt .... if task is disabled +prompt .... exec DBMS_AUTO_TASK_ADMIN.ENABLE( client_name => 'auto optimizer stats collection',operation => NULL,window_name => NULL) +prompt .... +prompt + +ttitle left "Check Auto tasks history" skip 2 + +prompt +prompt if empty no history!! +prompt + +select client_name + ,window_name + ,to_char(window_start_time, 'dd.mm.yyyy hh24:mi') as window_start_time + --, window_duration + --, job_name + ,job_status + ,to_char(job_start_time, 'dd.mm.yyyy hh24:mi') as job_start_time + ,extract(hour from job_duration) * 60 + extract(minute from job_duration) as job_duration + ,job_error + --, job_info + from dba_autotask_job_history + where job_start_time > sysdate - 14 +order by job_start_time +/ + +---------------------------- Check the Statistic Settings for this database ------------------------------- + +prompt +prompt if empty no history!! +prompt + +ttitle left "How long the DB keeps old statistics" skip 2 + +select DBMS_STATS.GET_STATS_HISTORY_RETENTION + from dual +/ + +ttitle left "Check Global Stat Settings" skip 2 + +column parameter format a30 +column value format a30 + +select 'AUTOSTATS_TARGET' as parameter, DBMS_STATS.GET_PREFS ( 'AUTOSTATS_TARGET','GLOBAL') as value from dual +union +select 'CASCADE' as parameter, DBMS_STATS.GET_PREFS ( 'CASCADE','GLOBAL') as value from dual +union +select 'DEGREE' as parameter, DBMS_STATS.GET_PREFS ( 'DEGREE','GLOBAL') as value from dual +union +select 'ESTIMATE_PERCENT' as parameter, DBMS_STATS.GET_PREFS ( 'ESTIMATE_PERCENT','GLOBAL') as value from dual +union +select 'METHOD_OPT' as parameter, DBMS_STATS.GET_PREFS ( 'METHOD_OPT','GLOBAL') as value from dual +union +select 'NO_INVALIDATE' as parameter, DBMS_STATS.GET_PREFS ( 'NO_INVALIDATE','GLOBAL') as value from dual +union +select 'GRANULARITY' as parameter, DBMS_STATS.GET_PREFS ( 'GRANULARITY','GLOBAL') as value from dual +union +select 'PUBLISH' as parameter, DBMS_STATS.GET_PREFS ( 'PUBLISH','GLOBAL') as value from dual +union +select 'INCREMENTAL' as parameter, DBMS_STATS.GET_PREFS ( 'INCREMENTAL','GLOBAL') as value from dual +union +select 'STALE_PERCENT' as parameter, DBMS_STATS.GET_PREFS ( 'STALE_PERCENT','GLOBAL') as value from dual +/ + +prompt ... +prompt ... to set the global preferences use "exec DBMS_STATS.SET_GLOBAL_PREFS ( pname => ' ', pvalue =>' ');" +prompt ... + +ttitle off + + + + + diff --git a/statistic_backup.sql b/statistic_backup.sql new file mode 100644 index 0000000..a4c7d29 --- /dev/null +++ b/statistic_backup.sql @@ -0,0 +1,312 @@ +--============================================================================== +-- backup the DB statistics +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +set heading on +set feedback on +set echo off +set trimspool on +set trimout on +set serveroutput on + +------------------- +-- create spool name +column SPOOL_NAME_VAR new_val SPOOL_NAME + +select replace ( + ora_database_name + || '_' + || sys_context ('USERENV', 'HOST') + || '_' + || to_char (sysdate, 'dd_mm_yyyy_hh24_mi') + || '_backup_statistics..sql' + , '\' + , '_') + --' resolve syntax highlight bug FROM my editor .-( + as SPOOL_NAME_VAR + from dual +/ + +column AKTDATE new_value LOG_DATE + +select to_char (sysdate, 'yyyymmdd_hh24mi') as AKTDATE from dual; + +define STATID_SUFFIX = &&LOG_DATE +define STAT_TAB = EXP_STATS_TABLE +define STAT_TBLSPACE = SYSAUX +define SYSSTAT_TAB = BAK_SYSSTAT_&&STATID_SUFFIX +define IOSTAT_TAB = BAK_IOSTAT_&&STATID_SUFFIX + +------------ + +define STAT_OWN = &STAT_OWNER + +----------- + +spool &&SPOOL_NAME + +column my_sid format a15 +column my_instance format a13 +column my_instance_name format a20 +column username format a15 + +select sys_context ('USERENV', 'SID') as my_sid + , sys_context ('USERENV', 'INSTANCE') as my_instance + , sys_context ('USERENV', 'INSTANCE_NAME') as my_instance_name + , sys_context ('USERENV', 'CURRENT_USER') as username + from dual; + +select to_char (sysdate, 'dd.mm.yyyy hh24:mi') from dual; + +show user + +select * from global_name; + +set timing on +set time on +set serveroutput on +set linesize 256 +set pagesize 200 +set echo off +set serveroutput on +set feedback off + +-- create statistic backup table +prompt +prompt ... creating stats table &&STAT_OWN..&&STAT_TAB. in tablespace &&STAT_TBLSPACE ... + +declare + v_count pls_integer := 0; +begin + select count (*) + into v_count + from dba_tables + where owner = '&&STAT_OWN.' + and table_name like '&&STAT_TAB.'; + + if v_count < 1 + then + dbms_stats.create_stat_table (ownname => '&&STAT_OWN.', stattab => '&&STAT_TAB.', tblspace => '&&STAT_TBLSPACE.'); + else + dbms_output.put_line ('-- Info : stats table &&STAT_OWN..&&STAT_TAB. in tablespace &&STAT_TBLSPACE still exists'); + end if; +end; +/ + +comment on table &&STAT_OWN..&&STAT_TAB. is 'statistics backup table. do not delete'; + + +-- backup database statistics +prompt +prompt ... backing up database stats to &&STAT_OWN..&&STAT_TAB. with statid: DB_STAT_&&STATID_SUFFIX ... + +begin + dbms_stats.EXPORT_DATABASE_STATS (stattab => '&&STAT_TAB.' + , statid => 'DB_STAT_&&STATID_SUFFIX.' + , statown => '&&STAT_OWN.' + , stat_category => 'OBJECT_STATS,SYNOPSES'); +end; +/ + +-- backup dictionary statistics +prompt +prompt ... backing up dictionary stats to &&STAT_OWN..&&STAT_TAB. with statid: DICT_STATS_&&STATID_SUFFIX ... + +begin + dbms_stats.EXPORT_DICTIONARY_STATS (stattab => '&&STAT_TAB.' + , statid => 'DICT_STATS_&&STATID_SUFFIX.' + , STAT_OWN => '&&STAT_OWN.' + , stat_category => 'OBJECT_STATS,SYNOPSES'); +end; +/ + + +-- backup fixed object statistics +prompt +prompt ... backing up fixed object stats to &&STAT_OWN..&&STAT_TAB. with statid: FIXED_OBJ_STATS_&&STATID_SUFFIX ... + +begin + dbms_stats.EXPORT_FIXED_OBJECTS_STATS (stattab => '&&STAT_TAB.' + , statid => 'FIXED_OBJ_STATS_&&STATID_SUFFIX' + , statown => '&&STAT_OWN.'); +end; +/ + + + +-- backup system/workload statistics +prompt +prompt ... backing up system/workload stats to &&STAT_OWN..&&STAT_TAB. with statid: system_stats_&&STATID_SUFFIX ... + +begin + dbms_stats.EXPORT_SYSTEM_STATS (stattab => '&&STAT_TAB.', statid => 'SYSTEM_STATS_&&STATID_SUFFIX', statown => '&&STAT_OWN.'); +end; +/ + +prompt +prompt Summary over the stat table + +column STATID format a20 +column type format a3 +column counts format 99999999 + + select STATID, type, count (*) as counts + from &&STAT_OWN..&&STAT_TAB. +group by STATID, type +/ + + +prompt +prompt ... creating backup &&STAT_OWN..&&SYSSTAT_TAB. of system/workload stats table sys.aux_stats$ ... + +create table &&STAT_OWN..&&SYSSTAT_TAB. +as + select * from sys.aux_stats$; + +comment on table &&STAT_OWN..&&SYSSTAT_TAB. is 'Backup of system/workload stats table sys.aux_stats$'; + + + +-- backup iocalibrate statistics +prompt +prompt ... creating backup &&STAT_OWN..&&IOSTAT_TAB. of iocalibrate stats table sys.RESOURCE_IO_CALIBRATE$ ... + +create table &&STAT_OWN..&&IOSTAT_TAB. +as + select * from sys.RESOURCE_IO_CALIBRATE$; + +comment on table &&STAT_OWN..&&IOSTAT_TAB. is 'Backup of iocalibrate stats table sys.RESOURCE_IO_CALIBRATE$'; + + + +-- print summary +column last format a14 +column name format a65 +column start_time format a25 +column end_time format a25 +column owner format a25 + +prompt +prompt ======================================================================================= +prompt IOCALIBRATE STATS (sys.RESOURCE_IO_CALIBRATE$,GV$IO_CALIBRATION_STATUS) +prompt ======================================================================================= + + +select * from sys.RESOURCE_IO_CALIBRATE$ +/ + +select * from GV$IO_CALIBRATION_STATUS +/ + +prompt ... +prompt ... Check that all disks are on async IO! (v$datafile, v$iostat_file) +prompt ... + + select count (*), i.asynch_io + from v$datafile f, v$iostat_file i + where f.file# = i.file_no + and i.filetype_name = 'Data File' +group by i.asynch_io +/ + + + +column START_TIME format a21 heading "Start|time" +column END_TIME format a21 heading "End|time" +column MAX_IOPS format 9999999 heading "Block/s|data block" +column MAX_MBPS format 9999999 heading "MB/s|maximum-sized read" +column MAX_PMBPS format 9999999 heading "MB/s|largeI/0" +column LATENCY format 9999999 heading "Latency|data block read" +column NUM_PHYSICAL_DISKS format 999 heading "Disk|Cnt" + + +select to_char (START_TIME, 'dd.mm.yyyy hh24:mi') as START_TIME + , to_char (END_TIME, 'dd.mm.yyyy hh24:mi') as END_TIME + , MAX_IOPS + , MAX_MBPS + , MAX_PMBPS + , LATENCY + , NUM_PHYSICAL_DISKS + from dba_rsrc_io_calibrate +/ + + +-- START_TIME Start time of the most recent I/O calibration +-- END_TIME End time of the most recent I/O calibration +-- MAX_IOPS Maximum number of data block read requests that can be sustained per second +-- MAX_MBPS Maximum megabytes per second of maximum-sized read requests that can be sustained +-- MAX_PMBPS Maximum megabytes per second of large I/O requests that can be sustained by a single process +-- LATENCY Latency for data block read requests +-- NUM_PHYSICAL_DISKS Number of physical disks in the storage subsystem (as specified by the user) + + +-- select +-- d.name +-- , f.file_no +-- , f.small_read_megabytes +-- , f.small_read_reqs +-- , f.large_read_megabytes +-- , f.large_read_reqs +-- from +-- v$iostat_file f +-- inner join v$datafile d on f.file_no = d.file# +-- / + + +prompt +prompt ======================================================================================= +prompt Workload Stats Summary (sys.aux_stats$) +prompt ======================================================================================= + +column SNAME format a15 heading "Statistic|Name" +column pname format a12 heading "Parameter" +column PVAL1 format a20 heading "Value 1" +column PVAL2 format a20 heading "Value 2" + + select sname + , pname + , to_char (pval1, '999G999G999D99') as pval1 + , pval2 + from sys.aux_stats$ +order by 1, 2 +/ + +prompt .... CPUSPEED Workload CPU speed in millions of cycles/second +prompt .... CPUSPEEDNW Noworkload CPU speed in millions of cycles/second +prompt .... IOSEEKTIM Seek time + latency time + operating system overhead time in milliseconds +prompt .... IOTFRSPEED Rate of a single read request in bytes/millisecond +prompt .... MAXTHR Maximum throughput that the I/O subsystem can deliver in bytes/second +prompt .... MBRC Average multiblock read count sequentially in blocks +prompt .... MREADTIM Average time for a multi-block read request in milliseconds +prompt .... SLAVETHR Average parallel slave I/O throughput in bytes/second +prompt .... SREADTIM Average time for a single-block read request in milliseconds + + +prompt +prompt ======================================================================================= +prompt Table Statistics Summary (dba_tables) +prompt ======================================================================================= + + + select count (*), owner, to_char (LAST_ANALYZED, 'dd.mm.yyyy') as last + from dba_tables +group by owner, to_char (LAST_ANALYZED, 'dd.mm.yyyy'), to_char (LAST_ANALYZED, 'YYYYDDMM') +order by owner, to_char (LAST_ANALYZED, 'YYYYDDMM') desc +/ + + + +undefine STATID_SUFFIX +undefine STAT_OWN +undefine STAT_TAB +undefine STAT_TBLSPACE +undefine SYSSTAT_TAB +undefine IOSTAT_TAB + + +spool off; +set echo off +set time off +set timing off \ No newline at end of file diff --git a/statspack_delete_job.sql b/statspack_delete_job.sql new file mode 100644 index 0000000..ae85478 --- /dev/null +++ b/statspack_delete_job.sql @@ -0,0 +1,47 @@ + + + +define DBID=1517503088 +prompt check if you have set the correct DB ID = &DBID ! + +variable jobno number + +set verify on + +begin + dbms_job.submit(job => :jobno + , what => 'statspack.purge(i_num_days=>14,i_extended_purge=>true,I_DBID=>&&DBID, I_INSTANCE_NUMBER=> 1 ); ' + , next_date => sysdate + , interval => 'trunc(SYSDATE+1)+(((1/24)*4)+((1/(26*60))*5))' + , no_parse => false + , instance => 1 + , force => true); + +end; +/ + + +commit + +begin + dbms_job.submit( + job => :jobno + , what => 'statspack.purge(i_num_days=>14,i_extended_purge=>true,I_DBID=>&&DBID, I_INSTANCE_NUMBER=> 2 ); ' + , next_date => sysdate + , interval => 'trunc(SYSDATE+1)+(((1/24)*4)+((1/(26*60))*12))' + , no_parse => true + , instance => 2 + , force => true); + +end; +/ + + +commit; + + +set verify off + + +@jobs_dbms + diff --git a/status.sql b/status.sql new file mode 100644 index 0000000..c32901d --- /dev/null +++ b/status.sql @@ -0,0 +1,30 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Status all Instances +-- Date: 01.September 2012 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +ttitle left "Status all Instances" skip 2 + +column inst_id format 9 heading "Inst|Id" +column status format A8 heading "Status" +column name format A8 heading "Instance|Name" +column startzeit format A15 heading "Start|Time" +column host_name format A25 heading "Server|Name" +column logins format a10 heading "Check|Restrict" +column active_state format a10 heading "Check|Quiesce " + +select inst_id + , status + , logins + , active_state + , instance_name as name + , to_char(STARTUP_TIME, 'dd.mm.YY hh24:mi') as startzeit + , host_name + from gv$instance + order by 1 +/ + +ttitle off diff --git a/stoptrace.sql b/stoptrace.sql new file mode 100644 index 0000000..f094638 --- /dev/null +++ b/stoptrace.sql @@ -0,0 +1,26 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: stop a trace in this session +--============================================================================== +-- see http://docs.oracle.com/cd/E11882_01/appdev.112/e40758/d_monitor.htm#ARPLS67176 +-- +-- session_id Database Session Identifier for which SQL trace is disabled +-- serial_num Serial number for this session +--============================================================================== + + + +-- Start tracing with session_trace_enable => No entry in dba_enabled_traces but Entry in gv$session column SQL_TRACE != 'DISABLED' +begin +dbms_monitor.session_trace_disable( + session_id => null, + serial_num => null); +end; +/ + + +-- set Session identifier and trace over this identifier +--begin +-- dbms_monitor.client_id_trace_disable ('GPI_TRACE_SESSION'); +--end; +--/ diff --git a/streams_config.sql b/streams_config.sql new file mode 100644 index 0000000..345fb31 --- /dev/null +++ b/streams_config.sql @@ -0,0 +1,58 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: streams configuration +--============================================================================== +-- http://docs.oracle.com/cd/E11882_01/server.112/e10705/man_gen_rep.htm#STREP013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +column capture_name heading 'capture|process|name' format a20 +column rule_set_owner heading 'positive|rule owner' format a15 +column rule_set_name heading 'positive|rule set' format a15 +column negative_rule_set_owner heading 'negative|rule owner' format a15 +column negative_rule_set_name heading 'negative|rule set' format a15 + +column apply_name heading 'apply|process|name' format a20 +column rule_set_owner heading 'positive|rule owner' format a15 +column rule_set_name heading 'positive|rule set' format a15 +column negative_rule_set_owner heading 'negative|rule owner' format a15 +column negative_rule_set_name heading 'negative|rule set' format a15 + + +break on capture_name + +select capture_name + , rule_set_owner + , rule_set_name + , negative_rule_set_owner + , negative_rule_set_name + from dba_capture +/ + +select * from dba_capture_parameters +/ + +select apply_name + , rule_set_owner + , rule_set_name + , negative_rule_set_owner + , negative_rule_set_name + from dba_apply +/ + + +column PARAMETER format a26 +column VALUE format a30 +column SET_BY_USER format a3 + +break on APPLY_NAME + +select APPLY_NAME + , PARAMETER + , value + , SET_BY_USER + from dba_apply_parameters +/ + +clear break \ No newline at end of file diff --git a/streams_logmnr.sql b/streams_logmnr.sql new file mode 100644 index 0000000..12a4927 --- /dev/null +++ b/streams_logmnr.sql @@ -0,0 +1,149 @@ +--============================================================================== +-- desc: information about the log miner process +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +column ROLE format a16 +column SESSION_ID format 99999 head 'Logmr|id' +column WORK_MICROSEC format 9999990.99 head 'Work(sec)' +column OVERHEAD_MICROSEC format 9999990.99 head 'Overead (sec)' + + +select inst_id + , SESSION_ID + , ROLE + , SID + , spid + , WORK_MICROSEC / 1000000 + , OVERHEAD_MICROSEC / 1000000 + , LATCHWAIT + , LATCHSPIN + from GV$LOGMNR_PROCESS +/ + +select a.inst_id + , class + , name + , value + from gv$sesstat a, gv$statname b + where value > 0 + and a.statistic# = b.statistic# + and sid = (select sid + from v$logmnr_process + where role = 'preparer') + and a.inst_id = b.inst_id +order by class, name, value +/ + +column WAIT_CLASS for a16 +column event for a45 + +select a.inst_id + , a.event + , total_waits total_waits + , total_timeouts total_timeouts + , time_waited / 100 time_waited + , average_wait average_wait + , a.wait_class + , a.wait_class# + from gv$session_event a, gv$session b + where a.sid = b.sid + and a.sid = (select sid + from v$logmnr_process + where role = 'preparer') + and a.inst_id = b.inst_id +/ + +-- +-- Procedure to Manually Coalesce All the IOTs / Indexes Associated with Advanced Queueing Tables to Maintain Enqueue +-- / Dequeue Performance; Reduce QMON CPU Usage and Redo Generation (Doc ID 271855.1) +-- + +column INST_ID format 99 heading "INST_ID" +column QUEUE_TABLE_ID format 9999999 heading "QUEUE|TABLE_ID" +column DEQUEUE_INDEX_BLOCKS_FREED format 99G999G999 heading "DEQUEUE_INDEX|BLOCKS_FREED" +column HISTORY_INDEX_BLOCKS_FREED format 99G999G999 heading "HISTORY_INDEX|BLOCKS_FREED" +column TIME_INDEX_BLOCKS_FREED format 99G999G999 heading "TIME_INDEX|BLOCKS_FREED" +column INDEX_CLEANUP_COUNT format 99G999G999 heading "INDEX|CLEANUP_COUNT" +column INDEX_CLEANUP_ELAPSED_TIME format 99G999G999 heading "INDEX_CLEANUP|ELAPSED_TIME" +column INDEX_CLEANUP_CPU_TIME format 99G999G999 heading "INDEX_CLEANUP|CPU_TIME" +column LAST_INDEX_CLEANUP_TIME format a20 heading "LAST_INDEX|CLEANUP_TIME" + + +select INST_ID + , QUEUE_TABLE_ID + , DEQUEUE_INDEX_BLOCKS_FREED + , HISTORY_INDEX_BLOCKS_FREED + , TIME_INDEX_BLOCKS_FREED + , INDEX_CLEANUP_COUNT + , INDEX_CLEANUP_ELAPSED_TIME + , INDEX_CLEANUP_CPU_TIME + , LAST_INDEX_CLEANUP_TIME + from GV$PERSISTENT_QMN_CACHE +/ + +-- +--QMON Slaves Processes Consuming High Amount of CPU after Upgrade to 11.2.0.4 (Doc ID 1615165.1) +-- + + column INST_ID format 99 heading "INST|ID" + column TASK_NAME format a20 heading "TASK|NAME" + column TASK_NUMBER format 99999 heading "TASK|NUMBER" + column TASK_TYPE format a20 heading "TASK|TYPE" + column TASK_SUBMIT_TIME format a10 heading "TASK|SUBMIT_TIME" + column TASK_READY_TIME format a10 heading "TASK|READY_TIME" + column TASK_EXPIRY_TIME format a10 heading "TASK|EXPIRY_TIME" + column TASK_START_TIME format a10 heading "TASK|START_TIME" + column TASK_STATUS format a10 heading "TASK|STATUS" + column SERVER_NAME format a10 heading "SERVER|NAME" + column MAX_RETRIES format 999 heading "MAX|RETRIES" + column NUM_RUNS format 999999999999 heading "NUM|RUNS" + column NUM_FAILURES format 999 heading "NUM|FAILURES" + + select * + from gv$qmon_tasks +order by inst_id + , task_type + , task_name + , task_number +/ + +column inst_id format 99 heading "inst_id" +column queue_schema format 99 heading "queue_schema" +column queue_name format 99 heading "queue_name" +column queue_id format 9999999 heading "queue_id" +column queue_state format 99 heading "queue_state" +column startup_time format 99 heading "startup_time" +column num_msgs format 99999 heading "num_msgs" +column spill_msgs format 99 heading "spill_msgs" +column waiting format 99 heading "waiting" +column ready format 99 heading "ready" +column expired format 999999 heading "expired" +column cnum_msgs format 999999 heading "cnum_msgs" +column cspill_msgs format 999999 heading "cspill_msgs" +column expired_msgs format 999999 heading "expired_msgs" +column total_wait format 99 heading "total_wait" +column average_wait format 99 heading "average_wait" + + select inst_id + , queue_schema + , queue_name + , queue_id + , queue_state + , startup_time + , num_msgs + , spill_msgs + , waiting + , ready + , expired + , cnum_msgs + , cspill_msgs + , expired_msgs + , total_wait + , average_wait + from gv$buffered_queues b, gv$aq q + where b.queue_id = q.qid +order by 1, 2, 3 +/ + diff --git a/streams_logs.sql b/streams_logs.sql new file mode 100644 index 0000000..c58400b --- /dev/null +++ b/streams_logs.sql @@ -0,0 +1,116 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the streams archive logs - which can be deleted +--============================================================================== +set verify off +set linesize 130 pagesize 2000 + +set serveroutput on size 1000000 + +--- +col SPOOL_NAME_COL new_val SPOOL_NAME + +select ora_database_name + -- fix Window Domain + --|| '_' + --|| sys_context ('USERENV', 'HOST') + || '_' + || to_char (sysdate, 'dd_mm_yyyy_hh24_mi') + || '_remove_old_streams_logs' + as SPOOL_NAME_COL + from dual +/ + +spool &&SPOOL_NAME + + +select to_char (sysdate, 'dd.mm.yyyy hh24:mi') as starttime from dual +/ + +declare + cursor c_log_remove (v_last_appl_scn number) + is + select * + from (select lr.name, lr.first_time, rank () over (order by lr.first_time asc) as rang + from DBA_REGISTERED_ARCHIVED_LOG LR, DBA_LOGMNR_PURGED_LOG LP + where lr.first_scn < v_last_appl_scn + and lr.name = lp.file_name + and lr.first_time < sysdate + - 1) + --for debug to get only the first records + where rang < 250 + order by FIRST_TIME desc; + + cursor c_need_logs + is + select r.name, to_char (FIRST_TIME, 'dd.mm hh24:mi') as start_time + from dba_registered_archived_log r, dba_capture c + where r.consumer_name = c.capture_name + and r.next_scn >= c.required_checkpoint_scn + order by FIRST_TIME desc; + + v_high_Scn number := 0; + v_low_Scn number := 0; + v_start_Scn number; + v_applied_Scn number; + v_required_scn number; + + v_alog varchar2 (1000); +begin + -- fix for pls-sql developer + dbms_output.ENABLE (1000000); + + -- get actual scn + select min (start_scn), min (applied_scn), min (required_checkpoint_scn) + into v_start_Scn, v_applied_Scn, v_required_scn + from dba_capture; + + dbms_output.put_line ('Info -- last applied scn: ' || v_applied_Scn || ' -required_checkpoint_scn ' || v_required_scn); + dbms_output.put_line ('Info -- Capture will restart from SCN ' || v_required_scn || ' in the following file:'); + dbms_output.put_line ('Info -- '); + + for rec in c_need_logs + loop + dbms_output.put_line ( + rpad ('Info -- still need this files fro the capture ', 46, ' ') + || ' :: ' + || rpad (rec.name, 56, ' ') + || ' from :: ' + || rec.start_time); + end loop; + + dbms_output.put_line ('Info -- '); + dbms_output.put_line ('Info -- START -> This archivelogs could be removed::'); + + for rec in c_log_remove (v_last_appl_scn => v_start_Scn) + loop + dbms_output.put_line ( + rpad ('Info -- try to delete this file ', 46, ' ') + || ' :: ' + || rpad (rec.name, 56, ' ') + || ' from :: ' + || to_char (rec.first_time, 'dd.mm hh24:mi')); + + begin + -- only possible if you have sys rights + null; + -- dbms_backup_restore.deletefile(rec.name); + dbms_output.put_line ('Info -- Command :: exec dbms_backup_restore.deletefile(''' || rec.name || ''')'); + exception + when others + then + dbms_output.put_line ( + rpad ('Info --try to delete this file ', 46, ' ') || ' :: ' || rpad (rec.name, 56, ' ') || ' Error ::' || sqlerrm); + end; + end loop; + + dbms_output.put_line ('Info -- END -> This archivelogs could be removed::'); +end; +/ + +select to_char (sysdate, 'dd.mm.yyyy hh24:mi') as endtime from dual +/ + +prompt check logfile &&SPOOL_NAME + +spool off diff --git a/streams_print_error.sql b/streams_print_error.sql new file mode 100644 index 0000000..89bcf8c --- /dev/null +++ b/streams_print_error.sql @@ -0,0 +1,203 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc : print the SQL Statements for all LCRS in a transaction if a streams error occurs +--============================================================================== +-- Source +-- http://docs.oracle.com/cd/B19306_01/appdev.102/b14258/d_apply.htm +-- http://docs.oracle.com/cd/B28359_01/appdev.111/b28419/t_lcr.htm#BABGGBHF +-- http://wedostreams.blogspot.de/2009/09/new-streams-112-sql-generation-facility.html +-- http://it.toolbox.com/blogs/oracle-guide/manually-creating-a-logical-change-record-lcr-13838 +-- http://www.fadalti.com/oracle/database/Streams.htm +--============================================================================== + +set verify off +set linesize 1000 pagesize 4000 + +set trimspool on +set serveroutput on + +------------------- +-- create spool name +col SPOOL_NAME_COL new_val SPOOL_NAME + +select replace ( + ora_database_name + || '_' + || sys_context ('USERENV', 'HOST') + || '_' + || to_char (sysdate, 'dd_mm_yyyy_hh24_mi') + || '_streams_sql.sql' + , '\' + , '_') + --' resolve syntax highlight bug FROM my editer .-( + as SPOOL_NAME_COL + from dual +/ + +alter session set NLS_TERRITORY=AMERICA; +alter session set NLS_LANGUAGE=AMERICAN; +alter session set NLS_NUMERIC_CHARACTERS='.,'; + +spool &&SPOOL_NAME + +prompt +prompt spool recreate_&&SPOOL_NAME.log +prompt +prompt +prompt prompt ============ Start ================ +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as start_date from dual +prompt / +prompt prompt =================================== +prompt +prompt alter session set NLS_TERRITORY=AMERICA; +; +prompt alter session set NLS_LANGUAGE=AMERICAN; +; +prompt alter session set NLS_NUMERIC_CHARACTERS='.,'; +; +prompt + +prompt set heading on +prompt set echo on +prompt set feedback on +prompt set define off + +declare + cursor c_error_queue + is + select local_transaction_id + , source_database + , message_number + , message_count + , error_number + , error_message + from dba_apply_error + order by local_transaction_id, message_number; + + v_i number; + v_txnid varchar2 (30); + v_source varchar2 (128); + v_msgno number; + v_msgcnt number; + v_errnum number := 0; + v_errno number; + v_errmsg varchar2 (255); + v_rowlcr sys.lcr$_row_record; + v_ddllcr sys.lcr$_ddl_record; + v_sqltext clob := ' '; + v_e_lcr sys.anydata; + v_res number; + v_typenm varchar2 (61); +begin + dbms_lob.createtemporary (v_sqltext, true); + + for rec in c_error_queue + loop + v_errnum := + v_errnum + + 1; + v_msgcnt := rec.MESSAGE_COUNT; + v_txnid := rec.LOCAL_TRANSACTION_ID; + v_source := rec.SOURCE_DATABASE; + v_msgno := rec.MESSAGE_NUMBER; + v_errno := rec.ERROR_NUMBER; + v_errmsg := rec.ERROR_MESSAGE; + + dbms_output.put_line ('-- Info --------------------------------------------------'); + dbms_output.put_line ('-- Info -- ERROR # : ' || v_errnum); + dbms_output.put_line ('-- Info -- Local Transaction ID : ' || v_txnid); + dbms_output.put_line ('-- Info -- Source Database : ' || v_source); + dbms_output.put_line ('-- Info -- Error in Message : ' || v_msgno); + dbms_output.put_line ('-- Info -- Error Number : ' || v_errno); + dbms_output.put_line ('-- Info -- Message Text : '); + dbms_output.put_line ('/*'); + dbms_output.put_line (v_errmsg); + dbms_output.put_line ('*/'); + dbms_output.put_line ('-- Info -- Message Count : ' || v_msgcnt); + dbms_output.put_line ('-- Info --------------------------------------------------'); + dbms_output.put_line (' '); + + for v_i in 1 .. v_msgcnt + loop + -- reinitialise all variables! + dbms_lob.createtemporary (v_sqltext, true); + v_rowlcr := null; + v_res := null; + v_e_lcr := null; + + begin + --- read LCR + v_e_lcr := dbms_apply_adm.GET_ERROR_MESSAGE (v_i, v_txnid); + -- get the Type of the LCR + v_typenm := v_e_lcr.GETTYPENAME (); + + -- extract SQL text + case v_typenm + when 'SYS.LCR$_DDL_RECORD' + then + -- transform to original data type sys.lcr$_ddl_record + v_res := v_e_lcr.GETOBJECT (v_ddllcr); + v_ddllcr.GET_DDL_TEXT (v_sqltext); + when 'SYS.LCR$_ROW_RECORD' + then + -- transform to original data type sys.lcr$_row_record + v_res := v_e_lcr.GETOBJECT (v_rowlcr); + v_rowlcr.get_row_text (v_sqltext); + else + dbms_output.put_line ('-- Error -- Non-LCR Message with type ' || v_typenm); + v_sqltext := '-- No SQL statement found'; + end case; + exception + when others + then + dbms_output.put_line ('-- Error -- SQL Error Message: ' || sqlerrm); + end; + + dbms_output.put_line ('-- Info -- Message id :' || v_i); + dbms_output.put_line ('-- Info -- SQL Command:'); + dbms_output.put_line (substr (v_sqltext, 1, 32000)); + dbms_output.put_line ('/'); + dbms_output.put_line ('-- Info --------------------------------------------------'); + -- If you are brave you can execute this also directly + -- + -- begin + -- execute immediate v_sqltext; + -- dbms_output.put_line('Info ----------successfully execute SQL from message:'||v_i||'for '|| %SQLCOUNT ||' records'); + -- exception + -- when others then + -- dbms_output.put_line('Error -- Error execute the SQL: '||v_sqltext); + -- dbms_output.put_line('Error -- Error execute the SQL: '||SQLERRM); + -- end; + + end loop; + end loop; +end; +/ + + +prompt +prompt prompt ============ Finish ================ +prompt select to_char(sysdate,'dd.mm.yyyy hh24:mi') as finish_date from dual +prompt / +prompt prompt =================================== +prompt +prompt prompt to check the log see reexecute_&&SPOOL_NAME.log +prompt prompt !!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!! +prompt prompt dont forget the commit if all is ok! +prompt prompt !!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!! + +prompt set heading on +prompt set feedback off +prompt set define on +prompt set echo off + +spool off + +prompt ..... +prompt to start he recreate scripts use the script: &&SPOOL_NAME +prompt ..... +prompt ..... to delete the errors and restart streams use this commands: +prompt ..... exec dbms_apply_adm.delete_all_errors( apply_name => 'downstream_apply') +prompt ..... exec dbms_apply_adm.start_apply ( apply_name => 'downstream_apply') +prompt ..... +prompt ..... \ No newline at end of file diff --git a/streams_print_lcr.sql b/streams_print_lcr.sql new file mode 100644 index 0000000..64ad427 --- /dev/null +++ b/streams_print_lcr.sql @@ -0,0 +1,25 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get one LCR of a streams replication +--============================================================================== +set verify off +set linesize 130 pagesize 3000 + +prompt.... Detail Error messages around the actual error + +select em.local_transaction_id + , em.object_owner || '.' || em.object_name as object_name + , em.operation + , em.transaction_message_number + , em.message + from dba_apply_error_messages em + , dba_apply_error ar +where em.local_transaction_id=ar.local_transaction_id + and em.transaction_message_number = &LCR_NUM. +order by em.local_transaction_id + , em.transaction_message_number + , em.position +/ + + + diff --git a/streams_status.sql b/streams_status.sql new file mode 100644 index 0000000..ecd5b8f --- /dev/null +++ b/streams_status.sql @@ -0,0 +1,243 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc : Get the status of the streams replication +--============================================================================== +-- http://docs.oracle.com/cd/E11882_01/server.112/e10705/toc.htm +-- http://www.oracle11ggotchas.com/articles/Resolving%20archived%20log%20file%20gaps%20in%20Streams.pdf +-- http://it.toolbox.com/blogs/oracle-guide/manually-creating-a-logical-change-record-lcr-13838 +-- +-- Streams Troubleshooting Guide (Doc ID 883372.1) +-- +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set verify off +set linesize 130 pagesize 300 + +set serveroutput on size 1000000 + + +column running_inst format 99 heading "In|St" +column capture_process_status format a10 heading "CaptureP|Status" +column apply_process_status format a10 heading "ApplyP|Status" +column apply_state format a10 heading "Apply|state" +column capture_state format a30 heading "Capture|State" +column hwm_message_create_time format a18 heading "MessageC|Time" +column delay_min format 9999999 heading "Delay|Minute" +column total_applied format 9999999 heading "Total|Applied" + +select to_char (sysdate, 'dd.mm.yyyy hh24:mi') as act_date from dual; + +select capture_state.inst_id as running_inst + , capture_status.status as capture_process_status + , apply_status.status as apply_process_status + , capture_state.state as capture_state + , apply_state.state as apply_state + , to_char (apply_state.hwm_message_create_time, 'dd.mm.yyyy hh24:mi') as hwm_message_create_time + , round ( ( sysdate - apply_state.hwm_message_create_time) * 24 * 60) as delay_min + , apply_state.total_applied + from (select 1 as jc, state, inst_id from gv$streams_capture) capture_state + , (select 1 as jc + , state + , hwm_message_create_time + , total_applied + from gv$streams_apply_coordinator) apply_state + , (select 1 as jc, status from dba_apply) apply_status + , (select 1 as jc, status from dba_capture) capture_status + where capture_status.jc = apply_state.jc(+) + and capture_status.jc = apply_status.jc(+) + and capture_status.jc = capture_state.jc(+) +/ + +prompt check for apply latency + +select to_char (applied_message_create_time, 'dd.mm.yyyy hh24:mi:ss') "event_creation" + , to_char (apply_time, 'dd.mm.yyyy hh24:mi:ss') "apply_time" + , round ( ( apply_time - applied_message_create_time) * 86400 / 60) "create_apply_latency_minutes" + , ( sysdate - apply_time) * 86400 "last_apply_in_seconds" + from dba_apply_progress +/ + + +prompt ... +prompt ... check if gap exists + + select thread + , consumer_name + , seq + 1 first_seq_missing + , seq + ( next_seq - seq - 1) last_seq_missing + , next_seq - seq - 1 missing_count + from (select THREAD# thread + , SEQUENCE# seq + , lead (SEQUENCE#, 1, SEQUENCE#) over (partition by thread# order by sequence#) next_seq + , consumer_name + from dba_registered_archived_log + where RESETLOGS_CHANGE# = (select max (RESETLOGS_CHANGE#) from dba_registered_archived_log)) + where next_seq + - seq > 1 +order by 1, 2 +/ + + +prompt ... +prompt ... check count of old archive logs not needed anymore for streams + +select purged_candiates_logs_count, registerd_logs_count + from (select count (*) as purged_candiates_logs_count from DBA_LOGMNR_PURGED_LOG) + , (select count (*) as registerd_logs_count from DBA_REGISTERED_ARCHIVED_LOG LR where Lr.first_time < sysdate - 1) +/ + +prompt ... +prompt ... check in apply_error for + +set long 650000 + +column local_transaction_id format a20 heading "trans|ID" +column source_database format a10 heading "Source|DB" +column message_number format 9999999 +column message_count format 9999999 +column error_number format 999999 +column error_message format a30 + +column MESSAGE_ID format a10 +column TRANSACTION_MESSAGE_NUMBER format 999 heading "Trans|Number" +column SOURCE_OBJECT_OWNER format a10 +column SOURCE_OBJECT_NAME format a20 +column OBJECT_OWNER format a10 +column OBJECT_NAME format a30 +column PRIMARY_KEY format a20 +column POSITION format a10 +column OPERATION format a10 +column MESSAGE format a50 word_wrapped +column error_time format a16 + + select local_transaction_id + , source_database + , message_number + , message_count + , error_number + , error_message + , to_char (ERROR_CREATION_TIME, 'dd.mm hh24:mi:ss') as error_time + from dba_apply_error +order by source_database, source_commit_scn +/ + +--BREAK ON local_transaction_id + +prompt .... Total count of error message in the apply error message + +select count (*) + from dba_apply_error_messages em +/ + +prompt .... Detail Error messages around the actual error + + select em.local_transaction_id + , em.object_owner || '.' || em.object_name as object_name + , em.operation + , em.transaction_message_number + , em.message + from dba_apply_error_messages em, dba_apply_error ar + where em.local_transaction_id = ar.local_transaction_id + and em.transaction_message_number between ar.message_number + - 1 + and message_number + + 1 +order by em.local_transaction_id, em.transaction_message_number, em.position +/ + +prompt ... +prompt ... check apply statistic for the last 24 hours +prompt ... check apply statistic first line is the cumulativ value over the whole statistic +prompt ... create from statistic, last hour values can be 0 in statistic was not now collected +prompt ... the total count is more informal, the highest number can be ignored - bug in the SQL Script + +column instance_number format A2 heading "IN|ST" +column hhour format a11 heading "Apply|Hour" +column apply_name format a16 heading "Apply|Name" +column server_total_messages_applied format 999g999g999 heading "applied | total" +column reader_total_messages_dequeued format 999g999g999 heading "dequeued| total" + + select instance_number + , hhour + , apply_name + , nvl ( server_total_messages_applied + - (lag (server_total_messages_applied, 1, 0) over (order by server_total_messages_applied)) + , 0) + as server_total_messages_applied + , nvl ( reader_total_messages_dequeued + - (lag (reader_total_messages_dequeued, 1, 0) over (order by reader_total_messages_dequeued)) + , 0) + as reader_total_messages_dequeued + from ( select nvl (to_char (stat.instance_number), '-') as instance_number + , to_char (hour_list.sorthour, 'dd.mm hh24:mi') as hhour + -- , stat.STARTUP_TIME + , nvl (stat.apply_name, '-') as apply_name + , nvl (stat.server_total_messages_applied, 0) as server_total_messages_applied + , nvl (stat.reader_total_messages_dequeued, 0) as reader_total_messages_dequeued + from ( select ah.instance_number + , to_number (to_char (sh.end_interval_time, 'YYYYMMDDHH24')) as interval_time + -- , to_char(ah.STARTUP_TIME,'dd.mm hh24:mi') as STARTUP_TIME + , ah.apply_name + , round (max (server_total_messages_applied)) as server_total_messages_applied + , round (max (reader_total_messages_dequeued)) as reader_total_messages_dequeued + , to_number (to_char (min (end_interval_time), 'YYYYMMDDHH24')) as joinhour + from dba_hist_streams_apply_sum ah, dba_hist_snapshot sh + where ah.snap_id = sh.snap_id + and sh.end_interval_time > trunc ( sysdate + - 1) + group by ah.instance_number -- , to_char(ah.STARTUP_TIME,'dd.mm hh24:mi') + , ah.apply_name, to_number (to_char (sh.end_interval_time, 'YYYYMMDDHH24'))) stat + , -- get the last 24 hours + ( select to_date (to_char ( ( sysdate - 1 - ( 1 / 24)) + ( 1 / 24 * rownum) , 'YYYYMMDDHH24') , 'YYYYMMDDHH24') sorthour + , to_number (to_char ( ( sysdate - 1 - ( 1 / 24)) + ( 1 / 24 * rownum), 'YYYYMMDDHH24')) joinhour + from user_objects + where rownum < 26 + order by sorthour) hour_list + where hour_list.joinhour = stat.joinhour(+) + order by hour_list.sorthour asc) +order by hhour +/ + +-- column component_name heading 'component|name' format a24 +-- column component_type heading 'component|type' format a12 +-- column action heading 'action' format a18 +-- column source_database_name heading 'source|database' format a10 +-- column object_owner heading 'object|owner' format a8 +-- column object_name heading 'object|name' format a18 +-- column command_type heading 'command|type' format a7 +-- +-- select component_name +-- ,component_type +-- ,action +-- ,source_database_name +-- ,object_owner +-- ,object_name +-- ,command_type +-- ,ACTION_DETAILS +-- ,to_char(MESSAGE_CREATION_TIME,'dd.mm.yyyy hh24:mi' ) +-- from v$streams_message_tracking +-- / + +column consumer_name heading 'capture|process|name' format a18 +column source_database heading 'source|database' format a10 +column sequence# heading 'sequence|number' format 99999999 +column name heading 'required|archived redo log|file name' format a60 + +/* +select r.consumer_name + , r.source_database + , r.sequence# + , r.name + , to_char(FIRST_TIME,'dd.mm hh24:mi') as start_time +from dba_registered_archived_log r + , dba_capture c +where r.consumer_name = c.capture_name + and r.next_scn >= c.required_checkpoint_scn + order by FIRST_TIME,THREAD# asc +/ + */ + + -- clear break \ No newline at end of file diff --git a/synonym.sql b/synonym.sql new file mode 100644 index 0000000..600e1ee --- /dev/null +++ b/synonym.sql @@ -0,0 +1,77 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get summary over synonyms +-- +-- Must be run with dba privileges +-- +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TYPE_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Type => &&TYPE_NAME. + +column owner format a15 heading "Synonym|Owner" +column table_owner format a15 heading "Object|Owner" +column object_type format a15 heading "Object|Type" +column obj_count format 999G999 heading "Object|Count" +column synonym_name format a27 heading "Synonym|Name" +column table_name format a27 heading "Object|Name" +column db_link format a10 heading "DB|Link" + + +ttitle "Overview over all Synonyms and types" SKIP 2 - + +select obj.object_type + , syn.owner + , syn.table_owner + , count(*) as obj_count +from dba_objects obj + , dba_synonyms syn +where syn.table_owner=upper('&&OWNER.') + and syn.table_owner=obj.owner + and obj.object_name=syn.table_name +group by syn.owner + , syn.table_owner + , obj.object_type +order by obj.object_type +/ + +ttitle "Detail for this type &&TYPE_NAME." SKIP 2 - + +select syn.owner + , syn.synonym_name + , syn.table_owner + , syn.table_name + , syn.db_link + , obj.object_type +from dba_objects obj + ,dba_synonyms syn +where syn.table_owner=upper('&&OWNER.') + and syn.table_owner=obj.owner + and obj.object_name=syn.table_name + and obj.object_type like upper('&&TYPE_NAME.%') +order by obj.object_type,syn.synonym_name +/ + +ttitle "delete Script for invalid synonym - synonym points on an not existing object" SKIP 2 + +select 'drop ' || decode(s.owner, 'PUBLIC', 'PUBLIC SYNONYM ', 'SYNONYM ' || s.owner || '.') || s.synonym_name || ';' as DELETE_ME + from dba_synonyms s + where s.table_owner=upper('&&OWNER.') + and (db_link is null or db_link = 'PUBLIC') + and not exists (select 1 + from dba_objects o + where decode(s.table_owner, 'PUBLIC', o.owner, s.table_owner) = o.owner + and s.table_name = o.object_name + ) +/ + +prompt + +ttitle off diff --git a/synonym_detail.sql b/synonym_detail.sql new file mode 100644 index 0000000..b679706 --- /dev/null +++ b/synonym_detail.sql @@ -0,0 +1,49 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get detail over one synonym +-- +-- Must be run with dba privileges +-- +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define SYN_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = SYN_NAME => &&SYN_NAME. + +column owner format a15 heading "Synonym|Owner" +column table_owner format a15 heading "Object|Owner" +column object_type format a15 heading "Object|Type" +column obj_count format 999G999 heading "Object|Count" +column synonym_name format a27 heading "Synonym|Name" +column table_name format a27 heading "Object|Name" +column db_link format a10 heading "DB|Link" + + +ttitle "Detail for this synonym &&SYN_NAME." SKIP 2 - + +select syn.owner + , syn.synonym_name + , syn.table_owner + , syn.table_name + , syn.db_link + , obj.object_type +from dba_objects obj + ,dba_synonyms syn +where syn.table_owner=upper('&&OWNER.') + and syn.table_owner=obj.owner + and obj.object_name=syn.table_name + and syn.synonym_name like upper('&&SYN_NAME.%') +order by obj.object_type,syn.synonym_name +/ + +prompt + +ttitle off + + diff --git a/system_stat.sql b/system_stat.sql new file mode 100644 index 0000000..7619191 --- /dev/null +++ b/system_stat.sql @@ -0,0 +1,89 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the DB internal system stat values like workload statistic and i/o calibrate values +--============================================================================== +set linesize 130 pagesize 300 + +ttitle left "Workload Statistic Values" skip 2 + +column SNAME format a15 heading "Statistic|Name" +column pname format a12 heading "Parameter" +column PVAL1 format a20 heading "Value 1" +column PVAL2 format a20 heading "Value 2" + +select sname + ,pname + ,to_char(pval1, '999G999G999D99') as pval1 + ,pval2 + from sys.aux_stats$ + order by 1 + ,2 +/ + +prompt .... CPUSPEED Workload CPU speed in millions of cycles/second +prompt .... CPUSPEEDNW Noworkload CPU speed in millions of cycles/second +prompt .... IOSEEKTIM Seek time + latency time + operating system overhead time in milliseconds +prompt .... IOTFRSPEED Rate of a single read request in bytes/millisecond +prompt .... MAXTHR Maximum throughput that the I/O subsystem can deliver in bytes/second +prompt .... MBRC Average multiblock read count sequentially in blocks +prompt .... MREADTIM Average time for a multi-block read request in milliseconds +prompt .... SLAVETHR Average parallel slave I/O throughput in bytes/second +prompt .... SREADTIM Average time for a single-block read request in milliseconds + + + +column START_TIME format a21 heading "Start|time" +column END_TIME format a21 heading "End|time" +column MAX_IOPS format 9999999 +--heading "Block/s|data block" +column MAX_MBPS format 9999999 +--heading "MB/s|maximum-sized read" +column MAX_PMBPS format 9999999 +--heading "MB/s|largeI/0" +column LATENCY format 9999999 +--heading "Latency|data block read" +column NUM_PHYSICAL_DISKS format 999 heading "Disk|Cnt" + + +ttitle left "I/O Calibrate Values" skip 2 + + +select to_char(START_TIME,'dd.mm.yyyy hh24:mi') as START_TIME + ,to_char(END_TIME,'dd.mm.yyyy hh24:mi') as END_TIME + ,MAX_IOPS + ,MAX_MBPS + ,MAX_PMBPS + ,LATENCY + ,NUM_PHYSICAL_DISKS + from dba_rsrc_io_calibrate +/ + + +prompt .... START_TIME Start time of the most recent I/O calibration +prompt .... END_TIME End time of the most recent I/O calibration +prompt .... MAX_IOPS Maximum number of data block read requests that can be sustained per second +prompt .... MAX_MBPS Maximum megabytes per second of maximum-sized read requests that can be sustained +prompt .... MAX_PMBPS Maximum megabytes per second of large I/O requests that can be sustained by a single process +prompt .... LATENCY Latency for data block read requests +prompt .... NUM_PHYSICAL_DISKS Number of physical disks in the storage subsystem (as specified by the user) + + +column INST_ID format 999 heading "IN|ID" +column STATUS format a13 heading "Status" +column CALIBRATION_TIME format a21 heading "Calibration|time" + + +ttitle left "I/O Calibrate Status" skip 2 + +select INST_ID + , STATUS + , to_char(CALIBRATION_TIME,'dd.mm.yyyy hh24:mi') as CALIBRATION_TIME + from GV$IO_CALIBRATION_STATUS +order by 1 +/ + +prompt ... You should see that your IO Calibrate is READY and therefore Auto DOP is ready. +prompt + +ttitle off + diff --git a/tab.sql b/tab.sql new file mode 100644 index 0000000..5b1c47c --- /dev/null +++ b/tab.sql @@ -0,0 +1,48 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: search the table in the database +-- Parameter 1: Name of the table +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define TAB_NAME = '&1' + +prompt +prompt Parameter 1 = Tab Name => &&TAB_NAME. +prompt + +column owner format a15 heading "Owner" +column table_name format a30 heading "Table/View Name" +column otype format a5 heading "Type" +column comments format a30 heading "Comment on this | table/view" +column tablespace_name format a40 heading "Tablespace|Name" + +select t.owner + , t.table_name + , 'table' as otype + , nvl (c.comments, 'n/a') as comments + , t.tablespace_name + from dba_tables t, dba_tab_comments c + where upper (t.table_name) like upper ('%&&tab_name.%') + and c.table_name(+) = t.table_name + and c.owner(+) = t.owner + and c.table_type(+) = 'TABLE' +union +select v.owner + , v.view_name + , 'view' as otype + , nvl (c.comments, 'n/a') as comments + , 'n/a' + from dba_views v, dba_tab_comments c + where upper (v.view_name) like upper ('%&&tab_name.%') + and c.table_name(+) = v.view_name + and c.owner(+) = v.owner + and c.table_type(+) = 'VIEW' +order by 1, 2 +/ + diff --git a/tab_cat.sql b/tab_cat.sql new file mode 100644 index 0000000..37c70e3 --- /dev/null +++ b/tab_cat.sql @@ -0,0 +1,27 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the tables of this user +-- Date: September 2013 +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +ttitle left "Tables and Views for this akt user" skip 2 + +column table_name format a30 heading "Table/View Name" +column ttype format a9 heading "Type" +column comments format a60 heading "Comment on this table/view" +column tablespace_name format a20 heading "Tablespace Name" + +select t.table_name + , t.table_type as ttype + , nvl(c.comments,'n/a') as comments + from cat t + ,user_tab_comments c +where c.table_name (+) = t.table_name +order by 2,1 +/ + +ttitle off diff --git a/tab_count.sql b/tab_count.sql new file mode 100644 index 0000000..ddb65bb --- /dev/null +++ b/tab_count.sql @@ -0,0 +1,40 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: List tables +-- Date: 01.September 2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define TAB_NAME = '&1' + +prompt +prompt Parameter 1 = Tab Name => &&TAB_NAME. +prompt + +ttitle left "Count table entries" skip 2 + +column table_name format a30 heading "Table|name" +column num_rows format 9999999 heading "Num|rows" +column size_MB format 999G990D000 heading "Size|MB" +column table_size format 999G990D000 heading "Size Table|MB" +column index_size format 999G990D000 heading "Size Index|MB" + + select t.table_name + , t.num_rows + , round(s.bytes/1024/1024,3) as size_MB + , (select count(*) from &&TAB_NAME ) as count_rows + from all_tables t + , dba_segments s + where t.table_name = s.segment_name + and upper(t.table_name) = upper('&&TAB_NAME') +order by t.table_name +/ + +prompt +prompt ... num rows are from the db table statistic! +prompt ... count rows are the record count in the table +prompt + + +ttitle off \ No newline at end of file diff --git a/tab_data_changes.sql b/tab_data_changes.sql new file mode 100644 index 0000000..82598e1 --- /dev/null +++ b/tab_data_changes.sql @@ -0,0 +1,50 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get an overview over changes on the tables of a user - parameter - Owner +--============================================================================== +----http://www.oracleangels.com/2011/01/automatic-statistics-gathering-job.html +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt + + +select num_rows + , last_analyzed + , tot_updates + , table_owner + , table_name + --, partition_name + --, subpartition_name + --, inserts + -- , updates + --, deletes + -- , timestamp +--, truncated + , to_char(perc_updates, 'FM999,999,999,990.00') perc_updates +from ( + select a.* , nvl(decode(num_rows, 0, '-1', 100 * tot_updates / num_rows), -1) perc_updates + from ( + select + (select num_rows + from dba_tables + where dba_tables.table_name = DBA_TAB_MODIFICATIONS.table_name + and DBA_TAB_MODIFICATIONS.table_owner = dba_tables.owner) num_rows + , (select last_analyzed + from dba_tables + where dba_tables.table_name = DBA_TAB_MODIFICATIONS.table_name + and DBA_TAB_MODIFICATIONS.table_owner = dba_tables.owner) last_analyzed + , (inserts + updates + deletes) tot_updates + , DBA_TAB_MODIFICATIONS.* + from sys.DBA_TAB_MODIFICATIONS + ) a +) b +where perc_updates > 10 + and table_owner = upper('&&OWNER.') +/ + diff --git a/tab_ddl.sql b/tab_ddl.sql new file mode 100644 index 0000000..ee35818 --- /dev/null +++ b/tab_ddl.sql @@ -0,0 +1,104 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: extract the DDL of a object in the database +-- +-- Parameter 2: Owner of the table/object +-- Parameter 1: Name of the table/object +-- +-- Must be run with dba privileges +-- +--============================================================================== +set verify off +set linesize 130 pagesize 3000 + +define OWNER = '&1' +define TAB_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&TAB_NAME. +prompt + +variable ddllob clob + +set heading off +set echo off + +set long 1000000; + +declare + cursor c_tab_idx is + select index_name,owner from all_indexes where table_name=upper('&&TAB_NAME.') and TABLE_OWNER=upper('&&OWNER.'); + + cursor c_obj_type is + select object_type,owner + from all_objects + where object_name =upper('&&TAB_NAME.') + and ( owner=upper('&&OWNER.') or owner='PUBLIC' ) + and object_type!='TABLE PARTITION'; + + v_type varchar2(32); + v_owner varchar2(32); +begin +-- set the transformation attributes + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'OID', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SEGMENT_ATTRIBUTES', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'TABLESPACE', true ); + -- no Schema Name inside + DBMS_METADATA.SET_TRANSFORM_PARAM(dbms_metadata.SESSION_TRANSFORM, 'EMIT_SCHEMA', false); + + + for o_rec in c_obj_type + loop + + v_type:=o_rec.object_type; + v_owner:=o_rec.owner; + + :ddllob:=dbms_metadata.get_ddl(replace(v_type,' ','_') ,upper('&&TAB_NAME.'),v_owner); + + + :ddllob:=:ddllob||chr(10)||chr(10)||'-- DDL for Grants : '||chr(10); + begin + :ddllob:=:ddllob||dbms_metadata.GET_DEPENDENT_DDL('OBJECT_GRANT',upper('&&TAB_NAME.'),v_owner); + + exception + when others then + :ddllob:=:ddllob||chr(10)||chr(10)||'-- NO DDL for Grants found : '||chr(10); + end; + + -- get the index DDL for this table + if v_type = 'TABLE' then + for rec in c_tab_idx + loop + + :ddllob:=:ddllob||chr(10)||chr(10)||'-- DDL for Index : '||rec.index_name||chr(10); + + :ddllob:=:ddllob||dbms_metadata.get_ddl('INDEX',rec.index_name,rec.owner); + + + end loop; + end if; + + :ddllob:=:ddllob||chr(10)||chr(10)||'-- DDL for Trigger : '||chr(10); + begin + -- get the trigger if exits + :ddllob:=:ddllob||dbms_metadata.GET_DEPENDENT_DDL('TRIGGER' ,upper('&&TAB_NAME.'),v_owner); + + exception + when others then + :ddllob:=:ddllob||chr(10)||chr(10)||'-- NO DDL for Trigger found : '||chr(10); + end; + + end loop; + +end; +/ + +print ddllob + +undefine ddllob + +set heading on diff --git a/tab_defekt_blocks.sql b/tab_defekt_blocks.sql new file mode 100644 index 0000000..cccc6fd --- /dev/null +++ b/tab_defekt_blocks.sql @@ -0,0 +1,50 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: check for block corruption +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +column segment_name format a16 heading "Segment|Name" +column tablespace_name format a16 heading "Tablespace|Name" +column partition_name format a10 heading "Partition|Name" +column owner format a14 +column relative_fno format 9999 heading "File|No" +column segment_type format a0 heading "Segment|Type" +column file# format 9999 heading "File|Id" +column defekt_range format a18 heading "defect|range" + + +prompt Check of the database has detected corrupt blocks + +select count(*) from v$database_block_corruption; + + --file# + --block# + --blocks + --corruption_change# + --corruption_type + +prompt ... +prompt Check which tables are affected +prompt + +select ext.owner + , ext.segment_name + , ext.segment_type + , ext.relative_fno + , ext.partition_name + , ext.tablespace_name + , blc.file# + , blc.block# ||' for '||blc.blocks as defekt_range + from dba_extents ext + , v$database_block_corruption blc +where ext.file_id = blc.file# + and blc.block# between ext.block_id and ext.block_id + ext.blocks - 1 +/ + + + +prompt ... to check the whole data file +prompt .... you can use RMAN> VALIDATE DATAFILE 5; + diff --git a/tab_defekt_blocks_bad_table.sql b/tab_defekt_blocks_bad_table.sql new file mode 100644 index 0000000..2f2c0db --- /dev/null +++ b/tab_defekt_blocks_bad_table.sql @@ -0,0 +1,86 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- create a table with all ids and rowid's for a not full readable oracle table with lobs +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +set concat off +set serveroutput on + + +define OWNER = 'GPI' +define TABLE_NAME = 'LOBTAB' +define TEST_COL = 'dbms_lob.getlength(DATA)' +define TABLESPACE = 'USERS' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Table Name => &&TABLE_NAME. +prompt Parameter 3 = TEST Col Name => &&TEST_COL. +prompt Parameter 4 = TEST Col Name => &&TABLESPACE. +prompt + +--------------------------------- +-- create the bad_rowid table +--------------------------------- + +declare + v_count number:=0; +begin + select count(*) into v_count from dba_tables where table_name = 'BAD_BLOCK_ROWS'; + + if v_count > 0 then + execute immediate 'drop table bad_block_rows'; + dbms_output.put_line('Info -- drop Table bad_block_rows'); + end if; + + execute immediate 'create table bad_block_rows (row_id ROWID ,oracle_error_code number) tablespace &&TABLESPACE'; + dbms_output.put_line('Info -- create Table bad_block_rows'); + +end; +/ + +--------------------------------- +-- Read all data from the table +-- remember all defect rowids +--------------------------------- + +declare + v_row rowid; + v_error_code number; + v_bad_rows number := 0; + v_good_rows number :=0; + + e_ora1578 EXCEPTION; + e_ora600 EXCEPTION; + PRAGMA EXCEPTION_INIT(e_ora1578, -1578); + PRAGMA EXCEPTION_INIT(e_ora600, -600); + +begin + for rec in (select rowid rid, &&TEST_COL from &&OWNER.&TABLE_NAME ) -- where rownum < 10 + loop + begin + -- read the rowid + v_row:=rec.rid; + v_good_rows:=v_good_rows+1; + + exception + when e_ora1578 then + v_bad_rows := v_bad_rows + 1; + insert into bad_block_rows(row_id,oracle_error_code) values(rec.rid,1578); + commit; + when e_ora600 then + v_bad_rows := v_bad_rows + 1; + insert into bad_block_rows(row_id,oracle_error_code) values(rec.rid,600); + commit; + when others then + v_error_code:=SQLCODE; + v_bad_rows := v_bad_rows + 1; + insert into bad_block_rows(row_id,oracle_error_code) values(rec.rid,v_error_code); + commit; + end; + end loop; + dbms_output.put_line('Info -- Total Rows identified with errors in LOB column: '||v_bad_rows); +end; +/ diff --git a/tab_desc.sql b/tab_desc.sql new file mode 100644 index 0000000..2ad5b75 --- /dev/null +++ b/tab_desc.sql @@ -0,0 +1,76 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: describe a table in the database +-- +-- Parameter 1: Owner of the table +-- Parameter 2: Name of the table +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TAB_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&TAB_NAME. +prompt + +column column_name format a25 heading "Column name" +column data_type format a25 heading "Data type" +column data_default format a20 heading "Column default" +column nullable format a3 heading "Null ?" +column char_length format a4 heading "Char Count" + +ttitle left "Describe the columns of a table" skip 2 + +select + column_name + ,data_length + ,data_precision + ,DATA_SCALE + , case data_type + when 'VARCHAR2' then 'varchar2('||lpad(data_length,5)||' '|| decode(char_used,'B','Byte','C','Char',char_used)||')' + when 'NUMBER' then 'number ('||lpad(data_length,5)|| nvl(data_precision,'') ||' '|| nvl(DATA_SCALE,'') ||')' + when 'DATE' then 'date' + else rpad(lower(data_type),8) ||'('||lpad(data_length,5)||nvl(data_precision,'') ||')' + end as data_type + , case when char_length > 0 then to_char(char_length) else '-' end as char_length + , decode(nullable,'Y','YES','NO') as nullable + , data_default + from all_tab_columns + where table_name like upper('&&TAB_NAME.') + and owner like upper('&&OWNER.') +order by COLUMN_ID +/ + +prompt ... + +ttitle "Settings for this table &TAB_NAME." SKIP 2 + +column table_name format a15 heading "Table|name" +column monitoring format a10 heading "Monitoring|enabled?" +column num_rows format 9999999999 heading "Num|Rows" +column degree format a5 heading "Deg|ree" +column row_movement format a10 heading "Row|Movement" +column buffer_pool format a10 heading "Pool" + +select table_name + , status + , to_char(last_analyzed,'dd.mm.yyyy hh24:mi') as last_analyzed + , num_rows + , degree + , row_movement + , monitoring + , buffer_pool + from all_tables +where table_name like upper('&TAB_NAME.') + and owner like upper('&OWNER.') +/ + +ttitle off diff --git a/tab_ext.sql b/tab_ext.sql new file mode 100644 index 0000000..e68b14a --- /dev/null +++ b/tab_ext.sql @@ -0,0 +1,53 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Show all external tables in the database +-- Must be run with dba privileges +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +column owner format a20 heading "Owner" +column table_name format a20 heading "Table|Name" +column location format a30 heading "Location" +column directory_owner format a3 heading "DO" +column directory_name format a20 heading "Directory|Name" + + select owner + , table_name + , location + , directory_owner + , directory_name + from dba_external_locations +order by owner, table_name +/ + +prompt +prompt Details ... +prompt + +column reject_limit format a20 heading "Reject|Limit" +column access_type format a20 heading "Access|Type" +column property format a10 heading "Property" +column access_parameters format a80 heading "Access|Parameter" fold_before word_wrapped + + +break on row skip 2 + +ttitle 'Detail of the external Tables :' + +set long 64000 + + select table_name + , reject_limit + , access_type + , property + , access_parameters + from dba_external_tables +order by owner, table_name +/ + + +clear break + +ttitle off \ No newline at end of file diff --git a/tab_identity_col.sql b/tab_identity_col.sql new file mode 100644 index 0000000..8b236b4 --- /dev/null +++ b/tab_identity_col.sql @@ -0,0 +1,37 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get informations about identiy columns in tables +--============================================================================== +-- https://oracle-base.com/articles/12c/identity-columns-in-oracle-12cr1 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TAB_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&TAB_NAME. + + +COLUMN table_name FORMAT A20 +COLUMN column_name FORMAT A15 +COLUMN generation_type FORMAT A10 +COLUMN identity_options FORMAT A50 +COLUMN sequence_name FORMAT A30 + + +SELECT table_name, + column_name, + generation_type, + identity_options +FROM dba_tab_identity_cols +/ + +SELECT a.name AS table_name, + b.name AS sequence_name +FROM sys.idnseq$ c + JOIN obj$ a ON c.obj# = a.obj# + JOIN obj$ b ON c.seqobj# = b.obj# +/ diff --git a/tab_iot.sql b/tab_iot.sql new file mode 100644 index 0000000..eef5f37 --- /dev/null +++ b/tab_iot.sql @@ -0,0 +1,133 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: show information about a index organized table - parameter - Owner, Table name +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define ENTER_OWNER='&1' +define ENTER_TABLE='&2' + +prompt +prompt Parameter 1 = User Name => &&ENTER_OWNER. +prompt Parameter 2 = Table Name => &&ENTER_TABLE. +prompt + +ttitle left "Check if the table is a IOT Table" skip 2 + +select 'This Table is'||decode(nvl(IOT_TYPE,'-'),'IOT',' index organised','heap organised') as TABLE_TYPE + from dba_tables + where upper(table_name) like upper('&ENTER_TABLE.') + and upper(owner) = upper('&ENTER_OWNER.') +/ + +ttitle left "IOT Name and Table space for Overflow Segments" skip 2 + +column owner format a10 heading "Owner" +column overflow_table format a20 heading "OverFlow Table|Name" +column IOT_TYPE format a14 heading "IOT|Type" +column IOT_NAME format a20 heading "IOT|Name" +column tablespace_name format a12 heading "IDX|TBS Name" +column overFlowTabspace format a12 heading "OverFlow|TBS Name" +column index_name format a20 heading "IOT Index|Name" +column iot_name_table format a20 heading "IOT Tab|Name" + +select i.owner + , i.table_name as iot_name_table + , nvl(t.table_name,'-') as overflow_table + , nvl(i.index_name,'-') as index_name + , nvl(t.IOT_TYPE,'-') as IOT_TYPE + , i.tablespace_name + , t.tablespace_name as overFlowTabspace + from dba_tables t + , dba_indexes i +where t.IOT_NAME (+) = i.table_name + and upper(i.table_name) like upper('&&ENTER_TABLE.') + and upper(i.owner) = upper('&&ENTER_OWNER.') +/ + +ttitle left "IOT Table SIZE " skip 2 + +set heading off + +column index_nameMB fold_after +column IndexSizeMB fold_after +column overflow_tableMB fold_after +column OverFlowSizeMB fold_after +column totalMB fold_after +column lastana fold_after +column numrows fold_after + + +select rpad('Index Name',30,' ') ||'::'||lpad(index_name,22,' ') as index_nameMB + , rpad('Index Size',30,' ') ||'::'||to_char(round((IndexSize/1024/1024),3),'999G999G999G999D99') ||' MB' as IndexSizeMB + , rpad('Overflow Name',30,' ')||'::'||lpad(overflow_table,22,' ') as overflow_tableMB + , rpad('Overflow Size',30,' ')||'::'||to_char(round((OverFlowSize/1024/1024),3),'999G999G999G999D99') ||' MB' as OverFlowSizeMB + , rpad('Total',30,' ') ||'::'||to_char(round(((IndexSize+OverFlowSize)/1024/1024),3),'999G999G999G999D99') ||' MB' as totalMB + , rpad('Last Analyzed',30,' ') ||'::'||to_char(LAST_ANALYZED,'dd.mm.yyyy hh24:mi') ||' ' as lastana + , rpad('Num Rows',30,' ') ||'::'||NUM_ROWS ||' ' as numrows + from ( + select nvl(i.index_name,'-') as index_name + , (select sum(bytes) from dba_segments where segment_name=i.index_name and owner=i.owner) as IndexSize + , nvl(t.table_name,'-') as overflow_table + , nvl((select sum(bytes) from dba_segments where segment_name=t.table_name and owner=t.owner ),0) as OverFlowSize + , i.LAST_ANALYZED + , i.NUM_ROWS + from dba_tables t + , dba_indexes i + where t.IOT_NAME (+) = i.table_name + and upper(i.table_name) like upper('&&ENTER_TABLE.') + and upper(i.owner) = upper('&&ENTER_OWNER.') +) +order by 1 +/ + +set heading on + +ttitle left "Check if the columns are in the overflow segment of the IOT Table" skip 2 + +select c.table_name + , c.column_name + , case + when i.include_column != 0 then ( case when c.column_id < i.include_column then 'TOP' else 'OVERFLOW' end ) + else 'TOP' + end as segment + from dba_tab_columns c + , dba_indexes i +where i.table_name (+) = c.table_name + and i.owner (+) = c.owner + and upper(c.table_name) like upper('&enter_table.') + and upper(c.owner) = upper('&enter_owner.') + order by table_name + , column_id +/ + +ttitle off + +/* test Case +CREATE TABLE T_IOT1( ID NUMBER , wert varchar2(20) , CONSTRAINT T_IOT1_PK PRIMARY KEY (ID) ENABLE ) ORGANIZATION INDEX; + +# mit den ersten Daten füllen: +BEGIN +FOR i IN 1..100 + loop + INSERT INTO T_IOT1 VALUES (i,to_char(i)||'er Wert'); +END loop; +commit; +END; +/ +SELECT * FROM T_IOT1 +/ +---- zweiter test mit overflow +CREATE TABLE T_IOT2( ID NUMBER , wert varchar2(20) , CONSTRAINT T_IOT2_PK PRIMARY KEY (ID) ENABLE ) ORGANIZATION INDEX INCLUDING wert OVERFLOW; +BEGIN +FOR i IN 1..100 + loop + INSERT INTO T_IOT2 VALUES (i,to_char(i)||'er Wert'); +END loop; +commit; +END; +/ +*/ + + diff --git a/tab_iot_all.sql b/tab_iot_all.sql new file mode 100644 index 0000000..bc3a46b --- /dev/null +++ b/tab_iot_all.sql @@ -0,0 +1,35 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Show all IOT's in the database +--============================================================================== +set verify off +set linesize 130 pagesize 300 + + +ttitle left "IOT Name and Table space for Overflow Segments" skip 2 + +column owner format a16 heading "Owner" +column overflow_table format a20 heading "OverFlow Table|Name" +column IOT_TYPE format a14 heading "IOT|Type" +column IOT_NAME format a20 heading "IOT|Name" +column tablespace_name format a12 heading "IDX|TBS Name" +column overFlowTabspace format a12 heading "OverFlow|TBS Name" +column index_name format a24 heading "IOT Index|Name" +column iot_name_table format a22 heading "IOT Tab|Name" + +select i.owner + , i.table_name as iot_name_table + , nvl(t.table_name,'-') as overflow_table + , nvl(i.index_name,'-') as index_name + , nvl(t.IOT_TYPE,'-') as IOT_TYPE + , i.tablespace_name + , t.tablespace_name as overFlowTabspace + from dba_tables t + , dba_indexes i +where t.IOT_NAME = i.table_name (+) + and t.owner = i.owner + and t.IOT_TYPE like 'IOT%' +order by i.owner,t.table_name +/ + +ttitle off \ No newline at end of file diff --git a/tab_last.sql b/tab_last.sql new file mode 100644 index 0000000..b1230fb --- /dev/null +++ b/tab_last.sql @@ -0,0 +1,96 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show change time of a table +-- Date: September 2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TAB_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&TAB_NAME. + +define FILTER = '&3' +prompt Parameter 3 = Tab Filter => &&FILTER. +prompt + +set serveroutput on; + +declare + + v_tab_owner varchar2(32):='&&OWNER.'; + v_tab_name varchar2(32):='&&TAB_NAME.'; + v_filter varchar2(32):='&&FILTER.'; + v_sql varchar2(2000); + v_max_scn number; + v_min_scn number; + v_count number; + + function getSCNTime(p_scn number) + return varchar2 + is + v_return varchar2(20); + begin + + select to_char(FIRST_TIME,'dd.mm.yyyy hh24:mi:ss') into v_return + from V$LOG_HISTORY + where p_scn between FIRST_CHANGE# and NEXT_CHANGE#; + + exception + when others then + + select to_char(min(FIRST_TIME),'dd.mm.yyyy hh24:mi:ss') into v_return + from V$LOG_HISTORY + where FIRST_CHANGE# > p_scn; + + return 'no exact value found but older then :: '||v_return; + + end; +begin + + v_sql:=' select max(ora_rowscn),min(ora_rowscn),count(*) from '||upper(v_tab_owner)||'.'||upper(v_tab_name); + + if length(v_filter) > 1 then + v_sql:=v_sql||' where '||v_filter; + end if; + + dbms_output.put_line('Info -- start search of last change date for the table :: '||upper(v_tab_name)); + dbms_output.put_line('Info -- sql ::'|| v_sql); + dbms_output.put_line('Info --'); + + execute immediate v_sql into v_max_scn,v_min_scn,v_count; + + dbms_output.put_line('Info -- MAX SCN:: '||to_char(v_max_scn)); + dbms_output.put_line('Info -- MIN SCN:: '||to_char(v_min_scn)); + dbms_output.put_line('Info -- Count :: '||to_char(v_count)); + dbms_output.put_line('Info --'); + + if v_count > 0 then + dbms_output.put_line('Info -- Transform scn to timestamp'); + dbms_output.put_line('Info -- May be the data has this age'); + + begin + dbms_output.put_line('Info -- Max time :: ' || SCN_TO_TIMESTAMP(v_max_scn)); + exception + when others then + dbms_output.put_line('Info -- For min time the scn is not valid :: '||v_max_scn); + dbms_output.put_line('Info -- Try to read from V$LOG_HISTORY found :: '||getSCNTime(v_max_scn)); + end; + dbms_output.put_line('Info --'); + begin + dbms_output.put_line('Info -- Min time :: ' || SCN_TO_TIMESTAMP(v_min_scn)); + exception + when others then + dbms_output.put_line('Info -- For min time the scn is not valid :: '||v_min_scn); + dbms_output.put_line('Info -- Try to read from V$LOG_HISTORY found :: '||getSCNTime(v_min_scn)); + end; + else + dbms_output.put_line('Info -- No Records found'); + end if; + +end; +/ diff --git a/tab_mat.sql b/tab_mat.sql new file mode 100644 index 0000000..ce73e31 --- /dev/null +++ b/tab_mat.sql @@ -0,0 +1,64 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get informations about mat views +--============================================================================== +-- http://docs.oracle.com/cd/B19306_01/server.102/b14237/statviews_1105.htm +--============================================================================== + +set linesize 130 pagesize 300 + +column owner format a10 heading "Owner" +column mview_name format a30 heading "Mview|Name" +column last_refresh_date format a16 heading "Last|refresh" +column refresh_method format a8 heading "Ref|mod" +column staleness format a10 heading "Stale" +column rewrite_enabled format a3 heading "RW|ena" +column comments format a20 heading "Comments" word_wrapped +column detailobj_name format a20 heading "Base|Tables" +column size_mb format 999G999G999 heading "Size" + +break on owner skip 2 +compute sum of SIZE_MB on owner; + + select ma.owner + , ma.mview_name + , round (sum ( ms.bytes / 1024 / 1024), 2) as size_mb + , to_char (ma.last_refresh_date, 'dd.mm.RR HH24:mi') as last_refresh_date + , ma.refresh_method + , ma.staleness + , ma.rewrite_enabled + --, md.detailobj_name + , nvl (mc.comments, '-') as comments + from dba_mviews ma, dba_mview_comments mc--, dba_mview_detail_relations md + , dba_segments ms + where ma.owner = mc.owner(+) + and ma.mview_name = mc.mview_name(+) + -- and ma.owner = md.owner (+) + -- and ma.mview_name = md.mview_name (+) + and ma.owner = ms.owner(+) + and ma.mview_name = ms.segment_name(+) +group by ma.owner + , ma.mview_name + , to_char (ma.last_refresh_date, 'dd.mm.RR HH24:mi') + , ma.refresh_method + , ma.staleness + , ma.rewrite_enabled + --, md.detailobj_name + , nvl (mc.comments, '-') +order by ma.owner, ma.mview_name +/ + +prompt +prompt ... Stale Status +prompt ... FRESH - Materialized view is a read-consistent view of the current state of its masters +prompt ... STALE - Materialized view is out of date because one or more of its masters has changed. +prompt ... If the materialized view was FRESH before it became STALE, +prompt ... then it is a read-consistent view of a former state of its masters. +prompt ... UNUSABLE - Materialized view is not a read-consistent view of its masters from any point in time +prompt ... UNKNOWN - Oracle Database does not know whether the materialized view is in a read-consistent view +prompt ... of its masters from any point in time +prompt ... this is the case for materialized views created on prebuilt tables) +prompt ... UNDEFINED - Materialized view has remote masters. The concept of staleness is not defined for such materialized views. +prompt + +clear break \ No newline at end of file diff --git a/tab_mat_log.sql b/tab_mat_log.sql new file mode 100644 index 0000000..4afbb47 --- /dev/null +++ b/tab_mat_log.sql @@ -0,0 +1,82 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Information about materialized views Logs +--============================================================================== +set verify off +set linesize 130 pagesize 500 + +column log_owner format a10 +column master format a22 +column log_table format a26 +column log_trigger format a10 +column rowids format a3 +column primary_key format a3 +column object_id format a3 +column filter_columns format a3 +column sequence format a3 +column include_new_values format a3 +column purge_asynchronous format a3 +column purge_deferred format a3 +column purge_start format a18 +column purge_interval format a20 +column last_purge_date format a18 +column last_purge_status format 99999 heading "Purge|Status" +column num_rows_purged format 999G999 heading "Num|Rows P" +column commit_scn_based format a3 +column size_mb format 999G990D99 + +compute sum of NUM_ROWS_PURGED on LOG_OWNER +compute sum of SIZE_MB on LOG_OWNER +break on LOG_OWNER + +select ml.LOG_OWNER + , ml.MASTER + , ml.LOG_TABLE + -- , ml.LOG_TRIGGER + -- , ml.ROWIDS + -- , ml.PRIMARY_KEY + -- , ml.OBJECT_ID + -- , ml.FILTER_COLUMNS + -- , ml.SEQUENCE + -- , ml.INCLUDE_NEW_VALUES + -- , ml.PURGE_ASYNCHRONOUS + -- , ml.PURGE_DEFERRED + -- , ml.PURGE_START + -- , ml.PURGE_INTERVAL + , to_char (ml.LAST_PURGE_DATE, 'dd.mm.yyyy hh24:mi') as LAST_PURGE_DATE + , ml.LAST_PURGE_STATUS + , ml.NUM_ROWS_PURGED + -- , ml.COMMIT_SCN_BASED + , round ( ( ds.bytes / 1024/ 1024), 2) as SIZE_MB + from DBA_MVIEW_LOGS ml, dba_segments ds + where ds.OWNER(+) = ml.LOG_OWNER + and ds.SEGMENT_NAME(+) = ml.LOG_TABLE +order by ml.LOG_OWNER, ml.LOG_TABLE +/ + + +-- LOG_OWNER VARCHAR2(30) Owner of the materialized view log +-- MASTER VARCHAR2(30) Name of the master table or master materialized view whose changes are logged +-- LOG_TABLE VARCHAR2(30) Name of the table where the changes to the master table or master materialized view are logged +-- LOG_TRIGGER VARCHAR2(30) Obsolete with Oracle8i and later. Set to NULL. Formerly, this parameter was an after-row trigger on the master which inserted rows into the log. +-- ROWIDS VARCHAR2(3) Indicates whether rowid information is recorded (YES) or not (NO) +-- PRIMARY_KEY VARCHAR2(3) Indicates whether primary key information is recorded (YES) or not (NO) +-- OBJECT_ID VARCHAR2(3) Indicates whether object identifier information in an object table is recorded (YES) or not (NO) +-- FILTER_COLUMNS VARCHAR2(3) Indicates whether filter column information is recorded (YES) or not (NO) +-- SEQUENCE VARCHAR2(3) Indicates whether the sequence value, which provides additional ordering information, is recorded (YES) or not (NO) +-- INCLUDE_NEW_VALUES VARCHAR2(3) Indicates whether both old and new values are recorded (YES) or old values are recorded but new values are not recorded (NO) +-- PURGE_ASYNCHRONOUS VARCHAR2(3) Indicates whether the materialized view log is purged asynchronously (YES) or not (NO) +-- PURGE_DEFERRED VARCHAR2(3) Indicates whether the materialized view log is purged in a deferred manner (YES) or not (NO) +-- PURGE_START DATE For deferred purge, the purge start date +-- PURGE_INTERVAL VARCHAR2(200) For deferred purge, the purge interval +-- LAST_PURGE_DATE DATE Date of the last purge +-- LAST_PURGE_STATUS NUMBER Status of the last purge (error code or 0 for success) +-- NUM_ROWS_PURGED NUMBER Number of rows purged in the last purge +-- COMMIT_SCN_BASED VARCHAR2(3) Indicates whether the materialized view log is commit SCN-based (YES) or not (NO) + + +-- Native: +-- select log, sysdate, youngest, youngest+1/86400, oldest, oldest_pk, oldest_oid, oldest_new, oldest_seq, oscn, oscn_pk, oscn_oid, oscn_new, oscn_seq, flag, purge_job from sys.mlog$ +-- + +clear break \ No newline at end of file diff --git a/tab_mod.sql b/tab_mod.sql new file mode 100644 index 0000000..86071fc --- /dev/null +++ b/tab_mod.sql @@ -0,0 +1,87 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the last modifications on a table +-- Date: October 2013 +-- +-- Source: http://docs.oracle.com/cd/E11882_01/server.112/e25513/statviews_2107.htm#i1591024 +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TAB_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&TAB_NAME. +prompt + +set serveroutput on; + +prompt ... +prompt ... if values are empty flash the counter as dba! with to the table: +prompt ... exec DBMS_STATS.FLUSH_DATABASE_MONITORING_INFO +prompt ... +prompt ... works only if "monitoring" is enabled on this table! +prompt ... + +ttitle "Read Modifications for this table &TAB_NAME." SKIP 2 + + +column TABLE_OWNER format a12 heading "Table|Owner" +column TABLE_NAME format a15 heading "Table|Name" +column PARTITION_NAME format a12 heading "Part|Name" +column SUBPARTITION_NAME format a12 heading "Subpart|Name" +column INSERTS format 999G999G999G999 heading "Inserts|Count" +column UPDATES format 999G999 heading "Updates|Count" +column DELETES format 999G999G999G999 heading "Deletes|Count" +column TIMESTAMP format a20 heading "Last|Access" +column TRUNCATED format a3 heading "Tru|cat" +column DROP_SEGMENTS format 999 heading "Drop Seg| Count" + +select TABLE_OWNER + , TABLE_NAME + , PARTITION_NAME + , SUBPARTITION_NAME + , INSERTS + , UPDATES + , DELETES + , to_char(TIMESTAMP,'dd.mm.yyyy hh24:mi') as TIMESTAMP + , TRUNCATED + , DROP_SEGMENTS + from DBA_TAB_MODIFICATIONS +where TABLE_OWNER like upper('&&OWNER.') + and TABLE_NAME like upper('&&TAB_NAME.') +order by TIMESTAMP asc +/ + + + +prompt ... Inserts - Approximate number of inserts since the last time statistics were gathered +prompt ... Updates - Approximate number of updates since the last time statistics were gathered +prompt ... Deletes - Approximate number of deletes since the last time statistics were gathered +prompt ... Last Access - Indicates the last time the table was modified +prompt ... Drop Seg - Number of partition and subpartition segments dropped since the last analyze +prompt + +ttitle "Last statistic info for this table &TAB_NAME." SKIP 2 + +column table_name format a15 +column MONITORING format a10 heading "Monitoring|enabled?" + +select table_name + , status + , to_char(LAST_ANALYZED,'dd.mm.yyyy hh24:mi') as LAST_ANALYZED + , NUM_ROWS + , AVG_SPACE + , CHAIN_CNT + , AVG_ROW_LEN + , MONITORING + from dba_tables +where table_name like upper('&TAB_NAME.%') + and owner like upper('&OWNER.') +/ + +ttitle off + \ No newline at end of file diff --git a/tab_overview_report.sql b/tab_overview_report.sql new file mode 100644 index 0000000..594b86f --- /dev/null +++ b/tab_overview_report.sql @@ -0,0 +1,77 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: HTML Report over all tables of a database, +-- for example to discuss with development which tables can be deleted +-- Date: September 2015 +-- +--============================================================================== + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_table_overview.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + +set verify off +SET linesize 250 pagesize 2000 + +spool &&SPOOL_NAME + +set markup html on + +ttitle left "Table Overview of this database" skip 2 + +select t.owner + , t.table_name + , o.OBJECT_TYPE + , nvl(o.SUBOBJECT_NAME,'-') as SUBOBJECT_NAME + , 'IN USE' as IN_USE_OR_ARCHIVE + , round( s.bytes /1024/1024 , 3) as size_MB + , t.num_rows + , t.LAST_ANALYZED + , o.LAST_DDL_TIME + , o.CREATED + , t.partitioned + , t.compression + , nvl (c.comments, 'n/a') as comments + -- plsql dependencies + , (select count(*) as results from dba_dependencies dep where dep.REFERENCED_OWNER=t.owner and dep.REFERENCED_NAME=t.table_name) as depObjCount + , (select substr(rtrim ( xmlagg (xmlelement (c, dep.type||':'||dep.name || ',') order by dep.name).extract ('//text()'), ',' ),1,3999) as results from dba_dependencies dep where dep.REFERENCED_OWNER=t.owner and dep.REFERENCED_NAME=t.table_name) as depObjList + from dba_tables t + , dba_tab_comments c + , dba_objects o + , dba_segments s + where 1=1 + -- + and c.table_name(+) = t.table_name + and c.owner(+) = t.owner + and c.table_type(+) = 'TABLE' + -- + and o.object_name = t.table_name + and o.owner = t.owner + -- + and s.segment_name = o.object_name + and s.owner = o.owner + and nvl(s.partition_name,'n/a')=nvl(o.subobject_name,'n/a') + -- + --and t.owner = 'GPI' + -- + and t.owner not in + ('SYS', 'MDSYS', 'SI_INFORMTN_SCHEMA', 'ORDPLUGINS', 'ORDDATA', 'ORDSYS', 'EXFSYS', 'XS$NULL', 'XDB', 'CTXSYS', 'WMSYS' + , 'APPQOSSYS', 'DBSNMP', 'ORACLE_OCM', 'DIP', 'OUTLN', 'SYSTEM', 'FLOWS_FILES', 'SYSMAN', 'OLAPSYS', 'OWBSYS' + , 'OWBSYS_AUDIT') + -- +order by t.owner + , t.table_name +/ + +set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window +host &&SPOOL_NAME diff --git a/tab_part.sql b/tab_part.sql new file mode 100644 index 0000000..32880bb --- /dev/null +++ b/tab_part.sql @@ -0,0 +1,104 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc.: show the partitions of a table +-- Parameter 1: Name of the User +-- Parameter 2: Name of the Table +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TAB_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&TAB_NAME. +prompt + +-------------------- +-- dba_partition_columns +-------------------- + +column table_owner format a12 heading "Owner" +column partition_name format a30 heading "Part|Name" +column partition_position format 999 heading "Posi|tion" +column subpartition_count format 999 heading "Sub|cnt" +column tablespace_name format a15 heading "Table space|Name" +column inital_ex_size_mb format 9999 heading "Inital Ex|MB" +column size_on_disk format 99999999 heading "Size on disk|MB" + +ttitle "Portions Overview of the table &&OWNER..&&TAB_NAME." SKIP 1 + +select p.partition_position + , p.partition_name + , p.subpartition_count + , p.tablespace_name + , (p.initial_extent/1024/1024) as inital_ex_size_mb + , round((s.bytes/1024/1024),0) as size_on_disk + from dba_tab_partitions p, dba_segments s +where p.table_owner like upper('&&OWNER.') + and p.table_name like upper('&&TAB_NAME.') + and p.table_name= s.SEGMENT_NAME (+) + and p.partition_name= s.PARTITION_NAME (+) + and p.table_owner = s.owner (+) +order by p.partition_position +/ + +ttitle "Portions last value of the table &&OWNER..&&TAB_NAME." SKIP 1 + +column partition_position format 99 heading "Pos" +column partition_name format a30 heading "Part|Name" +column HIGH_VALUE format a100 heading "Portions High Value" fold_before + + +-------------------- +-- read long buffer to read long values +set long 32767 +-------------------- + +select p.partition_position + , p.partition_name + , HIGH_VALUE + from dba_tab_partitions p + , dba_segments s +where p.table_owner like upper('&&OWNER.') + and p.table_name like upper('&&TAB_NAME.') + and p.table_name= s.SEGMENT_NAME (+) + and p.partition_name= s.PARTITION_NAME (+) + and p.table_owner = s.owner (+) +order by p.partition_position +/ + + +----------------------- +-- get the last partition of the table +---------------------- + + +ttitle "Last Portions of the table &&OWNER..&&TAB_NAME." SKIP 1 + +select out.TABLE_OWNER + , out.TABLE_NAME + , out.PARTITION_NAME + , out.HIGH_VALUE + from dba_tab_partitions out +where PARTITION_POSITION = (select max(PARTITION_POSITION) + from dba_tab_partitions inner + where out.TABLE_OWNER = inner.TABLE_OWNER + and out.TABLE_NAME = inner.TABLE_NAME) + and out.table_owner like upper('&&OWNER.') + and out.table_name like upper('&&TAB_NAME.') +order by TABLE_OWNER + ,TABLE_NAME +/ + +column partition_position clear +column partition_name clear + +ttitle off + diff --git a/tab_priv.sql b/tab_priv.sql new file mode 100644 index 0000000..d159b35 --- /dev/null +++ b/tab_priv.sql @@ -0,0 +1,38 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: describe a table in the database +-- +-- Parameter 1: Owner of the table +-- Parameter 2: Name of the table +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define OWNER = '&1' +define TAB_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&TAB_NAME. +prompt + +column table_name format a25 heading "Table|name" +column grantee format a25 heading "Granted|to" +column PRIVILEGE format a20 heading "PRIVILEGE" + +ttitle left "Show all rights on this table &OWNER..&TAB_NAME." skip 2 + +select table_name,grantee,PRIVILEGE + from dba_tab_privs + where table_name like upper('&TAB_NAME.') + and owner like upper('&OWNER.') + order by 1,2,3 +/ + + +ttitle off diff --git a/tab_redef.sql b/tab_redef.sql new file mode 100644 index 0000000..1ce0031 --- /dev/null +++ b/tab_redef.sql @@ -0,0 +1,590 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Example for a table redefinition script +--============================================================================== +-- http://www.dba-oracle.com/t_online_table_reorganization.htm +-- http://www.dba-oracle.com/t_dbms_redefinition_example.htm +-- http://docs.oracle.com/cd/E11882_01/appdev.112/e40758/d_redefi.htm#ARPLS67521 +-- http://www.oracle.com/webfolder/technetwork/de/community/dbadmin/tipps/dbms_redefinition/index.html +--============================================================================== + +--------------------------------------- +set verify off +set linesize 130 pagesize 300 +set echo on +set timing on +set time on +set serveroutput on + +--------------------------------------- +-- Parameter +--define USER_NAME ='GPI' +--define TABLE_NAME ='TAB_TEST' +--define ORDER_BY_COL='ID' +--define TABLE_SPACE ='tablespace DATA' +--define SET_PARALLEL=8 + +define USER_NAME ='&1' +define TABLE_NAME ='&2' +define ORDER_BY_COL='&3' +define TABLE_SPACE ='&4' +define SET_PARALLEL=&5 + +spool log_file_&&USER_NAME._&&TABLE_NAME._rebuild.log + +--------------------------------------- +-- set flashback restore point +-- CREATE RESTORE POINT before_redefinition; + + +--------------------------------------- +whenever sqlerror exit 2; + +--------------------------------------- +-- Verify if Table can be redefined + +begin + dbms_redefinition.can_redef_table (uname => '&&USER_NAME' + , tname => '&&TABLE_NAME' + , options_flag => dbms_redefinition.cons_use_pk + , part_name => null); +end; +/ + +--------------------------------------- +-- create interim table +-- adjust individually +-- !!! Attention default values like sysdate are not copied by a create table as select! +-- see : Create Table As Select Does Not Copy Table's Default Values. (Doc ID 579636.1) + +create table &&USER_NAME..&&TABLE_NAME._STAGE &&TABLE_SPACE COMPRESS FOR ALL OPERATIONS as select * from &&USER_NAME..&&TABLE_NAME. where 1=2; + +--------------------------------------- +-- remove not null constraints to avoid this error +-- ORA-01442: column to be modified to NOT NULL is already NOT NULL +-- ORA-06512: at "SYS.DBMS_REDEFINITION", line 984 +-- ORA-06512: at "SYS.DBMS_REDEFINITION", line 1726 + +begin + for i in (select owner + , table_name + , constraint_name + , search_condition + from dba_constraints + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME._STAGE' + and constraint_type = 'C') + loop + if i.search_condition like '%IS NOT NULL%' + then + dbms_output.put_line ( + 'INFO -- remove constraint ::' || i.owner || '.' || i.table_name || ' drop constraint ' || i.constraint_name); + + execute immediate 'alter table ' || i.owner || '.' || i.table_name || ' drop constraint ' || i.constraint_name; + end if; + end loop; +end; +/ + +--------------------------------------- +-- enable parallel in this session +alter session force parallel dml parallel &&SET_PARALLEL.; +alter session force parallel query parallel &&SET_PARALLEL.; + +---------------------------------------- +-- store original commmets due bug +-- Bug 12765293 - ORA-600 [kkzuord_copycolcomcb.2.prepare] may be seen during DBMS_REDEFINITION (Doc ID 12765293.8) +-- +-- remember comments + +create table &&USER_NAME..&&TABLE_NAME._t_c +as + select * + from dba_tab_comments + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME'; + +create table &&USER_NAME..&&TABLE_NAME._c_c +as + select * + from dba_col_comments + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME'; + +-- cut comments +comment on table &&USER_NAME..&&TABLE_NAME. is ''; +------------------------------------ +-- for all columns + +declare + cursor c_comment + is + select column_name, table_name, owner + from dba_col_comments + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME'; +begin + for rec in c_comment + loop + dbms_output.put_line ( + 'INFO -- set COMMENT ON column ' || rec.owner || '.' || rec.table_name || '.' || rec.column_name || ' is ''-'''); + + execute immediate 'COMMENT ON column ' || rec.owner || '.' || rec.table_name || '.' || rec.column_name || ' is ''-'''; + end loop; +end; +/ + + +-------------------------------------- +-- +-- check if comments removed + +column column_name format a20 +column comments format a50 + +select column_name, comments + from dba_col_comments + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME' +/ + +select comments + from dba_tab_comments + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME' +/ + + +--------------------------------------- +-- Start the redefinition process + +begin + dbms_redefinition.START_REDEF_TABLE (uname => '&&USER_NAME' + , orig_table => '&&TABLE_NAME' + , int_table => '&&TABLE_NAME._STAGE' + , col_mapping => null + , options_flag => dbms_redefinition.cons_use_pk + , orderby_cols => '&&ORDER_BY_COL' + , part_name => null); +end; +/ + +----------------------------------- +-- to stop the process use this function +-- +--begin +-- DBMS_REDEFINITION.ABORT_REDEF_TABLE ( +-- uname => '&&USER_NAME' +-- , orig_table => '&&TABLE_NAME' +-- , int_table => '&&TABLE_NAME._STAGE' +-- , part_name => null); +-- end; +--/ + + + +------ Constraints ----------- +-- fix constraint names +-- + +-- declare +-- cursor c_constraints +-- is +-- select orig_tab.constraint_name orig_constraint_name +-- , stage_tab.constraint_name int_constraint_name +-- from (select * from dba_cons_columns where table_name = '&&TABLE_NAME' and owner='&&USER_NAME') orig_tab +-- , (select * from dba_cons_columns where table_name = '&&TABLE_NAME._STAGE' and owner='&&USER_NAME') stage_tab +-- where orig_tab.column_name = stage_tab.column_name; +-- begin +-- for rec in c_constraints +-- loop +-- dbms_output.put_line('INFO -- register constraints on &&USER_NAME..&&TABLE_NAME. '||rec.orig_constraint_name); +-- DBMS_REDEFINITION.REGISTER_DEPENDENT_OBJECT( +-- uname => '&&USER_NAME' +-- , orig_table => '&&TABLE_NAME' +-- , int_table => '&&TABLE_NAME._STAGE' +-- , dep_type => DBMS_REDEFINITION.CONS_CONSTRAINT +-- , dep_owner => '&&USER_NAME' +-- , dep_orig_name => rec.orig_constraint_name +-- , dep_int_name => rec.int_constraint_name +-- ); +-- end loop; +-- end; +-- / + +--------------------------------------- +-- Copy dependent objects +-- constraints copied enabled missing constraints! +-- + +declare + v_error_count pls_integer; +begin + dbms_redefinition.COPY_TABLE_DEPENDENTS (uname => '&&USER_NAME' + , orig_table => '&&TABLE_NAME' + , int_table => '&&TABLE_NAME._STAGE' + -- copy the indexes using the physical parameters of the source indexes + , copy_indexes => dbms_redefinition.cons_orig_params + , copy_triggers => true + , copy_constraints => true + , copy_privileges => true + , ignore_errors => false + , num_errors => v_error_count + , copy_statistics => false + , copy_mvlog => false); + + if v_error_count > 0 + then + raise_application_error (-20100, 'Found ' || v_error_count || ' Errors cloning dependencies'); + end if; +end; +/ + +--------------------------------------- +-- Check for any errors +set long 34000 +column object_name format a32 +column base_table_name format a32 fold_after +column ddl_txt format a100 + +select object_name, base_table_name, ddl_txt from DBA_REDEFINITION_ERRORS +/ + +--------------------------------------- +-- Synchronize the interim table (optional) + +begin + dbms_redefinition.SYNC_INTERIM_TABLE (uname => '&&USER_NAME' + , orig_table => '&&TABLE_NAME' + , int_table => '&&TABLE_NAME._STAGE' + , part_name => null); +end; +/ + + +--------------------------------------- +-- check if all data is synced +--- + +select count (*) entries, '&&TABLE_NAME.' from &&USER_NAME..&&TABLE_NAME. +union all +select count (*) entries, '&&TABLE_NAME._STAGE' from &&USER_NAME..&&TABLE_NAME._stage +/ + + +--------------------------------------- +-- Complete the redefinition +-- and switch table + +begin + dbms_redefinition.SYNC_INTERIM_TABLE (uname => '&&USER_NAME' + , orig_table => '&&TABLE_NAME' + , int_table => '&&TABLE_NAME._STAGE' + , part_name => null); + + dbms_redefinition.FINISH_REDEF_TABLE (uname => '&&USER_NAME' + , orig_table => '&&TABLE_NAME' + , int_table => '&&TABLE_NAME._STAGE' + , part_name => null); +end; +/ + + +---------------------------------------- +-- fix not null constraints +-- fix wrong fk constraints +-- see support node 1089860.1 +-- +-- +alter session set ddl_lock_timeout=10; +-- +---------------------------------------- + +declare + cursor c_enable_const + is + select constraint_name, validated + from dba_constraints + where table_name = '&&TABLE_NAME' + and owner = '&&USER_NAME' + and validated != 'VALIDATED'; + + cursor c_fk_constraint + is + select 'alter table ' || sc.owner || '.' || sc.table_name || ' drop constraint ' || sc.constraint_name || ';' as command + from dba_constraints sc, dba_constraints tc + where sc.r_constraint_name = tc.constraint_name + and sc.owner = '&&USER_NAME' + and tc.table_name like '%STAGE'; + + cursor c_stage_constraint + is + select 'alter table ' || sc.owner || '.' || sc.table_name || ' drop constraint ' || sc.constraint_name || ';' as command + from dba_constraints sc + where sc.owner = '&&USER_NAME' + and sc.table_name like '%STAGE' + order by sc.table_name; +begin + -- re enable + for rec in c_enable_const + loop + -- !!!!!!!!!!!! -- check ---------------!!!!! + -- use NOVALIDATE to spare some time to enable the constraint + dbms_output.put_line ('Info -- call ALTER TABLE &&TABLE_NAME ENABLE NOVALIDATE CONSTRAINT ' || rec.constraint_name); + + begin + execute immediate 'ALTER TABLE &&USER_NAME..&&TABLE_NAME ENABLE NOVALIDATE CONSTRAINT ' || rec.constraint_name; + exception + when others + then + dbms_output.put_line ( + 'Error -- enable constraint ' || rec.constraint_name || ' failed! SQLERRM:' || sqlcode || ' - ' || sqlerrm); + end; + end loop; + + -- constraint on the FK tables + for rec in c_fk_constraint + loop + dbms_output.put_line ('Info -- disabe FK -- call ' || rec.command); + + begin + execute immediate '' || rec.command; + exception + when others + then + dbms_output.put_line ( + 'Error -- enable constraint ' || rec.command || ' failed! SQLERRM:' || sqlcode || ' - ' || sqlerrm); + end; + end loop; + + -- constraint on the stage tables + for rec in c_stage_constraint + loop + dbms_output.put_line ('Info -- disable Constraint -- call ' || rec.command); + + begin + execute immediate '' || rec.command; + exception + when others + then + dbms_output.put_line ( + 'Error -- enable constraint ' || rec.command || ' failed! SQLERRM:' || sqlcode || ' - ' || sqlerrm); + end; + end loop; +end; +/ + +---------------------------------------- + + +---------------------------------------- +-- check that all constraints in the db are enabled +-- + +column owner format a20 +column table_name format a30 +column constraint_name format a30 +column validated format a20 + +select owner + , table_name + , constraint_name + , validated + from dba_constraints + where owner = '&&USER_NAME' + and validated != 'VALIDATED' +/ + + + +---------------------------------------- +-- recreate statistic on the table +-- + +begin + dbms_stats.gather_table_stats (ownname => '&&USER_NAME.' + , tabname => '&&TABLE_NAME.' + , estimate_percent => dbms_stats.auto_sample_size + , method_opt => 'FOR ALL COLUMNS SIZE auto' + , cascade => true + , degree => &&SET_PARALLEL.); +end; +/ + +---------------------------------------- +-- restore original comments due bug +-- Bug 12765293 - ORA-600 [kkzuord_copycolcomcb.2.prepare] may be seen during DBMS_REDEFINITION (Doc ID 12765293.8) +-- + +declare + cursor c_c_comment + is + select column_name + , table_name + , owner + , comments + from &&USER_NAME..&&TABLE_NAME._c_c + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME'; + + cursor c_t_comment + is + select table_name, owner, comments + from &&USER_NAME..&&TABLE_NAME._t_c + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME'; +begin + for rec in c_c_comment + loop + dbms_output.put_line ( + 'INFO -- set COMMENT ON column ' + || rec.owner + || '.' + || rec.table_name + || '.' + || rec.column_name + || ' is ''' + || rec.comments + || ''''); + + execute immediate + 'COMMENT ON column ' + || rec.owner + || '.' + || rec.table_name + || '.' + || rec.column_name + || ' is ''' + || replace (rec.comments, '''', '''''') + || ''''; + end loop; + + for rec in c_t_comment + loop + dbms_output.put_line ( + 'INFO -- set COMMENT ON TABLE ' || rec.owner || '.' || rec.table_name || ' is ''' || rec.comments || ''''); + + execute immediate + 'COMMENT ON TABLE ' || rec.owner || '.' || rec.table_name || ' is ''' || replace (rec.comments, '''', '''''') || ''''; + end loop; +end; +/ + +-------------------------------------- +-- +-- check if comments exits + +column column_name format a20 +column comments format a50 + +select column_name, comments + from dba_col_comments + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME' +/ + +select comments + from dba_tab_comments + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME' +/ + +-- remove the interim table +drop table &&USER_NAME..&&TABLE_NAME._t_c; +drop table &&USER_NAME..&&TABLE_NAME._c_c; + + +---------------------------------------- +-- check index names +-- rename if necessary +-- example TMP$$_ will be added by redef +-- + +declare + cursor c_index + is + select index_name, owner + from dba_indexes + where owner = '&&USER_NAME.' + and table_name = '&&TABLE_NAME.' + and index_name like 'TMP$$_%'; +begin + for rec in c_index + loop + dbms_output.put_line ('INFO -- rename index'); + + execute immediate + 'alter index ' || rec.owner || '.' || rec.index_name || ' rename to ' || replace (rec.index_name, 'TMP$$_', ''); + end loop; +end; +/ + + +--------------------------- +-- check the tablespace of the switched table +column table_name format a32 +column tablespace_name format a20 +column COMPRESSION format a8 +column COMPRESS_FOR format a8 + +select table_name + , tablespace_name + , COMPRESSION + , COMPRESS_FOR + from dba_tables + where owner = '&&USER_NAME.' + and table_name in ('&&TABLE_NAME.', '&&TABLE_NAME._STAGE') +/ + +--------------------------- +-- check for invalid +-- +@invalid + +--------------------------------------- +-- check if all data is synced +--- + +select count (*) entries, '&&TABLE_NAME.' from &&USER_NAME..&&TABLE_NAME. +union all +select count (*) entries, '&&TABLE_NAME._STAGE' from &&USER_NAME..&&TABLE_NAME._stage +/ + +------------------------------------- +--- +--- check for constraints + +select sc.constraint_name as child_constraint + , sc.constraint_type as child_type + , sc.table_name as child_tab + , sc.validated as child_validated + , sc.status as child_status + , tc.constraint_name as fk_constraint + , tc.constraint_type as fk_type + , tc.table_name as fk_table_name + , tc.validated as fk_validated + , tc.status as fk_status + from dba_constraints sc, dba_constraints tc + where sc.r_constraint_name = tc.constraint_name + and sc.owner = '&&USER_NAME.' + and tc.table_name = '&&TABLE_NAME._STAGE' +/ + +prompt .... not constraint should point to this tables! + + + +--------------------------------------- +-- if table is switched to +-- Drop the interim table +--drop table &&USER_NAME..&&TABLE_NAME._STAGE purge +--/ + +--------------------------------------- +-- set flashback restore point +-- drop RESTORE POINT before_redefinition; +--------------------------------------- + + + +spool off \ No newline at end of file diff --git a/tab_space.sql b/tab_space.sql new file mode 100644 index 0000000..ce7dfdc --- /dev/null +++ b/tab_space.sql @@ -0,0 +1,371 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script to check the size of a table +-- Doku: http://www.pipperr.de/dokuwiki/doku.php?id=dba:sql_groesse_tabelle +-- Date: 08.2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define lnum = "format 9G999G999D99" +define num = "format 99G999" +define snum = "format 9G999" + + +define ENTER_OWNER='&1' +define ENTER_TABLE='&2' + + +prompt +prompt Parameter 1 = User Name => &&ENTER_OWNER. +prompt Parameter 2 = Table Name => &&ENTER_TABLE. +prompt + + +ttitle left "Check if the table is a IOT Table" skip 2 +column COMPRESSION FOLD_BEFORE + +select 'This table is '||decode(nvl(IOT_TYPE,'-'),'IOT','Index-organized','Heap-organized') as TABLE_TYPE + , 'This table compression is '|| COMPRESSION || decode(COMPRESSION,'DISABLED','!',' Type is '||COMPRESS_FOR) as COMPRESSION + from dba_tables + where upper(table_name) like upper('&ENTER_TABLE.') + and upper(owner) = upper('&ENTER_OWNER.') +/ + + +ttitle left "Space Usage of the table &ENTER_OWNER..&ENTER_TABLE." skip 2 + + +column segment_name format A20 +column owner format A10 +column Size_MB &&lnum +column count_blk format 999G999G999 +column count_ext &&lnum +column count_part &&snum +column tablespace_name format a20 heading "Tablespace Name" + +select segment_name + ,owner + ,round(sum(bytes) / 1024 / 1024, 3) as Size_MB + ,sum(blocks) as count_blk + ,sum(EXTENTS) as count_ext + ,count(*) as count_part + ,tablespace_name + from dba_segments + where upper(segment_name) like upper('&ENTER_TABLE.') + and upper(owner) = upper('&ENTER_OWNER.') + group by segment_name + ,owner + ,tablespace_name +/ + + +-- to slow .... +--ttitle left "Extend Map of this table" skip 2 +-- +--declare +-- +-- TYPE tt_blocks IS TABLE OF number INDEX BY BINARY_INTEGER; +-- +-- cursor c_tab_files is +-- select file_id +-- ,TABLESPACE_NAME +-- from DBA_EXTENTS +-- where upper(segment_name) like upper('&ENTER_TABLE.') +-- and upper(owner) = upper('&ENTER_OWNER.') +-- group by file_id +-- ,TABLESPACE_NAME +-- order by file_id; +-- +-- cursor c_extend_map(p_file_id DBA_EXTENTS.file_id%type) is +-- select block_id +-- ,blocks +-- ,bytes as Sizeb +-- ,file_id +-- from DBA_EXTENTS +-- where upper(segment_name) like upper('&ENTER_TABLE.') +-- and upper(owner) = upper('&ENTER_OWNER.') +-- and file_id = p_file_id +-- order by file_id +-- ,block_id; +-- +-- v_start_block_id DBA_EXTENTS.block_id%type := 0; +-- v_end_block_id DBA_EXTENTS.block_id%type := 0; +-- v_last_block_id DBA_EXTENTS.block_id%type := 0; +-- +-- v_last_blocks DBA_EXTENTS.blocks%type := 0; +-- v_size number; +-- p_printout boolean := true; +-- v_max_blocks DBA_EXTENTS.block_id%type := 0; +-- v_datafile dba_data_files.FILE_NAME%type; +-- +-- v_block_factor pls_integer; +-- v_block_exists pls_integer; +-- +-- i pls_integer:=1; +-- t_blocks tt_blocks; +-- +--begin +-- dbms_output.put_line('Info -- ======= Table Extend Map for table &ENTER_TABLE. - &ENTER_OWNER. ======='); +-- for trec in c_tab_files +-- loop +-- dbms_output.put_line('Info -- Analyse file with id :: ' || trec.file_id || ' tablespace :: ' || +-- trec.tablespace_name); +-- dbms_output.put_line('Info --'); +-- for rec in c_extend_map(p_file_id => trec.file_id) +-- loop +-- if (rec.block_id > (v_last_block_id + v_last_blocks)) then +-- +-- if (v_start_block_id != 0) then +-- dbms_output.put_line('Info -- Start : ' || to_char(v_start_block_id, '999G999G999') || ' -- End : ' || +-- to_char(v_end_block_id + v_last_blocks, '999G999G999') || ' Block -- Size used MB -->' || +-- to_char(v_size / 1024 / 1024, '999G990D999')); +-- t_blocks(i):=v_start_block_id; +-- i:=i+1; +-- +-- end if; +-- +-- v_start_block_id := rec.block_id; +-- v_size := rec.Sizeb; +-- else +-- v_size := v_size + rec.Sizeb; +-- v_end_block_id := rec.block_id; +-- end if; +-- v_last_block_id := rec.block_id; +-- v_last_blocks := rec.blocks; +-- end loop; +-- if p_printout then +-- dbms_output.put_line('Info -- Start : ' || to_char(v_start_block_id, '999G999G999') || ' -- End : ' || +-- to_char(v_start_block_id + v_last_blocks, '999G999G999') || ' Block -- Size used MB -->' || +-- to_char(v_size / 1024 / 1024, '999G990D999')); +-- t_blocks(i):=v_start_block_id; +-- i:=i+1; +-- end if; +-- select max(block_id) into v_max_blocks from DBA_EXTENTS where file_id = trec.file_id; +-- select FILE_NAME into v_datafile from dba_data_files where FILE_ID = trec.file_id; +-- dbms_output.put_line('Info --'); +-- dbms_output.put_line('Info -- last use extend block :: ' || to_char(v_max_blocks) || ' in this datafile :: ' || +-- v_datafile); +-- dbms_output.put_line('Info --'); +-- end loop; +-- +-- for trec in c_tab_files +-- loop +-- +-- select max(block_id) into v_max_blocks from DBA_EXTENTS where file_id = trec.file_id; +-- +-- +-- if v_max_blocks > 500000 then +-- v_block_factor := 10000; +-- elsif v_max_blocks > 100000 then +-- v_block_factor := 10000; +-- else +-- v_block_factor := 1000; +-- end if; +-- +-- dbms_output.put('Info -- '); +-- dbms_output.put_line('Info -- draw map for :: ' || trec.file_id || ' tablespace :: ' || trec.tablespace_name); +-- dbms_output.put_line('Info -- Each star represent '||v_block_factor||' Blocks'); +-- dbms_output.put('Info -- '); +-- +-- for i in 1 .. v_max_blocks +-- loop +-- -- all 1000 Block draw a # +-- if mod(i, v_block_factor) = 0 then +-- +-- -- check with the remember values +-- -- faster! +-- --select count(*) +-- -- into v_block_exists +-- -- from DBA_EXTENTS +-- -- where upper(segment_name) like upper('&ENTER_TABLE.') +-- --- and upper(owner) = upper('&ENTER_OWNER.') +-- -- and file_id = trec.file_id +-- -- and block_id between (i) and i+v_block_factor; +-- +-- FOR j IN 1 .. t_blocks.COUNT LOOP +-- if t_blocks(j) between (i) and i+v_block_factor then +-- v_block_exists:=100; +-- end if; +-- END LOOP; +-- +-- if v_block_exists > 0 then +-- dbms_output.put('+'); +-- else +-- dbms_output.put('#'); +-- end if; +-- +-- v_block_exists:=0; +-- end if; +-- if mod(i, (v_block_factor * 100)) = 0 then +-- dbms_output.put_line(''); +-- dbms_output.put('Info -- '); +-- end if; +-- end loop; +-- dbms_output.put_line(''); +-- dbms_output.put_line('Info --'); +-- end loop; +-- +-- dbms_output.put_line('Info -- ======= Finish ======='); +--end; +--/ + + + +/* +Parameter Description +----------------------------------------------------------------------- +segment_owner Schema name of the segment to be analyzed +segment_name Name of the segment to be analyzed +partition_name Partition name of the segment to be analyzed +segment_type Type of the segment to be analyzed (TABLE, INDEX, or CLUSTER) +unformatted_blocks Total number of blocks that are unformatted +unformatted bytes Total number of bytes that are unformatted +fs1_blocks Number of blocks that has at least 0 to 25% free space +fs1_bytes Number of bytes that has at least 0 to 25% free space +fs2_blocks Number of blocks that has at least 25 to 50% free space +fs2_bytes Number of bytes that has at least 25 to 50% free space +fs3_blocks Number of blocks that has at least 50 to 75% free space +fs3_bytes Number of bytes that has at least 50 to 75% free space +fs4_blocks Number of blocks that has at least 75 to 100% free space +fs4_bytes Number of bytes that has at least 75 to 100% free space +ful1_blocks Total number of blocks that are full in the segment +full_bytes Total number of bytes that are full in the segment + + +---------------------------- + +total_blocks Returns total number of blocks in the segment. +total_bytes Returns total number of blocks in the segment, in bytes. +unused_blocks Returns number of blocks which are not used. +unused_bytes Returns, in bytes, number of blocks which are not used. +last_used_extent_ file_id Returns the file ID of the last extent which contains data. +last_used_extent_ block_id Returns the starting block ID of the last extent which contains data. +last_used_block Returns the last block within this extent which contains data. + +*/ + +set serveroutput on + +declare + unf number; + unfb number; + fs1 number; + fs1b number; + fs2 number; + fs2b number; + fs3 number; + fs3b number; + fs4 number; + fs4b number; + full number; + fullb number; + + total_blocks number; + total_bytes number; + unused_blocks number; + unused_bytes number; + lastextf number; + last_extb number; + lastusedblock number; + + v_file_name dba_data_files.file_name%type; + v_tablespace_name dba_segments.TABLESPACE_NAME%type; + v_segment_management dba_tablespaces.SEGMENT_SPACE_MANAGEMENT%type; + + cursor c_seg is + select segment_name + , owner + , SEGMENT_TYPE + , PARTITION_NAME + from dba_segments + where upper(segment_name) like upper('&ENTER_TABLE.') and upper(owner)=upper('&ENTER_OWNER.'); + +begin + + for rec in c_seg + loop + + begin + dbms_output.put_line('Info -- Call dbms_space.space_usage for table ( Type:'|| rec.segment_type||' ) ::'||rec.segment_name ||' Partition::'||rec.PARTITION_NAME); + + dbms_output.put_line('Info ------------------------------------------------------------------'); + + dbms_space.space_usage( + segment_owner => rec.owner + ,segment_name => rec.segment_name + ,segment_type => rec.segment_type + ,unformatted_blocks => unf + ,unformatted_bytes => unfb + ,fs1_blocks => fs1 + ,fs1_bytes => fs1b + ,fs2_blocks => fs2 + ,fs2_bytes => fs2b + ,fs3_blocks => fs3 + ,fs3_bytes => fs3b + ,fs4_blocks => fs4 + ,fs4_bytes => fs4b + ,full_blocks => full + ,full_bytes => fullb + ,partition_name => rec.PARTITION_NAME); + + dbms_output.put_line('Info -- Total Count of blocks that are unformatted : '||unf ||' |Bytes : '||unfb); + dbms_output.put_line('Info -- Total Count of blocks that are full in the segment : '||full||' |Bytes : '||fullb); + + dbms_output.put_line('Info -- '); + + dbms_output.put_line('Info -- Count of blocks that has at least 0 to 25% free space : '||fs1||' |Bytes : '||fs1b); + dbms_output.put_line('Info -- Count of blocks that has at least 25 to 50% free space : '||fs2||' |Bytes : '||fs2b); + dbms_output.put_line('Info -- Count of blocks that has at least 50 to 75% free space : '||fs3||' |Bytes : '||fs3b); + dbms_output.put_line('Info -- Count of blocks that has at least 75 to 100% free space : '||fs4||' |Bytes : '||fs4b); + + dbms_output.put_line('Info ------------------------------------------------------------------'); + exception + when others then + dbms_output.put_line('Error --'); + dbms_output.put_line('Error -- '||SQLERRM); + dbms_output.put_line('Error -- +This procedure can be used only on segments in tablespaces with AUTO SEGMENT SPACE MANAGEMENT'); + dbms_output.put_line('Error -- +Action: Check the segment name and type and re-issue the statement'); + select distinct s.TABLESPACE_NAME , t.SEGMENT_SPACE_MANAGEMENT into v_tablespace_name , v_segment_management + from dba_segments s , dba_tablespaces t + where upper(s.segment_name) like upper('&ENTER_TABLE.') + and upper(s.owner)=upper('&ENTER_OWNER.') + and s.TABLESPACE_NAME=t.TABLESPACE_NAME; + + dbms_output.put_line('Error -- +Tablespace for the table &ENTER_TABLE.:: '||v_tablespace_name ||' - Segment Management for this tablespace:: '||v_segment_management); + dbms_output.put_line('Error --'); + end; + + begin + dbms_output.put_line('Info -- Call dbms_space.UNUSED_SPACE for table ( Type:'|| rec.segment_type||' ) ::'||rec.segment_name); + + dbms_space.UNUSED_SPACE(rec.owner,rec.segment_name,rec.segment_type, total_blocks, total_bytes, unused_blocks, unused_bytes, lastextf, last_extb, lastusedblock,rec.PARTITION_NAME); + + dbms_output.put_line('Info ------------------------------------------------------------------'); + dbms_output.put_line('Info -- Used total_blocks :'|| total_blocks); + dbms_output.put_line('Info -- Used total_bytes :'|| total_bytes ); + dbms_output.put_line('Info -- Unused block :'|| unused_blocks ); + dbms_output.put_line('Info -- Unused byte :'|| unused_bytes ); + dbms_output.put_line('Info -- File ID of the last extent with data :'|| lastextf ); + + select file_name into v_file_name from dba_data_files where FILE_ID=lastextf; + + dbms_output.put_line('Info -- File Name last extent with data :'|| v_file_name ); + + dbms_output.put_line('Info -- Starting block ID of the last extent :'|| last_extb ); + dbms_output.put_line('Info -- Last block within this extent :'|| lastusedblock ); + dbms_output.put_line('Info ------------------------------------------------------------------'); + + exception + when others then + dbms_output.put_line('Error ---'||SQLERRM); + end; + + end loop; + +end; +/ + +ttitle off + diff --git a/tab_stat.sql b/tab_stat.sql new file mode 100644 index 0000000..c610726 --- /dev/null +++ b/tab_stat.sql @@ -0,0 +1,175 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Get the statistic settings of the table +-- Parameter 1: Name of the table +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 +define TABLE_NAME = &2 + +prompt +prompt Parameter 1 = Owner Name => &&USER_NAME. +prompt Parameter 2 = Tab Name => &&TABLE_NAME. +prompt + +create or replace function show_rawvalue (p_rawval raw, p_dtype varchar2) + return varchar2 +is + -- different datatypes + v_cn number; + v_cv varchar2 (32); + v_cd date; + v_cnv nvarchar2 (32); + v_cr rowid; + v_cc char (32); + v_cbf binary_float; + v_cbd binary_double; + -- return value + v_return varchar2 (4000); +begin + case p_dtype + when 'VARCHAR2' + then + dbms_stats.convert_raw_value (p_rawval, v_cv); + v_return := to_char (v_cv); + when 'DATE' + then + dbms_stats.convert_raw_value (p_rawval, v_cd); + v_return := to_char (v_cd, 'DD.MM.YYYY HH24:MI:SS'); + when 'NUMBER' + then + dbms_stats.convert_raw_value (p_rawval, v_cn); + v_return := to_char (v_cn); + when 'BINARY_FLOAT' + then + dbms_stats.convert_raw_value (p_rawval, v_cbf); + v_return := to_char (v_cbf); + when 'BINARY_DOUBLE' + then + dbms_stats.convert_raw_value (p_rawval, v_cbd); + v_return := to_char (v_cbd); + when 'NVARCHAR2' + then + dbms_stats.convert_raw_value_nvarchar (p_rawval, v_cnv); + v_return := to_char (v_cnv); + when 'ROWID' + then + dbms_stats.convert_raw_value_rowid (p_rawval, v_cr); + v_return := to_char (v_cr); + when 'CHAR' + then + dbms_stats.convert_raw_value (p_rawval, v_cc); + v_return := to_char (v_cc); + else + v_return := 'UNKNOWN DATATYPE'; + end case; + + return v_return; +end; +/ + + +set linesize 150 pagesize 200 + +ttitle "Read Statistic Values for this table &TABLE_NAME." skip 2 + +column table_name format a15 +column PARTITION_NAME format a20 +colum locked format a5 heading "Stat|Lock" + + select t.table_name + , ts.PARTITION_NAME + , t.status + , to_char (ts.LAST_ANALYZED, 'dd.mm.yyyy hh24:mi') as LAST_ANALYZED + , ts.NUM_ROWS + , ts.AVG_SPACE + , ts.CHAIN_CNT + , ts.AVG_ROW_LEN + , ts.stattype_locked as locked + from dba_tables t, dba_tab_statistics ts + where ts.table_name = t.table_name + and ts.owner = t.owner + and t.table_name like '&TABLE_NAME.' + and t.owner like '&USER_NAME.' +order by ts.PARTITION_NAME +/ + +prompt ... to anaylse the space Usage use tab.sql +prompt ... to refresh statistic use EXEC DBMS_STATS.GATHER_TABLE_STATS ('&USER_NAME.', '&TABLE_NAME.'); + +ttitle center "Read Statistic Values of the columns of this table " skip 2 + + +column column_name format a18 +column low_value format a35 +column high_value format a35 +column data_type format a10 +column histogram format a15 + +set serveroutput on + + select b.table_name + , b.column_name + , show_rawvalue (a.low_value, b.data_type) as low_value + , show_rawvalue (a.high_value, b.data_type) as high_value + , b.data_type + , a.histogram + from dba_tab_col_statistics a, dba_tab_cols b + where b.table_name like '&TABLE_NAME.' + and b.owner like '&USER_NAME.' + and a.table_name(+) = b.table_name + and a.owner(+) = b.owner + and a.column_name(+) = b.column_name +order by 1, 2 +/ + +ttitle left "Overview histogram statistic usage for this table" skip 2 + + select table_name, column_name, count (*) as count_hist_buckets + from DBA_TAB_HISTOGRAMS + where table_name like '&TABLE_NAME.' + and owner like '&USER_NAME.' +group by table_name, column_name +order by column_name +/ + + +ttitle left "Overview of the last 10 statistics on this table" skip 2 + + select h.TABLE_NAME, h.PARTITION_NAME, to_char (h.STATS_UPDATE_TIME, 'dd.mm.yyyy hh24:mi') as STATS_UPDATE_TIME + from dba_tab_stats_history h + where h.table_name like upper ('&TABLE_NAME.') + and h.owner like upper ('&USER_NAME.') + and rownum < 10 +order by STATS_UPDATE_TIME +/ + +-- Details Analyse +-- column endpoint_number format 99999 heading "End|Nr." +-- column endpoint_value heading "Value" +-- column endpoint_actual_value format a30 heading "Act|Value" +-- +-- +-- select table_name +-- , column_name +-- , endpoint_number +-- , endpoint_value +-- , endpoint_actual_value +-- from DBA_TAB_HISTOGRAMS +-- where table_name like '&TABLE_NAME.%' +-- and owner like '&USER_NAME.%' +-- order by column_name,ENDPOINT_NUMBER +-- / + + + +ttitle off + +drop function show_rawvalue +/ \ No newline at end of file diff --git a/tab_stat_overview.sql b/tab_stat_overview.sql new file mode 100644 index 0000000..7319607 --- /dev/null +++ b/tab_stat_overview.sql @@ -0,0 +1,53 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Get the statistic settings of all tables of a user +-- Parameter 1: Name of the table +-- +-- Must be run with dba privileges +-- +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +prompt +prompt Parameter 1 = Owner Name => &&USER_NAME. +prompt + +SET linesize 150 pagesize 2000 + +ttitle "Read Statistic Values for all tables of this user &USER_NAME." SKIP 2 + +column table_name format a32 + +select table_name + , status + , to_char(LAST_ANALYZED,'dd.mm.yyyy hh24:mi') as LAST_ANALYZED + , NUM_ROWS + , AVG_SPACE + , CHAIN_CNT + , AVG_ROW_LEN + from dba_tables +where owner like '&USER_NAME.' +order by nvl(NUM_ROWS,1) asc +/ + +prompt ... to anaylse the space Usage use tab.sql +prompt ... to refresh statistic use EXEC DBMS_STATS.GATHER_TABLE_STATS ('&USER_NAME.', 'TABLE_NAME'); + +ttitle "Read Statistic Values for all tables of this user &USER_NAME." SKIP 2 + +column col_group format a30 + +select e.extension col_group + , t.num_distinct + , t.histogram + from dba_stat_extensions e + , dba_tab_col_statistics t +where e.extension_name=t.column_name + and t.owner like '&USER_NAME.' +/ + +ttitle off diff --git a/tab_tablespace.sql b/tab_tablespace.sql new file mode 100644 index 0000000..f7b2cff --- /dev/null +++ b/tab_tablespace.sql @@ -0,0 +1,31 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the tablespaces of the user - parameter - Owner +-- Date: November 2013 +-- +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = '&1' + +prompt +prompt Parameter 1 = User Name => &&USER_NAME. +prompt + +BREAK ON tablespace_name + +column tablespace_name format a32 heading "Tablespace Name" +column segment_type format a20 heading "Segment Type" +column count_ format 99999 heading "Count" + +select tablespace_name + , segment_type + , '::' as "|" + , count(*) as count_ + from dba_segments +where owner like upper('&&USER_NAME') +group by tablespace_name,segment_type +order by tablespace_name,segment_type +/ diff --git a/tab_tablespace_all.sql b/tab_tablespace_all.sql new file mode 100644 index 0000000..77d408e --- /dev/null +++ b/tab_tablespace_all.sql @@ -0,0 +1,25 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the tablespaces of all the users +-- Date: November 2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +column tablespace_name format a20 heading "Tablespace|Name" +column segment_type format a20 heading "Segment|Type" +column count_ format 99999 heading "Count|Objects" +column space_usage format 999G999G999D99 heading "Space|Usage" + +BREAK ON owner + +select owner + , tablespace_name + , segment_type + , '::' as "|" + , count(*) as count_ + , round(sum(bytes)/1024/1024,2) as space_usage + from dba_segments +group by tablespace_name,segment_type,owner +order by owner,tablespace_name,segment_type +/ diff --git a/tab_umlaut.sql b/tab_umlaut.sql new file mode 100644 index 0000000..7cde1e6 --- /dev/null +++ b/tab_umlaut.sql @@ -0,0 +1,61 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get List of Tables with Umlauts +-- Date: 01.September 2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + + +column owner format a14 heading "Owner" +column table_name format a30 heading "Table|name" +column column_name format a30 heading "Column|name" + +ttitle left "Table and View Names with strange signs like umlauts" skip 2 + +select t.owner + , t.view_name + from dba_views t +where regexp_instr(upper( + replace ( + replace( + replace( + replace(t.view_name,'+','') + ,' ','') + ,'/','') + ,'#','') + ),'[^QWERTZUIOPASDFGHJKLYXCVBNM1234567890$_-]') > 0 +union -- may be duplicates , fix +select t.owner + , t.table_name + from dba_tables t +where regexp_instr(upper( + replace ( + replace( + replace( + replace(t.table_name,'+','') + ,' ','') + ,'/','') + ,'#','') + ),'[^QWERTZUIOPASDFGHJKLYXCVBNM1234567890$_-]') > 0 +order by 1,2 +/ + + +ttitle left "Table and View Columns with strange signs like umlauts" skip 2 + +select t.owner + , t.table_name + , t.column_name + from dba_tab_columns t +where regexp_instr(upper( + replace ( replace( + replace( + replace(t.column_name,'+','') + ,' ','') + ,'/','') + ,'#','') + ) + ,'[^QWERTZUIOPASDFGHJKLYXCVBNM1234567890$_-]') > 0 +order by 1,2,3 +/ diff --git a/tab_usage.sql b/tab_usage.sql new file mode 100644 index 0000000..fda6395 --- /dev/null +++ b/tab_usage.sql @@ -0,0 +1,61 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: check if the table is used in the last time - parameter - Owner, Table name +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 +define TABLE_NAME = &2 + +prompt +prompt Parameter 1 = Owner Name => &&USER_NAME. +prompt Parameter 2 = Tab Name => &&TABLE_NAME. +prompt + +ttitle center "Check if a column of the Table was in use in SQL Queries" SKIP 2 + +column owner format a14 +column object_name format a24 +column column_name format a18 + +column equality_preds format 99G999 heading "equ" +column equijoin_preds format 99G999 heading "Jequ" +column nonequijoin_preds format 99G999 heading "Jnoe" +column range_preds format 99G999 heading "ran" +column like_preds format 99G999 heading "lik" +column null_preds format 99G999 heading "nul" +column last_collect format a18 heading "last Usage |collected" + + +select o.owner + , o.object_name + , c.name as column_name + , u.equality_preds + , u.range_preds + , u.like_preds + , u.null_preds + , u.equijoin_preds + , u.nonequijoin_preds + , to_char(u.TIMESTAMP,'dd.mm.yyyy hh24:mi') as last_collect + from sys.col_usage$ u + , dba_objects o + , sys.col$ c + where u.obj# = o.OBJECT_ID + and u.obj# = c.obj# + and u.intcol# = c.col# + and upper(o.owner) like upper('&&USER_NAME.') + and upper(o.object_name) like upper('&&TABLE_NAME.') + order by o.owner + ,o.object_name + ,c.name +/ + +ttitle off + +ttitle center "Check if in the SQL cache" SKIP 2 + +@sql_find &&TABLE_NAME. + +ttitle off + diff --git a/tablespace.sql b/tablespace.sql new file mode 100644 index 0000000..dbe8d81 --- /dev/null +++ b/tablespace.sql @@ -0,0 +1,104 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Information about the tablespaces +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +-- use the default block size as variable +-- + +col BLOCK_SIZE_COL new_val BLOCK_SIZE + +column BLOCK_SIZE_COL format a20 heading "Default DB Blocksize" + +ttitle "Default DB Blocksize" SKIP 2 + +select value as BLOCK_SIZE_COL + from v$parameter + where name = 'db_block_size' + / + +column tablespace_name format a25 heading "Tablespace|Name" +column used_space_gb format 999G990D999 heading "Used Space|GB" +column gb_free format 999G990D999 heading "Free Space|GB" +column tablespace_size_gb format 999G990D999 heading "Max Tablespace|Size GB" +column DF_SIZE_GB format 999G990D999 heading "Size on| Disk GB" +column used_percent format 90G99 heading "Used |% Max" +column pct_used_size format 90G99 heading "Used |% Disk" +column BLOCK_SIZE format 99G999 heading "TBS BL|Size" +column DF_Count format 9G999 heading "Count|DB Files" + + +ttitle "Used Space over DBA_TABLESPACE_USAGE_METRICS" SKIP 2 + +select dt.tablespace_name + , round((dm.tablespace_size * dt.BLOCK_SIZE)/1024/1024/1024,3) as tablespace_size_gb + , round( + (case dt.CONTENTS + when 'TEMPORARY' then + (select sum(df.BLOCKS)*dt.BLOCK_SIZE from dba_temp_files df where df.TABLESPACE_NAME=dt.tablespace_name) + else + (select sum(df.BLOCKS)*dt.BLOCK_SIZE from dba_data_files df where df.TABLESPACE_NAME=dt.tablespace_name) + end) /1024/1024/1024,3) as DF_SIZE_GB + , (case dt.CONTENTS + when 'TEMPORARY' then + (select count(*) from dba_temp_files df where df.TABLESPACE_NAME=dt.tablespace_name) + else + (select count(*) from dba_data_files df where df.TABLESPACE_NAME=dt.tablespace_name) + end) as DF_Count + , round(((dm.used_space * dt.BLOCK_SIZE)/1024/1024/1024),3) as used_space_gb + , round(100*dm.used_percent,2) as used_percent + , dt.BLOCK_SIZE + from DBA_TABLESPACE_USAGE_METRICS dm + , dba_tablespaces dt +where dm.tablespace_name=dt.tablespace_name +order by dm.tablespace_name +/ + + +ttitle "Used Space over dba_data_files and dba_free_space" SKIP 2 + +select df.tablespace_name + , df.gb_max as tablespace_size_gb + , df.gb_size as DF_SIZE_GB + , fs.gb_free + , (df.gb_size - fs.gb_free) as used_space_gb + , (case gb_max when 0 then 0 else (round((100/df.gb_max*(df.gb_size - fs.gb_free)),3)*100) end) as used_percent + , round((100/df.gb_size*(df.gb_size - fs.gb_free)),3)*100 as pct_used_size + , dt.BLOCK_SIZE +from (select tablespace_name + , round(sum(bytes/1024/1024/1024),3) as gb_size + ,round(sum(MAXBYTES/1024/1024/1024),3) as gb_max + from dba_data_files + group by tablespace_name) df, + (select tablespace_name + , round(sum(bytes/1024/1024/1024),3) as gb_free + from dba_free_space group by tablespace_name) fs + , dba_tablespaces dt +where df.tablespace_name = fs.tablespace_name + and dt.tablespace_name = fs.tablespace_name +order by df.tablespace_name +/ + + + +ttitle "Get max free extend from the tablespace" SKIP 2 + +column max_extend_free_mb format 999G990D999 heading "Max Free Space Extend|MB" +column max_blocks format 999G990 heading "Max Free Space Extend|Blocks" + +SELECT round(max(fs.bytes)/1024/1024,3) as max_extend_free_mb + , max(fs.bytes)/dt.BLOCK_SIZE as max_blocks + , fs.tablespace_name + , dt.EXTENT_MANAGEMENT + , dt.ALLOCATION_TYPE + from dba_free_space fs + , dba_tablespaces dt +where fs.tablespace_name=dt.tablespace_name +group by fs.tablespace_name,dt.BLOCK_SIZE,dt.ALLOCATION_TYPE,dt.EXTENT_MANAGEMENT +order by fs.tablespace_name +/ + +ttitle off + diff --git a/tablespace_autoextend.sql b/tablespace_autoextend.sql new file mode 100644 index 0000000..40f3b4e --- /dev/null +++ b/tablespace_autoextend.sql @@ -0,0 +1,29 @@ + --============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: SQL Script to set all datafiles of a tablespae to autoexend unlimited +-- Date: 04.2016 +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + + +define TABLESPACE = "&1" + +prompt +prompt Parameter 1 = Tablespace Name => '&TABLESPACE' +prompt + +ttitle left "Create the DDL to set all Files of the tablespace :: &&TABLESPACE" skip 2 + + +select 'alter database datafile '''|| file_name||''' autoextend on maxsize unlimited;' + from dba_data_files dbf + , dba_tablespaces et +where dbf.TABLESPACE_NAME = et.TABLESPACE_NAME + and et.TABLESPACE_NAME=upper('&&TABLESPACE') +/ + + +ttitle off + \ No newline at end of file diff --git a/tablespace_create.sql b/tablespace_create.sql new file mode 100644 index 0000000..9722a20 --- /dev/null +++ b/tablespace_create.sql @@ -0,0 +1,30 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the ddl example for a new tablespace +-- Parameter name of the tablespace +-- Path of the datafiles +--============================================================================== +set verify off +set linesize 130 pagesize 4000 + +define TABLESPACE_NAME = '&1' +define DATA_FILE_PATH = '&2' + +prompt +prompt Parameter 1 = Tablespace Name => &&TABLESPACE_NAME. +prompt Parameter 1 = Data File Path => &&DATA_FILE_PATH. +prompt +prompt Example DDL to create a tablespace +prompt +prompt CREATE TABLESPACE &&TABLESPACE_NAME. DATAFILE +prompt '&&DATA_FILE_PATH.&&TABLESPACE_NAME.01.DBF' SIZE 100M AUTOEXTEND ON NEXT 10M MAXSIZE 32000M +prompt ,'&&DATA_FILE_PATH.&&TABLESPACE_NAME.02.DBF' SIZE 100M AUTOEXTEND ON NEXT 10M MAXSIZE 32000M +prompt LOGGING +prompt ONLINE +prompt PERMANENT +--prompt BLOCKSIZE 8192 +prompt EXTENT MANAGEMENT LOCAL UNIFORM SIZE 10M +prompt DEFAULT NOCOMPRESS +prompt SEGMENT SPACE MANAGEMENT AUTO +prompt +prompt \ No newline at end of file diff --git a/tablespace_ddl.sql b/tablespace_ddl.sql new file mode 100644 index 0000000..ecda056 --- /dev/null +++ b/tablespace_ddl.sql @@ -0,0 +1,32 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the ddl of a tablespace, show default storage options! +-- Parameter name of the tablespace +--============================================================================== +set verify off +set linesize 130 pagesize 4000 + +define TABLESPACE_NAME = '&1' + +prompt +prompt Parameter 1 = Tablespace Name => &&TABLESPACE_NAME. +prompt + +set long 1000000; + +column tab_ddl format a100 heading "Tablespace DDL" WORD_WRAPPED + +select dbms_metadata.get_ddl('TABLESPACE','&&TABLESPACE_NAME.') as tab_ddl + from dual +/ + +-- fix it to plsql block to use parameter +-- set the transformation attributes +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true ); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true ); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'OID', false); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SEGMENT_ATTRIBUTES', false); +-- dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'TABLESPACE', true ); + + \ No newline at end of file diff --git a/tablespace_last_objects.sql b/tablespace_last_objects.sql new file mode 100644 index 0000000..528e280 --- /dev/null +++ b/tablespace_last_objects.sql @@ -0,0 +1,61 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Get the last 5 Objects in a tablespace +-- Date: Januar 2015 +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define TABLESPACE_NAME = '&1' + +prompt +prompt Parameter 1 = Tablespace Name => &&TABLESPACE_NAME. +prompt + +ttitle left "The last 5 Objects inside the tablespace" skip 2 + +column owner format a15 heading "Owner" +column segment_name format a25 heading "Segment|name" +column partition_name format a20 heading "Partition|name" +column segment_type format a10 heading "Segment|type" +column file_id format 99 heading "File|id" +column block_id format 9999999 heading "Block|id" + +prompt -- get the last Object in this tablespace + +select e.owner + ,e.segment_name + ,nvl(e.partition_name,'n/a') as partition_name + ,e.segment_type + ,e.block_id + ,e.file_id + from dba_extents e +where tablespace_name like upper('&TABLESPACE_NAME.') + and (file_id,block_id) in (select file_id,block_id + from ( + select file_id + , block_id + , rank() over (order by block_id desc) as row_rank + from dba_extents + where tablespace_name like upper('&TABLESPACE_NAME.') + group by file_id,block_id + ) + where row_rank between 1 and 5 ) +order by block_id desc +/ + +prompt .... +prompt .... to move LOG Segments move the column of the tablespace +prompt .... ALTER TABLE owner.table_name MOVE LOB (column_name) STORE AS (tablespace_name) + +prompt .... to move Tables +prompt .... ALTER TABLE owner.table_name MOVE PARTITION xxxxxx ONLINE TABLESPACE xxxxx UPDATE INDEXES + +prompt .... to move INDEXES +prompt .... alter index owner.index_name rebuild +prompt .... + + + +ttitle off diff --git a/tablespace_set_size.sql b/tablespace_set_size.sql new file mode 100644 index 0000000..16ff4fc --- /dev/null +++ b/tablespace_set_size.sql @@ -0,0 +1,32 @@ + --============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: Create SQL Script to set all datafiles of a tablespae to defined size +-- Date: 04.2016 +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + + +define TABLESPACE = "&1" + +define SIZE_MB = "&2" + +prompt +prompt Parameter 1 = Tablespace Name => '&TABLESPACE' +prompt Parameter 2 = New Size => '&SIZE_MB' +prompt + +ttitle left "Create the DDL to set all Files of the tablespace :: &&TABLESPACE" skip 2 + + +select 'alter database datafile '''|| file_name||''' resize &&SIZE_MB.M;' + from dba_data_files dbf + , dba_tablespaces et +where dbf.TABLESPACE_NAME = et.TABLESPACE_NAME + and et.TABLESPACE_NAME in upper('&&TABLESPACE.') +/ + + +ttitle off + \ No newline at end of file diff --git a/tablespace_space.sql b/tablespace_space.sql new file mode 100644 index 0000000..6d9336c --- /dev/null +++ b/tablespace_space.sql @@ -0,0 +1,71 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get a overview over the free and used space for a tablespace +-- parameter name of the tablespace +--============================================================================== +-- http://oraculix.wordpress.com/2010/10/03/ora-01652-und-fragmentierte-tablespaces/ +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + +define TABLESPACE_NAME = '&1' + +prompt +prompt Parameter 1 = Tablespace Name => &&TABLESPACE_NAME. +prompt + +column file_id format 9999 heading "File|Id" +column free_space_parts format 999G999G999 heading "Free|Parts" +column free_bytes_total format 999G999D99 heading "Free Total|MB's" +column free_blocks_total format 999G999G999 heading "Free Total|Blocks" +column max_free_bytes_in_one format 999G999D99 heading "Largest|MB's" +column max_free_blks_in_one format 999G999G999 heading "Largest|Blocks" + +select file_id, + count(*) free_space_parts + ,round(sum(bytes)/1024/1024,2) free_bytes_total + ,sum(blocks) free_blocks_total + ,round(max(bytes)/1024/1024,2) max_free_bytes_in_one + ,max(blocks) max_free_blks_in_one + from sys.dba_free_space +where upper(tablespace_name)=upper('&&tablespace_name') +group by tablespace_name + , file_id +order by file_id +/ + +prompt +prompt existing storage distriubtion in the tablespace +prompt + +select sizes + , count(distinct segment_name) segs + , sum(blocks) blks + from (select segment_name + , case + when blocks < 128 then 'small' + when blocks between 128 and 1023 then 'mittel' + else 'large' + end as sizes + , blocks + from dba_extents + where tablespace_name = upper('&&tablespace_name') + ) +group by sizes +order by blks desc +/ + +prompt +prompt Extented distribution over the tables +prompt + +select segment_name + , bytes/1024 as kb + , count(*) + from dba_extents + where tablespace_name=upper('&&tablespace_name') + group by segment_name,bytes + order by 1 + / + diff --git a/tablespace_tab_storage.sql b/tablespace_tab_storage.sql new file mode 100644 index 0000000..fdb42da --- /dev/null +++ b/tablespace_tab_storage.sql @@ -0,0 +1,30 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- In Work! +-- Desc: show all tables on a tablespace +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define TABLESPACE_NAME = '&1' + +column TABLE_NAME format a25 heading "Table|Name" + + select TABLE_NAME + , owner + , PCT_FREE + , PCT_USED + , INI_TRANS + , MAX_TRANS + , INITIAL_EXTENT + , NEXT_EXTENT + , NEXT_EXTENT / 8192 frag_factor + --,MIN_EXTENTS + --,MAX_EXTENTS + --,PCT_INCREASE + --,FREELISTS + --,FREELIST_GROUPS + from dba_tables + where tablespace_name = upper ('&&TABLESPACE_NAME.') +order by NEXT_EXTENT +/ \ No newline at end of file diff --git a/tablespace_usage.sql b/tablespace_usage.sql new file mode 100644 index 0000000..a89a604 --- /dev/null +++ b/tablespace_usage.sql @@ -0,0 +1,83 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the object count and size of a tablespace +-- Date: Januar 2015 +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + + +define TABLESPACE = "&1" + + +prompt +prompt Parameter 1 = Tablespace Name => '&TABLESPACE' +prompt + + +ttitle left "Space Usage overview for this tablespace &TABLESPACE" skip 2 + +column OWNER format a25 + +--user summary +--break on owner SKIP 1 +--COMPUTE SUM OF size_GB ON owner + +column dummy noprint; +compute sum of size_gb on dummy; +break on dummy; + + +select null dummy + , owner + , obj_type + , obj_count + , sum(size_GB) as size_GB + from ( + select count(*) as obj_count + , o.object_type as obj_type + , o.owner + ,round( sum(s.bytes) /1024/1024/1024 , 3) as size_GB + from dba_objects o + , dba_segments s + where s.owner=o.owner + and s.segment_name =o.object_name(+) + and s.TABLESPACE_NAME= upper('&TABLESPACE.') + --and o.object_name like '%TEMP%' + group by o.object_type,o.owner + ) +where obj_type in ('TABLE','INDEX','LOB') +--GROUP BY rollup (owner,obj_type,obj_count) +group by owner,obj_type,obj_count +order by owner,obj_type +/ + +ttitle left "Space Usage overview for this tablespace &TABLESPACE - the 25 top objects" skip 2 + +select * from ( + select object_name + , object_type + , owner + , size_GB + , rank() OVER (ORDER BY size_GB DESC) AS rang + from ( + select o.object_name + , o.object_type + , o.owner + , round( (s.bytes) /1024/1024/1024 , 3) as size_GB + from dba_objects o + , dba_segments s + where s.owner=o.owner + and s.segment_name =o.object_name + and s.TABLESPACE_NAME= upper('&TABLESPACE.') + --order by s.bytes + ) +) +--where rownum < 25 +where rang < 25 +/ + +ttitle off + +clear break diff --git a/taf.sql b/taf.sql new file mode 100644 index 0000000..5e14e16 --- /dev/null +++ b/taf.sql @@ -0,0 +1,48 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: check TAF - Transparent Application Fail over Connects to a database +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +column inst_id format 99 heading "Inst|ID" +column username format a20 heading "DB User|name" +column machine format a30 heading "Remote|pc/server" +column connect_count format 9G999 heading "Con|count" +column failover_type format a6 heading "Fail|type" +column failover_method format a6 heading "Fail|method" +column failed_over format a6 heading "Fail|over" +column service_name format a20 heading "Service|Name" +column status format a10 + + +break on report +compute sum of connect_count on report + +--BREAK ON inst_id skip 2 +--COMPUTE SUM OF connect_count ON inst_id + + select inst_id + , service_name + , machine + , username + , status + , failover_type + , failover_method + , failed_over + , count (*) as connect_count + from gv$session + where username not in ('SYS', 'DBSNMP') +group by inst_id + , machine + , username + , status + , failover_type + , failover_method + , failed_over + , service_name +order by machine, username +/ + +clear break \ No newline at end of file diff --git a/tempspace_usage.sql b/tempspace_usage.sql new file mode 100644 index 0000000..6ff9e6b --- /dev/null +++ b/tempspace_usage.sql @@ -0,0 +1,77 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show processes using the temp tablespace +--============================================================================== +--http://gavinsoorma.com/2009/06/temp-tablespace-usage/ +--============================================================================== + +set linesize 130 pagesize 300 + +column inst_id format 99 heading "Inst|ID" +column username format a8 heading "DB User|name" +column sid format 9999 heading "SID" +column spid format a8 heading "sPID" +column serial# format 99999 heading "Serial" +column program format a19 heading "Remote|program" +column module format a19 heading "Remote|module" +column tablespace format a10 heading "Table|space" +column osuser format a12 heading "OS|User" +column mb_used format 9G999G999 heading "In USE|MB" +column statements format 9999 heading "Segments" + +select ses.inst_id + , ses.sid + , ses.serial# + , ses.username + , ses.osuser + , to_char(pro.spid) as spid + , sum(sou.blocks) * tbs.block_size / 1024 / 1024 mb_used + , sou.tablespace + , count(*) statements + , ses.module + , pro.program + from gv$sort_usage sou + , gv$session ses + , dba_tablespaces tbs + , gv$process pro + where sou.session_addr = ses.saddr + and ses.paddr = pro.addr + and sou.tablespace = tbs.tablespace_name + and pro.inst_id=sou.inst_id + and sou.inst_id=ses.inst_id + group by ses.inst_id + , ses.sid + ,ses.serial# + ,ses.username + ,ses.osuser + ,pro.spid + ,ses.module + ,pro.program + ,tbs.block_size + ,sou.tablespace + order by ses.inst_id +/ + + +select TABLESPACE_NAME + , round(TABLESPACE_SIZE/1024/1024,3) as TABLESPACE_SIZE_MB + , round(ALLOCATED_SPACE/1024/1024,3) as ALLOCATED_SPACE_MB + , round(FREE_SPACE/1024/1024,3) as FREE_SPACE_MB + from DBA_TEMP_FREE_SPACE +/ + +-- select round(bytes/1024/1024,3) as akt_size_mb +-- , round(MAXBYTES/1024/1024,3) as max_size_mb +-- , status +-- , s.AUTOEXTENSIBLE +-- , INCREMENT_BY +-- , FILE_ID +-- from dba_temp_files s +-- / +-- +-- select 'alter database tempfile ''' || s.file_name || ''' resize '||'&TEMP_NEW_SIZE'||';' as command ,FILE_ID +-- from dba_temp_files s +-- / + + + diff --git a/test_sqlnet_fw.sql b/test_sqlnet_fw.sql new file mode 100644 index 0000000..5086262 --- /dev/null +++ b/test_sqlnet_fw.sql @@ -0,0 +1,263 @@ +----==================================== +-- GPI - Gunther Pippèrr +-- Desc: Test Script to check FW Time-outs in SQL*Net +-- +-- Idea: Select something form the DB - Wait some time in a pl/sql loop - test against -- wait a longer period of time - test again and so on.. +-- Goal: How long can be the connection idle until the communication is dropped by the FW +-- +-- edit the Intervals Value to check the test intervals +-- the may spool off should avoid that some messages are not in the log file (Buffer effect! ) ! +--==================================== +set verify off +set linesize 130 pagesize 300 + +set serveroutput on +set feedback off + +variable WAITTIME number; +variable INTERVALS number; + +begin + :WAITTIME := 15; + :INTERVALS := 15; +end; +/ + +------------------- +-- create spool name +col SPOOL_NAME_COL new_val SPOOL_NAME + +select replace ( + ora_database_name + || '_' + || sys_context ('USERENV', 'HOST') + || '_' + || to_char (sysdate, 'dd_mm_yyyy_hh24_mi') + || '_fwchek_.sql' + , '\' + , '_') + --' resolve syntax highlight bug FROM my editer .-( + as SPOOL_NAME_COL + from dual +/ + +spool &&SPOOL_NAME + +------------------- + +prompt ======================================= +prompt START FW TEST +prompt ======================================= +@date +@my_user +-- !! not use the first block for copy past the next ones!! +prompt == Start waiting ............ + +begin + dbms_lock.sleep ( 60 + * :INTERVALS); + dbms_output.put_line ( + '== Info Wait time :: ' || to_char (:INTERVALS) || ' Wake up at :: ' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + :WAITTIME := + :WAITTIME + + :INTERVALS; +end; +/ + +prompt == Finish Waiting , start next try +@date +@my_user + +spool off +-- +spool &&SPOOL_NAME append + +------------------- + +prompt == Start waiting ............ +-- Use this block for new blocks! + +begin + dbms_lock.sleep ( 60 + * :WAITTIME); + dbms_output.put_line ( + '== Info Wait time :: ' || to_char (:WAITTIME) || ' Wake up at :: ' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + :WAITTIME := + :WAITTIME + + :INTERVALS; +end; +/ + +prompt == Finish Waiting , start next try +@date +@my_user + +spool off +-- +spool &&SPOOL_NAME append + +------------------- + +prompt == Start waiting ............ + +begin + dbms_lock.sleep ( 60 + * :WAITTIME); + dbms_output.put_line ( + '== Info Wait time :: ' || to_char (:WAITTIME) || ' Wake up at :: ' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + :WAITTIME := + :WAITTIME + + :INTERVALS; +end; +/ + +prompt == Finish Waiting , start next try +@date +@my_user + +spool off +-- +spool &&SPOOL_NAME append + +------------------- + +prompt == Start waiting ............ + +begin + dbms_lock.sleep ( 60 + * :WAITTIME); + dbms_output.put_line ( + '== Info Wait time :: ' || to_char (:WAITTIME) || ' Wake up at :: ' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + :WAITTIME := + :WAITTIME + + :INTERVALS; +end; +/ + +prompt == Finish Waiting , start next try +@date +@my_user + +spool off +-- +spool &&SPOOL_NAME append + +------------------- + +prompt == Start waiting ............ + +begin + dbms_lock.sleep ( 60 + * :WAITTIME); + dbms_output.put_line ( + '== Info Wait time :: ' || to_char (:WAITTIME) || ' Wake up at :: ' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + :WAITTIME := + :WAITTIME + + :INTERVALS; +end; +/ + +prompt == Finish Waiting , start next try +@date +@my_user + +spool off +-- +spool &&SPOOL_NAME append + +------------------- + +prompt == Start waiting ............ + +begin + dbms_lock.sleep ( 60 + * :WAITTIME); + dbms_output.put_line ( + '== Info Wait time :: ' || to_char (:WAITTIME) || ' Wake up at :: ' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + :WAITTIME := + :WAITTIME + + :INTERVALS; +end; +/ + +prompt == Finish Waiting , start next try +@date +@my_user + +spool off +-- +spool &&SPOOL_NAME append + +------------------- + + +prompt == Start waiting ............ + +begin + dbms_lock.sleep ( 60 + * :WAITTIME); + dbms_output.put_line ( + '== Info Wait time :: ' || to_char (:WAITTIME) || ' Wake up at :: ' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + :WAITTIME := + :WAITTIME + + :INTERVALS; +end; +/ + +prompt == Finish Waiting , start next try +@date +@my_user + +spool off +-- +spool &&SPOOL_NAME append + +------------------- + + +prompt == Start waiting ............ + +begin + dbms_lock.sleep ( 60 + * :WAITTIME); + dbms_output.put_line ( + '== Info Wait time :: ' || to_char (:WAITTIME) || ' Wake up at :: ' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + :WAITTIME := + :WAITTIME + + :INTERVALS; +end; +/ + +prompt == Finish Waiting +@date +@my_user + +spool off +-- +spool &&SPOOL_NAME append + +------------------- + + +prompt == Start waiting ............ + +begin + dbms_lock.sleep ( 60 + * :WAITTIME); + dbms_output.put_line ( + '== Info Wait time :: ' || to_char (:WAITTIME) || ' Wake up at :: ' || to_char (sysdate, 'dd.mm.yyyy hh24:mi')); + :WAITTIME := + :WAITTIME + + :INTERVALS; +end; +/ + +prompt == Finish Waiting , start next try +@date +@my_user + +prompt ======================================= +prompt FINISH FW TEST +prompt ======================================= + +spool off diff --git a/tns.sql b/tns.sql new file mode 100644 index 0000000..4c4fabc --- /dev/null +++ b/tns.sql @@ -0,0 +1,228 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: check Services and tns Settings for the services +-- Date: 09.2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + + +ttitle 'services configured to use load balancing advisory (lba) features| (from dba_services)' + +column name format a16 heading 'service name' wrap +column created_on format a20 heading 'created on' wrap +column goal format a12 heading 'service|workload|management|goal' +column clb_goal format a12 heading 'connection|load|balancing|goal' +column aq_ha_notifications format a16 heading 'advanced|queueing|high-|availability|notification' + + select name + , to_char (creation_date, 'mm-dd-yyyy hh24:mi:ss') created_on + , goal + , clb_goal + , aq_ha_notifications + from dba_services + where goal is not null + and name not like 'SYS%' +order by name +/ + + +ttitle 'current service-level metrics|(from gv$servicemetric)' + + +--break on service_name noduplicates + +column service_name format a15 heading 'service|name' wrap +column inst_id format 9999 heading 'inst|id' +column beg_hist format a10 heading 'start time' wrap +column end_hist format a10 heading 'end time' wrap +column intsize_csec format 9999 heading 'intvl|size|(cs)' +column goodness format 999999 heading 'goodness' +column delta format 999999 heading 'pred-|icted|good-|ness|incr' +column cpupercall format 99999999 heading 'cpu|time|per|call|(mus)' +column dbtimepercall format 99999999 heading 'elpsd|time|per|call|(mus)' +column callspersec format 99999999 heading '# 0f|user|calls|per|second' +column dbtimepersec format 99999999 heading 'dbtime|per|second' +column flags format 999999 heading 'flags' + + select sm.inst_id + , sm.service_name + , ds.service_id + , to_char (sm.begin_time, 'hh24:mi:ss') beg_hist + , to_char (sm.end_time, 'hh24:mi:ss') end_hist + , sm.goodness + , sm.flags + , ds.goal + , sm.delta + , sm.dbtimepercall + , sm.callspersec + , sm.dbtimepersec + from gv$servicemetric sm, dba_services ds + where sm.service_name = ds.name + and ds.goal is not null +order by sm.service_name, sm.inst_id, sm.begin_time +/ + +prompt ... +prompt ... goodness => indicates how attractive a given instance is with respect to processing the workload that is presented to the service. +prompt ... a lower number is better. this number is internally computed based on the goal (long or short) that is specified for the particular service. +prompt ... +prompt ... predicted goodness incr => the predicted increase in the goodness for every additional session that is routed to this instance +prompt ... +prompt ... flags +prompt ... 0x01 - service is blocked from accepting new connections +prompt ... 0x02 - service is violating the set threshold on some metric +prompt .. 0x04 - goodness is unknown + +clear break + + +ttitle 'current connection distribution over the services' + + select count (*) + , inst_id + , service_name + , username + from gv$session + where service_name not like 'SYS%' +group by service_name, inst_id, username +order by 4 +/ + +ttitle 'current connection over the services for each server' + + select count (*) + , inst_id + , service_name + , username + , machine + from gv$session + where service_name not like 'SYS%' +group by service_name + , inst_id + , username + , machine +order by 5 +/ + +ttitle 'current services defined but not active? delete script' + +column cmd format a100 + +select 'execute dbms_service.delete_service(''' || name || ''');' as cmd + from dba_services + where name not in (select name from gv$active_services) +/ + +ttitle 'Current Service Name Paramter' + +@init service_names + + +variable ddllob clob + +set heading off +set echo off + +set long 64000; + + + +declare + type tockenTab is table of varchar2 (255) + index by binary_integer; + + cursor c_sv_value + is + select value + from gv$parameter p, gv$instance v + where p.inst_id = v.inst_id + and name = 'service_names'; + + v_param_list varchar2 (32767); + v_ddl varchar (2000) := 'alter system set service_names=##SERVICE_NAME_LIST## scope=both sid=''*'';'; + v_tab_length binary_integer; + v_s_array dbms_utility.lname_array; + v_a_list tockenTab; + v_a_count pls_integer := 0; + v_s_mon_found boolean := false; +begin + for rec in c_sv_value + loop + -- split servicenames in a table + dbms_utility.comma_to_table (list => rec.value, tablen => v_tab_length, tab => v_s_array); + + -- check for monitoring service + for i in 1 .. v_tab_length + loop + if rtrim (ltrim (upper (v_s_array (i)))) like 'S_MONITORING%' + then + v_s_mon_found := true; + end if; + end loop; + + if v_s_mon_found = false + then + v_tab_length := + v_tab_length + + 1; + v_s_array (v_tab_length) := 'S_MONITORING'; + end if; + + -- recreate the parameter + for i in 1 .. v_tab_length + loop + if i = 1 + then + v_param_list := rtrim (ltrim (v_s_array (i))); + else + if length (v_param_list || ',' || v_s_array (i)) < 200 + then + v_param_list := v_param_list || ',' || rtrim (ltrim (v_s_array (i))); + else + v_a_count := + v_a_count + + 1; + v_a_list (v_a_count) := v_param_list; + v_param_list := rtrim (ltrim (v_s_array (i))); + end if; + end if; + end loop; + + v_a_count := + v_a_count + + 1; + v_a_list (v_a_count) := v_param_list; + + dbms_output.put_line ('Info -- orginal==' || rec.value); + + + for i in 1 .. v_a_count + loop + if i = 1 + then + v_param_list := '''' || v_a_list (i); + else + v_param_list := v_param_list || ''',''' || v_a_list (i); + end if; + end loop; + + v_param_list := v_param_list || ''''; + end loop; + + :ddllob := replace (v_ddl, '##SERVICE_NAME_LIST##', v_param_list); +end; +/ + +set linesize 130 +column cmd format a130 + +select :ddllob as cmd from dual; + +undefine ddllob + +set heading on + + +ttitle off diff --git a/tns_history.sql b/tns_history.sql new file mode 100644 index 0000000..fc0103e --- /dev/null +++ b/tns_history.sql @@ -0,0 +1,59 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: History of usage of a service in the last half day +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + + +ttitle 'Past service-level metrics|(from gv$servicemetric)' + + +--break on service_name noduplicates + +column service_name format a15 heading 'service|name' wrap +column inst_id format 9999 heading 'inst|id' +column beg_hist format a10 heading 'start time' wrap +column end_hist format a10 heading 'end time' wrap +column intsize_csec format 9999 heading 'intvl|size|(cs)' +column goodness format 999999 heading 'goodness' +column delta format 999999 heading 'pred-|icted|good-|ness|incr' +column cpupercall format 99999999 heading 'cpu|time|per|call|(mus)' +column dbtimepercall format 99999999 heading 'elpsd|time|per|call|(mus)' +column callspersec format 99999999 heading '# 0f|user|calls|per|second' +column dbtimepersec format 99999999 heading 'dbtime|per|second' +column flags format 999999 heading 'flags' + +select sm.inst_id + , sm.service_name + , ds.service_id + , to_char(sm.begin_time,'hh24:mi:ss') beg_hist + , to_char(sm.end_time,'hh24:mi:ss') end_hist + , ds.goal + , sm.dbtimepercall + , sm.callspersec + , sm.dbtimepersec + from gv$servicemetric_history sm + , dba_services ds + where sm.service_name=ds.name + and ds.goal is not null + and sm.BEGIN_TIME between sysdate-0.5 and sysdate + and sm.dbtimepercall > 0 + order by sm.service_name,sm.inst_id,sm.begin_time +/ + +prompt... +prompt... goodness => indicates how attractive a given instance is with respect to processing the workload that is presented to the service. +prompt... a lower number is better. this number is internally computed based on the goal (long or short) that is specified for the particular service. +prompt... +prompt... predicted goodness incr => the predicted increase in the goodness for every additional session that is routed to this instance +prompt... +prompt... flags +prompt... 0x01 - service is blocked from accepting new connections +prompt... 0x02 - service is violating the set threshold on some metric +prompt.. 0x04 - goodness is unknown + +--clear break + +ttitle off diff --git a/top_sql.sql b/top_sql.sql new file mode 100644 index 0000000..72cc8d6 --- /dev/null +++ b/top_sql.sql @@ -0,0 +1,122 @@ +--============================================================================== +-- GPI - Gunther Pippčrr +-- Desc: HTML Report for SQL queries with the most resource usage +--============================================================================== + +col SPOOL_NAME_COL new_val SPOOL_NAME + +SELECT replace(ora_database_name||'_'||SYS_CONTEXT('USERENV','HOST')||'_'||to_char(sysdate,'dd_mm_yyyy_hh24_mi')||'_top_sql.html','\','_') +--' resolve syntax highlight bug FROM my editer .-( + AS SPOOL_NAME_COL +FROM dual +/ + +set verify off +set linesize 130 pagesize 300 + +column sql_text format a35 heading "SQL|Text" +column sql_id format a13 heading "SQL|ID" +column parsing_user_name format a10 heading "Parsing|Schema" +column executions format 999G999G999G999 heading "Exec" +column buffer_gets format 999G999G999G999 heading "Buffer|Gets" +column disk_reads format 999G999G999G999 heading "Disks|Reads" +column cpu_time format 999G999G999G999 heading "CpuTime|microseconds" +column sorts format 999G999G999G999 heading "Sorts" +column avg_bufferget_per_ex format 999G999G999D99 heading "AVG Buffer gets|Executions" +column avg_disk_reads_per_ex format 999G999G999D99 heading "AVG Disk reads|Executions" +column avg_sort_per_ex format 999G999G999D99 heading "AVG Sorts|Executions" +column avg_cpu_per_ex format 999G99G999G999D99 heading "AVG CPU|Executions" + +spool &&SPOOL_NAME + + +set markup html on + +ttitle center "Top 20 SQL Statements with high buffer gets > 10000" SKIP 2 + +select * from +( + select SQL_ID + , (select username from dba_users where user_id=parsing_user_id) as "Parsing User" + , executions + , loads + , buffer_gets + , disk_reads + , trunc(buffer_gets/(executions),2) avg_bufferget_per_ex + , trunc(disk_reads/(executions),2) avg_disk_reads_per_ex + , sql_text + from v$sqlarea + where executions > 1 + and buffer_gets > 10000 + order by buffer_gets desc +) +where rownum <=20; + +ttitle center "Top 20 SQL Statements with high sorts" SKIP 2 + +select * from +( + select SQL_ID + , (select username from dba_users where user_id=parsing_user_id) as "Parsing User" + , executions + , loads + , sorts + , buffer_gets + , disk_reads + , trunc(sorts/(executions),2) avg_sort_per_ex + , sql_text + from v$sqlarea + where executions > 1 + and sorts > 10 + order by sorts desc +) +where rownum <=20; + + +ttitle center "Top 20 SQL Statements with high CPU" SKIP 2 + +select * from +( + select SQL_ID + , (select username from dba_users where user_id=parsing_user_id) as "Parsing User" + , executions + , loads + , cpu_time + , buffer_gets + , disk_reads + , trunc(cpu_time/(executions),2) avg_cpu_per_ex + , sql_text + from v$sqlarea + where executions > 1 + and cpu_time > 10 + order by cpu_time desc +) +where rownum <=20; + +ttitle center "Top 20 SQL Statements with mostly executed" SKIP 2 + +select * from +( + select SQL_ID + , (select username from dba_users where user_id=parsing_user_id) as "Parsing User" + , executions + , loads + , cpu_time + , buffer_gets + , disk_reads + , trunc(cpu_time/(executions),2) avg_cpu_per_ex + , sql_text + from v$sqlarea + where executions > 1000 + order by cpu_time desc +) +where rownum <=20; + +set markup html off + +spool off +ttitle off + +-- works only in a ms windows environment +-- auto start of the result in a browser window +host &&SPOOL_NAME \ No newline at end of file diff --git a/trace_status.sql b/trace_status.sql new file mode 100644 index 0000000..5a0c067 --- /dev/null +++ b/trace_status.sql @@ -0,0 +1,74 @@ +--============================================================================== +-- GPI- Gunther Pippčrr +-- Desc: show the trace status of the DB +--============================================================================== +-- see also Tracing Enhancements Using DBMS_MONITOR (In 10g, 11g and Above) (Doc ID 293661.1) +-- +--============================================================================== + +set verify off +set linesize 130 pagesize 300 + + +column trace_type format a15 +column primary_id format a15 +column qualifier_id1 format a15 +column qualifier_id2 format a15 +column waits format a5 +column binds format a5 +column plan_stats format a15 +column instance_name format a20 + + +ttitle left "DB Trace status for Using DBMS_MONITOR only" skip 2 + +-- https://docs.oracle.com/cd/E11882_01/server.112/e40402/statviews_3167.htm + +select trace_type + , primary_id + , qualifier_id1 + , qualifier_id2 + , waits + , binds + , plan_stats + , instance_name + from dba_enabled_traces +order by instance_name +/ + + +ttitle left "DB Trace status for all user sessions" skip 2 + +column inst_id format 99 heading "Inst|ID" +column username format a20 heading "DB User|name" +column sid format 99999 heading "SID" +column serial# format 99999 heading "Serial" +column program format a16 heading "Remote|program" +column module format a16 heading "Remote|module" +column client_info format a15 heading "Client|info" +column client_identifier format A15 heading "Client|identifier" +column action format a30 +column tracefile format a80 heading "Trace|File" FOLD_BEFORE +column sep FOLD_BEFORE + +select vs.inst_id + , vs.sid + , vs.serial# + , vs.username + , vs.module + , vs.ACTION + , to_char(vs.LOGON_TIME,'dd.mm hh24:mi') as LOGON_TIME + , vs.client_identifier + , vs.client_info + , substr(p.tracefile,length(p.tracefile)-REGEXP_INSTR(reverse(p.tracefile),'[\/|\]')+2,1000) as tracefile + , p.tracefile + , rpad('+',80,'=') as sep +from gv$session vs + , gv$process p +where vs.SQL_TRACE != 'DISABLED' + and vs.paddr=p.addr + and vs.inst_id=p.inst_id +order by inst_id +/ + +ttitle off \ No newline at end of file diff --git a/trans.sql b/trans.sql new file mode 100644 index 0000000..eb5cd08 --- /dev/null +++ b/trans.sql @@ -0,0 +1,49 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: running transactions in the database +-- Date: September 2012 +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Report active DB transactions" SKIP 1 + +column sessionid format a8 heading "DB|Session" +column inst_id format 99 heading "In|id" +column username format a9 heading "DB|user" +column osuser format a9 heading "OS|Benutzer" +column machine format a9 heading "OS|Maschine" +column program format a9 heading "OS|Programm" +column xidsqn heading "Trans.| Nr." +column start_scnb heading "Start|SCN" + +column start_time heading "Start|Time" +--column used_ublk heading "Ver.|Blocks" +column status format a6 heading "Status" +--column xidusn heading "Nr.|RB Seg." + +column logon_time format a14 heading "Login|Time" +column start_time format a14 heading "Start|Time" +column last_call_et format a14 heading "Last Sql|Time" + + +select s.sid||':'||serial# as sessionid + , s.inst_id + , s.username + , s.osuser + , s.machine + , s.program + , to_char(s.logon_time,'dd.mm hh24:mi') as logon_time + , t.xidsqn + , t.start_scnb + , t.start_time + , s.last_call_et +-- , t.used_ublk + , t.status +-- , t.xidusn + from gv$transaction t, gv$session s + where s.taddr=t.addr + and s.inst_id = t.inst_id +order by s.logon_time +/ + +ttitle off \ No newline at end of file diff --git a/undo.sql b/undo.sql new file mode 100644 index 0000000..139b6bb --- /dev/null +++ b/undo.sql @@ -0,0 +1,41 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: undo usage +-- Date: November 2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +show parameter undo + +column name format a30 +column status format a20 +column username format a20 +column sid format 99999999 + +select a.name + , b.status + , d.username + , d.sid + , d.serial# + , d.inst_id + from v$rollname a + , v$rollstat b + , gv$transaction c + , gv$session d + where a.usn = b.usn + and a.usn = c.xidusn + and c.ses_addr = d.saddr + and c.inst_id = d.inst_id + and a.name in (select segment_name + from dba_segments + where tablespace_name like 'UNDO%') +/ + + +select DBMS_UNDO_ADV.longest_query(sysdate-1,sysdate) as best_undo_time from dual +/ + +select DBMS_UNDO_ADV.required_retention(sysdate-30,sysdate) as longst_query_30_days from dual; +/ \ No newline at end of file diff --git a/undo_stat.sql b/undo_stat.sql new file mode 100644 index 0000000..2263b82 --- /dev/null +++ b/undo_stat.sql @@ -0,0 +1,203 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: undo stat +--============================================================================== +-- Source: +-- http://www.dbaref.com/home/dba-routine-tasks/scriptstocheckundotablespacestats +-- http://docs.oracle.com/cd/B28359_01/server.111/b28320/dynviews_3110.htm#REFRN30295 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +prompt Show the Undo init.ora settings + +show parameter undo + +column "Begin" format a21 +column "End" format a21 + +ttitle "How often and when does -Snapshot too old (ORA-01555) -occur?" skip 2 + +select Inst_id + , to_char(begin_time,'YYYY-MM-DD HH24:MI:SS') "Begin" + , to_char(end_time,'YYYY-MM-DD HH24:MI:SS') "End" + , undoblks "UndoBlocks" + , SSOLDERRCNT "ORA-1555" + , MAXQUERYID +from GV$UNDOSTAT +where SSOLDERRCNT > 0 +order by 1 +/ + +ttitle "length of the longest query (in seconds and hours)" skip 2 + +Select max(MAXQUERYLEN), max(MAXQUERYLEN)/60/60 From V$UNDOSTAT; + + + + +ttitle "When and how often was the undo-table space too small?" skip 2 + + +select Inst_id + , to_char(begin_time,'YYYY-MM-DD HH24:MI:SS') as "Begin" + , to_char(end_time,'YYYY-MM-DD HH24:MI:SS') as "End" + , undoblks "UndoBlocks" + , nospaceerrcnt "Space Err" +from GV$UNDOSTAT +where nospaceerrcnt > 0 +order by 1 +/ + +--This option is disabled by default. see http://docs.oracle.com/cd/B28359_01/server.111/b28310/undo002.htm#ADMIN10180 +ttitle "RETENTION policy on the tablespace" skip 2 + +column tablespace_name format a25 heading "Tablespace|Name" +column used_space_gb format 999G990D999 heading "Used Space|GB" +column gb_free format 999G990D999 heading "Free Space|GB" +column tablespace_size_gb format 999G990D999 heading "Max Tablespace|Size GB" +column DF_SIZE_GB format 999G990D999 heading "Size on| Disk GB" +column used_percent format 90G99 heading "Used |% Max" +column pct_used_size format 90G99 heading "Used |% Disk" +column BLOCK_SIZE format 99G999 heading "TBS BL|Size" +column DF_Count format 9G999 heading "Count|DB Files" + +select dt.tablespace_name + , dt.RETENTION + , round((dm.tablespace_size * dt.BLOCK_SIZE)/1024/1024/1024,3) as tablespace_size_gb + , round( + (case dt.CONTENTS + when 'TEMPORARY' then + (select sum(df.BLOCKS)*dt.BLOCK_SIZE from dba_temp_files df where df.TABLESPACE_NAME=dt.tablespace_name) + else + (select sum(df.BLOCKS)*dt.BLOCK_SIZE from dba_data_files df where df.TABLESPACE_NAME=dt.tablespace_name) + end) /1024/1024/1024,3) as DF_SIZE_GB + , (case dt.CONTENTS + when 'TEMPORARY' then + (select count(*) from dba_temp_files df where df.TABLESPACE_NAME=dt.tablespace_name) + else + (select count(*) from dba_data_files df where df.TABLESPACE_NAME=dt.tablespace_name) + end) as DF_Count + , round(((dm.used_space * dt.BLOCK_SIZE)/1024/1024/1024),3) as used_space_gb + , round(100*dm.used_percent,2) as used_percent + , dt.BLOCK_SIZE + from DBA_TABLESPACE_USAGE_METRICS dm + , dba_tablespaces dt +where dm.tablespace_name=dt.tablespace_name +and dt.tablespace_name like 'UNDO%' +order by dm.tablespace_name +/ + + +prompt ... +prompt ... if "NOGUARANTEE" the DB will not gurantee the Undo Rention time +prompt ... + + +ttitle "Maximal Undo usage (MB) over the last 4 days - but only for this instance!" skip 2 + +-- http://docs.oracle.com/cd/E11882_01/server.112/e40402/dynviews_3118.htm#REFRN30295 +-- thanks to may be trivadis ? + +column days format a6 heading "day" +column m30 format 999G999 heading "30m" +column m60 format 999G999 heading "1h" +column m120 format 999G999 heading "2h" +column m180 format 999G999 heading "3h" +column m240 format 999G999 heading "4h" +column m300 format 999G999 heading "5h" +column m600 format 999G999 heading "6h" +column m900 format 999G999 heading "15" +column m1440 format 999G999 heading "24h" +column m1800 format 999G999 heading "30h" +column m2400 format 999G999 heading "40h" +column m3000 format 999G999 heading "50h" + +select days + , round(b.block_size * a.m30 /(1024*1024)) m30 + , round(b.block_size * a.m60 /(1024*1024)) m60 + , round(b.block_size * a.m120 /(1024*1024)) m120 + , round(b.block_size * a.m180 /(1024*1024)) m180 + , round(b.block_size * a.m240 /(1024*1024)) m240 + , round(b.block_size * a.m300 /(1024*1024)) m300 + , round(b.block_size * a.m600 /(1024*1024)) m600 + , round(b.block_size * a.m900 /(1024*1024)) m900 + , round(b.block_size * a.m1440/(1024*1024)) m1440 + , round(b.block_size * a.m1800/(1024*1024)) m1800 + , round(b.block_size * a.m2400/(1024*1024)) m2400 + , round(b.block_size * a.m3000/(1024*1024)) m3000 +from + (select max(sum_blk30) m30 + , max(sum_blk60) m60 + , max(sum_blk120) m120 + , max(sum_blk180) m180 + , max(sum_blk240) m240 + , max(sum_blk300) m300 + , max(sum_blk600) m600 + , max(sum_blk900) m900 + , max(sum_blk1440) m1440 + , max(sum_blk1800) m1800 + , max(sum_blk2400) m2400 + , max(sum_blk3000) m3000 + , days + from + (select begin_time + , undoblks + , to_char(begin_time,'dd.mm') as days + , sum(undoblks) over (order by begin_time rows between current row and 2 following) as sum_blk30 + , sum(undoblks) over (order by begin_time rows between current row and 5 following) as sum_blk60 + , sum(undoblks) over (order by begin_time rows between current row and 11 following) as sum_blk120 + , sum(undoblks) over (order by begin_time rows between current row and 17 following) as sum_blk180 + , sum(undoblks) over (order by begin_time rows between current row and 23 following) as sum_blk240 + , sum(undoblks) over (order by begin_time rows between current row and 29 following) as sum_blk300 + , sum(undoblks) over (order by begin_time rows between current row and 59 following) as sum_blk600 + , sum(undoblks) over (order by begin_time rows between current row and 89 following) as sum_blk900 + , sum(undoblks) over (order by begin_time rows between current row and 143 following) as sum_blk1440 + , sum(undoblks) over (order by begin_time rows between current row and 179 following) as sum_blk1800 + , sum(undoblks) over (order by begin_time rows between current row and 239 following) as sum_blk2400 + , sum(undoblks) over (order by begin_time rows between current row and 299 following) as sum_blk3000 + from v$undostat + order by begin_time ) + group by days + ) a +, (select block_size from dba_tablespaces where contents='UNDO' and status ='ONLINE' ) b +order by days +/ + +ttitle "undo per sec in the last 12 hours" skip 2 + +select trunc(end_time,'hh24') as hour + , round(sum(undoblks)/60,2) as undo_block_pr_min + , round(((sum(undoblks)/60)*( b.block_size ))/1024/1204,2) as undo_mb_pr_min + from v$undostat + , (select block_size from dba_tablespaces where contents='undo' and status ='online' ) b + where end_time > sysdate - ((1/24) * 12) +group by trunc(end_time,'hh24'),b.block_size +order by 1 +/ + + +ttitle "Dynamic Undo Retention in the last hour" skip 2 +-- +-- http://docs.oracle.com/cd/B28359_01/server.111/b28310/undo002.htm#ADMIN11462 +-- + +select to_char(begin_time, 'dd.mm.yyyy HH24:MI') begin_time + , to_char(end_time, 'dd.mm.yyyy HH24:MI') end_time + , tuned_undoretention +from v$undostat +where end_time > sysdate - (1/24*1) +order by end_time +/ + +ttitle "Dynamic Undo Retention max - min Value" skip 2 + +select min(begin_time)begin_time + , max(end_time) end_time + , min(tuned_undoretention) + , max(tuned_undoretention) +from v$undostat +/ + + +ttitle off diff --git a/user.sql b/user.sql new file mode 100644 index 0000000..cc2c14a --- /dev/null +++ b/user.sql @@ -0,0 +1,173 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the user rights and grants +-- Date: September 2012 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +set verify off + +SET linesize 120 pagesize 500 + +ttitle left "User Account status" skip 2 + +select username + , account_status + , lock_date + , expiry_date + , default_tablespace + , temporary_tablespace + from dba_users + where username like upper('&&USER_NAME.') + / + +ttitle left "User Info" skip 2 + +select lpad(' ', 2 * level) || granted_role "User, his roles and privileges" + from ( + /* THE USERS */ + select null grantee + ,username granted_role + from dba_users + where username like upper('&&USER_NAME.') + /* THE ROLES TO ROLES RELATIONS */ + union + select grantee + ,granted_role + from dba_role_privs + /* THE ROLES TO PRIVILEGE RELATIONS */ + union + select grantee + ,privilege + from dba_sys_privs) + start with grantee is null +connect by grantee = prior granted_role +/ + +ttitle left "Object rights from &&USER_NAME. to other User" skip 2 + +column grantee format a25 +column GRANTOR format a25 +column PRIVILEGE format a20 +column cnt format 9999 + +select GRANTOR + ,grantee + ,PRIVILEGE + ,table_name + ,count(*) as cnt + from DBA_TAB_PRIVS + where owner like upper('&&USER_NAME.') +-- owner not in ('SYS','MDSYS','SI_INFORMTN_SCHEMA','ORDPLUGINS','ORDDATA','ORDSYS','EXFSYS','XS$NULL','XDB','CTXSYS','WMSYS','APPQOSSYS','DBSNMP','ORACLE_OCM','DIP','OUTLN','SYSTEM','FLOWS_FILES','PUBLIC','SYSMAN','OLAPSYS','OWBSYS','OWBSYS_AUDIT') + group by owner + ,grantee + ,GRANTOR + ,PRIVILEGE + ,table_name +order by owner,table_name, PRIVILEGE +/ + +ttitle left "Object rights from other user to &&USER_NAME." skip 2 + + + +select GRANTOR + ,grantee + ,PRIVILEGE + ,table_name + ,count(*) as cnt + from DBA_TAB_PRIVS + where grantee like upper('&&USER_NAME.') + group by owner + ,grantee + ,GRANTOR + ,PRIVILEGE + ,table_name +order by owner,table_name, PRIVILEGE +/ + +ttitle left "User Quota Settings for the user &&USER_NAME." skip 2 + +column tablespace_name format a20 heading "Tablespace|Name" +column username format a20 heading "User|Name" +column m_bytes format 999G999D99 heading "Bytes" +column max_bytes_mb format 999G999D99 heading "Max|Bytes" + + +select tablespace_name + , username + , round(bytes /1024/1024,2) as m_bytes + , round(max_bytes /1024/1024,2) as max_bytes_mb +from dba_ts_quotas +where username like upper('&&USER_NAME.') +/ + +prompt ... max_bytes = -1 => unlimited! +prompt +prompt ... to set the quota +prompt ... alter user &&USER_NAME. quota unlimited on xxxxxxx; +prompt ... alter user &&USER_NAME. quota 50M on xxxxxxx; +prompt ... alter user &&USER_NAME. quota 0 on xxxxxxx; +prompt + + +ttitle left "Profile Settings for the user &&USER_NAME." skip 2 + +column PROFILE format a18 +column RESOURCE_NAME format a30 +column limit format a20 + +select p.PROFILE + , p.RESOURCE_NAME + , p.limit + from dba_profiles p + , dba_users u +where u.PROFILE=p.PROFILE + and u.username like upper('&&USER_NAME.') +order by p.RESOURCE_NAME +/ + +ttitle left "Proxy Settings for the user &&USER_NAME." skip 2 + +column PROXY format a15 heading "Proxy" +column CLIENT format a15 heading "Client|User" +column AUTHENTICATION format a5 heading "Auth" +column AUTHORIZATION_CONSTRAINT format a40 heading "Auth|Const" +column ROLE format a15 heading "Role" +column PROXY_AUTHORITY format a10 heading "Proxy|Auth" + + +select proxy + , client + , authentication + , authorization_constraint + , role + , proxy_authority + from dba_proxies +where proxy like upper('&&USER_NAME.%') +/ + +--ttitle left "Password History for the user &&USER_NAME." skip 2 +-- +--SELECT user$.NAME +-- , user$.PASSWORD +-- , user$.ptime +-- , user_history$.password_date +--FROM SYS.user_history$ +-- , SYS.user$ +--WHERE user_history$.user# = user$.user# +-- and user$.NAME like upper('&&USER_NAME.%') +-- / +-- +--prompt ... If you have PASSWORD_REUSE_TIME and/or PASSWORD_REUSE_MAX set in a profile assigned to a user account +--prompt ... then you can reference dictionary table USER_HISTORY$ for when the password was changed for this account. + +prompt ... +prompt ... Unlock User use "alter user xxxx account unlock;" +prompt ... Expire the password use "alter user xxx password expire;" + +ttitle off diff --git a/user_ddl.sql b/user_ddl.sql new file mode 100644 index 0000000..5dd2a7a --- /dev/null +++ b/user_ddl.sql @@ -0,0 +1,90 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the script to create a user - parameter 1 - Name of the user +--============================================================================== +set verify off +set linesize 130 pagesize 4000 + +define USERNAME = '&1' + +prompt +prompt Parameter 1 = USER Name => &&USERNAME. +prompt + +variable ddllob clob + +set heading off +set echo off + +set long 1000000; + +spool create_user_script_&&USERNAME..sql + +declare + cursor c_user + is + select username + from dba_users + where upper (username) like upper ('&&USERNAME.'); + + v_user varchar2 (32); +begin + -- set the transformation attributes + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true ); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'OID', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SEGMENT_ATTRIBUTES', false); + dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'TABLESPACE', true ); + + for o_rec in c_user + loop + v_user := o_rec.username; + + :ddllob := dbms_metadata.get_ddl ('USER', v_user); + + :ddllob := :ddllob || chr (10) || chr (10) || '-- Role Grants : ' || chr (10); + + begin + :ddllob := :ddllob || dbms_metadata.get_granted_ddl ('ROLE_GRANT', v_user); + exception + when others + then + :ddllob := :ddllob || chr (10) || chr (10) || '-- NO DDL for Role Grants found' || chr (10); + end; + + :ddllob := :ddllob || chr (10) || chr (10) || '-- System Grants : ' || chr (10); + + begin + :ddllob := :ddllob || dbms_metadata.get_granted_ddl ('SYSTEM_GRANT', v_user); + exception + when others + then + :ddllob := :ddllob || chr (10) || chr (10) || '-- NO DDL for Sytem Grants found' || chr (10); + end; + + :ddllob := :ddllob || chr (10) || chr (10) || '-- Object Grants : ' || chr (10); + + begin + :ddllob := :ddllob || dbms_metadata.get_granted_ddl ('OBJECT_GRANT', v_user); + exception + when others + then + :ddllob := :ddllob || chr (10) || chr (10) || '-- NO DDL for Object Grants found' || chr (10); + end; + end loop; +end; +/ + +print ddllob + +undefine ddllob + +spool off; + +set head on +set pages 1000 + +prompt ... +prompt ... to create the user call create_user_script_&&USERNAME..sql in the target DB +prompt ... \ No newline at end of file diff --git a/user_history.sql b/user_history.sql new file mode 100644 index 0000000..9c74ab4 --- /dev/null +++ b/user_history.sql @@ -0,0 +1,14 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get some static information for the login behavior of this user - Parameter 1 - Name of the user +-- Date: November 2013 +-- in work +--============================================================================== +prompt +prompt !!!!You need the Tuning Pack for this feature!!!! +prompt + +set verify off +set linesize 130 pagesize 300 + +@select DBA_HIST_ACTIVE_SESS_HISTORY diff --git a/user_objects.sql b/user_objects.sql new file mode 100644 index 0000000..c1ba88a --- /dev/null +++ b/user_objects.sql @@ -0,0 +1,107 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the object count of none default users +-- Date: October 2013 + +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +variable PUSERNAME varchar2(32) + +prompt +prompt Parameter 1 = User Name => &&USER_NAME. +prompt + +begin + if length('&&USER_NAME.') < 1 then + :PUSERNAME:='%'; + else + :PUSERNAME:='&&USER_NAME.'||'%'; + end if; +end; +/ + +column OWNER format a25 + +--user summary +--break on owner SKIP 1 +--COMPUTE SUM OF size_GB ON owner + +ttitle "MegaByte DB Objects total" SKIP 2 + +column DUMMY NOPRINT; +COMPUTE SUM OF size_GB ON DUMMY; +BREAK ON DUMMY; + +column username format a22 +column OBJ_TYPE format a22 +column size_GB format 9G999G999G990D999 + +select null dummy + , u.username + , o.obj_type + , o.obj_count + , sum(o.size_GB) as size_GB + from ( + select count(*) as obj_count, s.segment_type as obj_type, o.owner ,round( sum(s.bytes) /1024/1024/1024 , 3) as size_GB + from dba_objects o, dba_segments s + where s.owner=o.owner + and s.segment_name=o.object_name + and nvl(s.partition_name,'n/a')=nvl(o.subobject_name,'n/a') + group by s.segment_type,o.owner + union + select count(*) as obj_count, s.segment_type as obj_type, l.owner ,round( sum(s.bytes) /1024/1024/1024 , 3) as size_GB + from dba_lobs l + , dba_segments s + where l.segment_name = s.segment_name(+) + and l.owner=s.owner + group by s.segment_type,l.owner ) o + , dba_users u +where o.owner not in ('SYS','MDSYS','SI_INFORMTN_SCHEMA','ORDPLUGINS','ORDDATA','ORDSYS','EXFSYS','XS$NULL','XDB','CTXSYS','WMSYS','APPQOSSYS','DBSNMP','ORACLE_OCM','DIP','OUTLN','SYSTEM','FLOWS_FILES','PUBLIC','SYSMAN','OLAPSYS','OWBSYS','OWBSYS_AUDIT','PUBLIC','TSMSYS') + and o.obj_type in ('TABLE','INDEX','LOB','TABLE PARTITION','INDEX PARTITION','MATERIALIZED VIEW','LOBSEGMENT','LOBINDEX') + --and o.obj_type in ('INDEX','INDEX PARTITION') + and u.username = o.owner (+) + and u.username like upper(:PUSERNAME) +group by u.username,o.obj_type,o.obj_count +--GROUP BY rollup (owner,obj_type,obj_count) +order by u.username,o.obj_type +/ + +ttitle "MegaByte DB Objects in Trash" SKIP 2 + +select null dummy + , owner + , round( sum(s.bytes) /1024/1024/1024 , 3) as size_GB + from dba_segments s + where owner not in ('SYS','MDSYS','SI_INFORMTN_SCHEMA','ORDPLUGINS','ORDDATA','ORDSYS','EXFSYS','XS$NULL','XDB','CTXSYS','WMSYS','APPQOSSYS','DBSNMP','ORACLE_OCM','DIP','OUTLN','SYSTEM','FLOWS_FILES','PUBLIC','SYSMAN','OLAPSYS','OWBSYS','OWBSYS_AUDIT','PUBLIC','TSMSYS') + and segment_name like 'BIN%' + and owner like upper(:PUSERNAME) + group by owner +/ + + +ttitle "MegaByte DB Objects declared as Temporary" SKIP 2 + +select null dummy + , owner + , round( sum(s.bytes) /1024/1024/1024 , 3) as size_GB + from dba_segments s +where owner not in ('SYS','MDSYS','SI_INFORMTN_SCHEMA','ORDPLUGINS','ORDDATA','ORDSYS','EXFSYS','XS$NULL','XDB','CTXSYS','WMSYS','APPQOSSYS','DBSNMP','ORACLE_OCM','DIP','OUTLN','SYSTEM','FLOWS_FILES','PUBLIC','SYSMAN','OLAPSYS','OWBSYS','OWBSYS_AUDIT','PUBLIC','TSMSYS') + and segment_type = 'TEMPORARY' + and owner like upper(:PUSERNAME) +group by owner +/ + +ttitle off + +clear BREAK + +--undef variables --- + +undefine PUSERNAME + +--------------------- +set verify on \ No newline at end of file diff --git a/user_oracle_default.sql b/user_oracle_default.sql new file mode 100644 index 0000000..ee7cd7b --- /dev/null +++ b/user_oracle_default.sql @@ -0,0 +1 @@ +define default_oracle_user_sql =owner NOT IN ('ANONYMOUS','APEX_PUBLIC_USER','APPQOSSYS','BI','CTXSYS','DBSNMP','DIP','EXFSYS','FLOWS_FILES','HR','IX','MDDATA','MDSYS','MGMT_VIEW','OE','OLAPSYS','ORACLE_OCM','ORDDATA','ORDPLUGINS','ORDSYS','OUTLN','OWBSYS','OWBSYS_AUDIT','PM','SCOTT','SH','SI_INFORMTN_SCHEMA','SPATIAL_CSW_ADMIN_USR','SPATIAL_WFS_ADMIN_USR','SYS','SYSMAN','SYSTEM','WMSYS','XDB','XS$NULL') and not like 'APEX_0%' \ No newline at end of file diff --git a/user_tab.sql b/user_tab.sql new file mode 100644 index 0000000..5fd399c --- /dev/null +++ b/user_tab.sql @@ -0,0 +1,53 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the tables and views of this user +-- Parameter 1: Name of the User +-- +-- Date: September 2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USERNAME = &1 + +prompt +prompt Parameter 1 = User Name => &&USERNAME. +prompt + + +set linesize 130 pagesize 300 + +ttitle left "Tables and Views for this user &&USERNAME." skip 2 + +column owner format a15 heading "Qwner" +column table_name format a30 heading "Table/View Name" +column otype format a5 heading "Type" +column comments format a40 heading "Comment on this table/view" +column tablespace_name format a20 heading "Tablespace Name" + +select t.owner + , t.table_name + , 'table' as otype + , nvl (c.comments, 'n/a') as comments + , t.tablespace_name + from dba_tables t, dba_tab_comments c + where upper (t.owner) like upper ('%&&USERNAME.%') + and c.table_name(+) = t.table_name + and c.owner(+) = t.owner + and c.table_type(+) = 'TABLE' +union +select v.owner + , v.view_name + , 'view' as otype + , nvl (c.comments, 'n/a') as comments + , 'n/a' + from dba_views v, dba_tab_comments c + where upper (v.owner) like upper ('%&&USERNAME.%') + and c.table_name(+) = v.view_name + and c.owner(+) = v.owner + and c.table_type(+) = 'VIEW' +order by 1, 2 +/ + +ttitle off diff --git a/users.sql b/users.sql new file mode 100644 index 0000000..7db3b50 --- /dev/null +++ b/users.sql @@ -0,0 +1,69 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the users of the database +-- Date: September 2013 +-- +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define USER_NAME = &1 + +variable PUSERNAME varchar2(32) + +prompt +prompt Parameter 1 = User Name => &&USER_NAME. +prompt + +begin + if length('&&USER_NAME.') < 1 then + :PUSERNAME:='%'; + else + :PUSERNAME:='&&USER_NAME.'||'%'; + end if; +end; +/ + + + +ttitle left "Default Table space" skip 2 + +column default_tablespace format a20 heading "Default Table|space" + +SELECT property_value as default_tablespace + FROM database_properties +WHERE property_name = 'DEFAULT_PERMANENT_TABLESPACE' +/ + +prompt ... to set the default tablespace : alter database default tablespace ; +prompt + +ttitle left "User information" skip 2 + +column username format a24 heading "User Name" +column account_status format a20 heading "Status" +column profile format a30 heading "Profil" +column created format a16 heading "Create Date" + +select username + , account_status + , default_tablespace + , profile + , to_char(CREATED,'dd.mm.yyyy hh24:mi') as created + from dba_users +where username like upper(:PUSERNAME) + --and account_status='LOCKED' +order by username +/ + +ttitle off + +prompt ... to unlock the user : alter user account unlock; +prompt ... to set the tablespace : alter user default tablespace ; + +--undef variables --- + +undefine PUSERNAME + +--------------------- +set verify on diff --git a/version.sql b/version.sql new file mode 100644 index 0000000..1572fac --- /dev/null +++ b/version.sql @@ -0,0 +1,110 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: version of the database +-- Date: 01.September 2012 +--============================================================================== +-- see Script to Collect DB Upgrade/Migrate Diagnostic Information (dbupgdiag.sql) (Doc ID 556610.1) +--============================================================================== +set linesize 130 pagesize 300 + +ttitle left "DB Infos -- Version" skip 2 + +select banner from v$version +/ + +select * from product_component_version +/ + +ttitle left "DB Infos -- DB Bit Version" skip 2 +SELECT distinct('DB Bit Version:: '|| (length(addr)*4) || '-bit database') "WordSize" +FROM v$process +/ + +ttitle left "check if DB been created originally in a 32-bit environment and is now on a 64-bit platform" skip 2 +--10.2.0.3 Note:412271.1 +select decode(instr(metadata,'B023'),0,'64bit Database','32bit Database') as "DB Creation" +from kopm$ +/ + + +--- + +column JAVA_VERSION format a20 + +ttitle left "Which Java Version is installed on this database" + +SELECT dbms_java.get_ojvm_property(PROPSTRING=>'java.version') as JAVA_VERSION FROM dual; + +-- + + +ttitle left "DB Infos -- DB OS Version" skip 2 + +column OS_VER format a30 heading "DB OS Version" + +select dbms_utility.port_string as os_ver from dual +/ + + +ttitle left "DB Infos -- Compatibility" skip 2 + +column Compatible format a40 + +SELECT 'Compatibility is set to :: '||value Compatible +FROM v$parameter WHERE name ='compatible' +/ + +ttitle left "DB Infos -- installed components" skip 2 +column comp_name format a40 +column status format a8 +column version format a12 +column schema format a12 + +select comp_name + ,status + ,version + ,schema + from dba_registry +/ + +ttitle left "DB Infos -- check for Oracle Label Security" skip 2 + +column labelsec format a60 heading "Oracle Label Security Check" + +SELECT case count(schema) +WHEN 0 THEN 'Oracle Label Security is NOT installed at database level' +ELSE 'Oracle Label Security is installed ' +END as labelsec +FROM dba_registry +WHERE schema='LBACSYS' +/ + +prompt Check for Patches .... +prompt +ttitle left "DB Infos -- last Patches" skip 2 + +column a_time format a10 +column action format a16 +column namespace format a8 +column version format a15 +column id format a20 +column comments format a35 +column bundle_series format a6 + +select to_char(action_time, 'dd.mm.yyyy') as a_time + , action + , namespace + , version + , comments + from sys.registry$history + order by action_time desc NULLS LAST +/ + +prompt ... check for 12c also DBA_REGISTRY_SQLPATCH + +ttitle left "DB Infos -- Timezone" skip 2 +column version format 99 +SELECT version from v$timezone_file; + + +ttitle off diff --git a/view_count.sql b/view_count.sql new file mode 100644 index 0000000..8945043 --- /dev/null +++ b/view_count.sql @@ -0,0 +1,37 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: count the entries of a table +-- Date: 01.September 2013 +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +-- col y new_value OWNER +-- define OWNER=? +-- select case when nvl('&2','NO') = 'NO' then user else '&1' end as y from dual; +-- col x new_value TAB_NAME +-- define TAB_NAME=? +-- select case when nvl('&2','NO') != 'NO' then '&2' else '&' end as x from dual; + +define OWNER ='&1' +define TAB_NAME='&2' + +prompt +prompt Parameter 1 = OWNER => &&OWNER. +prompt Parameter 2 = Tab or view Name => &&TAB_NAME. +prompt + +ttitle left "Count records of the table &&OWNER..&&TAB_NAME" skip 2 + +column count_rows format 9999999 heading "Count|rows" + + +select /* gpi script lib view_count.sql */ count(*) as count_rows from &&OWNER..&&TAB_NAME +/ + +prompt +prompt +undef TAB_NAME +undef OWNER + +ttitle off \ No newline at end of file diff --git a/view_getsql.sql b/view_getsql.sql new file mode 100644 index 0000000..8a33d10 --- /dev/null +++ b/view_getsql.sql @@ -0,0 +1,37 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: extract the real SQL from a query over a view +-- +-- Parameter 2: Owner of the table/object +-- Parameter 1: Name of the table/object +-- +-- Must be run with dba privileges +-- Source : https://oracle-base.com/articles/12c/expand-sql-text-12cr1 +--============================================================================== +set verify off +set linesize 130 pagesize 3000 + +define OWNER = '&1' +define VIEW_NAME = '&2' + +prompt +prompt Parameter 1 = Owner Name => &&OWNER. +prompt Parameter 2 = Tab Name => &&VIEW_NAME. +prompt + + +SET SERVEROUTPUT ON + +DECLARE + l_clob CLOB; +BEGIN + DBMS_UTILITY.expand_sql_text ( + input_sql_text => 'select count(*) from &&OWNER..&&VIEW_NAME.', + output_sql_text => l_clob + ); + + DBMS_OUTPUT.put_line(l_clob); +END; +/ + + diff --git a/vpd.sql b/vpd.sql new file mode 100644 index 0000000..d813887 --- /dev/null +++ b/vpd.sql @@ -0,0 +1,48 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the profiles of the database +-- Date: September 2013 +-- see http://docs.oracle.com/cd/B28359_01/network.111/b28531/vpd.htm +--============================================================================== +-- see +-- DBA_POLICIES Describes all Oracle Virtual Private Database security policies in the database. +-- DBA_POLICY_GROUPS Describes all policy groups in the database. +-- DBA_POLICY_CONTEXTS Describes all driving contexts in the database. Its columns are the same as those in ALL_POLICY_CONTEXTS. +-- DBA_SEC_RELEVANT_COLS Describes the security relevant columns of all security policies in the database + +set linesize 130 pagesize 300 + +ttitle "VPD Informations" SKIP 2 + +column OBJECT_OWNER format a10 heading "OBJECT|OWNER" +column OBJECT_NAME format a15 heading "OBJECT|NAME " +column POLICY_GROUP format a15 heading "POLICY|GROUP" +column POLICY_NAME format a15 heading "POLICY|NAME " +column PF_OWNER format a7 heading "PF|OWNER" +column PACKAGE format a15 heading "PACKAGE" +column FUNCTION format a15 heading "FUNCTION" +column SEL format a3 heading "SEL" +column INS format a3 heading "INS" +column UPD format a3 heading "UPD" +column DEL format a3 heading "DEL" +column IDX format a3 heading "IDX" +column CHK_OPTION format a3 heading "CHK|OPTION" +column ENABLE format a3 heading "ENABLE" +column STATIC_POLICY format a3 heading "STATIC|POLICY" +column POLICY_TYPE format a20 heading "POLICY|TYPE" +column LONG_PREDICATE format a3 heading "LONG|PREDICATE" + + +select OBJECT_OWNER + , OBJECT_NAME + , POLICY_GROUP + , POLICY_NAME + , PF_OWNER + , PACKAGE + , FUNCTION + , ENABLE +from DBA_POLICIES +/ + + +ttitle off \ No newline at end of file diff --git a/wait.sql b/wait.sql new file mode 100644 index 0000000..6313910 --- /dev/null +++ b/wait.sql @@ -0,0 +1,115 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: show the actual wait of the database +--============================================================================== +set linesize 130 pagesize 300 + +ttitle "Report waiting Sessions" skip 2 + +column snap format a16 +column client_info format a30 +column MODULE format a20 +column username format a10 heading "User|name" + +column program format a20 +column state format a20 +column event format a15 +column last_sql format a20 +column sec format 99999 heading "Wait|sec" +column inst format 9 heading "Inst" +column ss format a10 heading "SID:Ser#" + +select /* gpi script lib wait.sql */ + --to_char(sysdate, 'dd.mm.yyyy hh24:mi') as snap + --, + sw.inst_id as inst + , s.sid || ',' || s.serial# as ss + --,s.client_info + --,s.MODULE + , s.username + --,s.program + --,sw.state + , sw.event + , sw.seconds_in_wait sec + , sw.p1 + , sw.p2 + , sw.p3 + , sa.sql_text last_sql + from gv$session_wait sw, gv$session s, gv$sqlarea sa + where sw.event not in + ('rdbms ipc message' + , 'smon timer' + , 'pmon timer' + , 'SQL*Net message from client' + , 'lock manager wait for remote message' + , 'ges remote message' + , 'client message' + , 'pipe get' + , 'Null event' + , 'PX Idle Wait' + , 'single-task message' + , 'PX Deq: Execution Msg' + , 'KXFQ: kxfqdeq - normal deqeue' + , 'listen endpoint status' + , 'slave wait' + , 'wakeup time manager' + , 'jobq slave wait' + , 'Space Manager: slave idle wait' + , 'Streams AQ: qmn coordinator idle wait' + , 'Streams AQ: qmn slave idle wait' + , 'Streams AQ: qmn slave idle wait or cleanup tasks' + , 'Streams AQ: waiting for time management or cleanup tasks' + , 'VKRM Idle' + , 'VKTM Logical Idle Wait' + , 'DIAG idle wait') + and sw.seconds_in_wait > 0 + and sw.inst_id = s.inst_id + and sw.sid = s.sid + and s.inst_id = sa.inst_id + and s.sql_address = sa.address +order by sw.seconds_in_wait desc +/ + +ttitle "Event Description" skip 2 + +column event format a40 +column p1text format a18 +column p2text format a18 +column p3text format a18 + +select distinct sw.event + , sw.p1text + , sw.p2text + , sw.p3text + from gv$session_wait sw, gv$session s + where sw.event not in + ('rdbms ipc message' + , 'smon timer' + , 'pmon timer' + , 'SQL*Net message from client' + , 'lock manager wait for remote message' + , 'ges remote message' + , 'client message' + , 'pipe get' + , 'Null event' + , 'PX Idle Wait' + , 'single-task message' + , 'PX Deq: Execution Msg' + , 'KXFQ: kxfqdeq - normal deqeue' + , 'listen endpoint status' + , 'slave wait' + , 'wakeup time manager' + , 'jobq slave wait' + , 'Space Manager: slave idle wait' + , 'Streams AQ: qmn coordinator idle wait' + , 'Streams AQ: qmn slave idle wait' + , 'Streams AQ: qmn slave idle wait or cleanup tasks' + , 'Streams AQ: waiting for time management or cleanup tasks' + , 'VKRM Idle' + , 'VKTM Logical Idle Wait' + , 'DIAG idle wait') + and sw.seconds_in_wait > 0 + and ( sw.inst_id = s.inst_id + and sw.sid = s.sid) +order by event +/ \ No newline at end of file diff --git a/wait_get_name.sql b/wait_get_name.sql new file mode 100644 index 0000000..b979ff8 --- /dev/null +++ b/wait_get_name.sql @@ -0,0 +1,28 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the name of a wait statistic +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define SYSSTAT_NAME = &1 + +prompt +prompt Parameter 1 = SYSSTAT_NAME => &&SYSSTAT_NAME. +prompt + + +------------------------------------------------------------ +ttitle 'Search after all waits statistics with this name &&SYSSTAT_NAME.' skip 2 + + +select statistic# + , name + , class + from v$statname +where name like '&&SYSSTAT_NAME.%' +order by 2 +/ + + +ttitle off diff --git a/wait_text.sql b/wait_text.sql new file mode 100644 index 0000000..7c67111 --- /dev/null +++ b/wait_text.sql @@ -0,0 +1,25 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: text to a wait event - parameter 1 part of the event name +--============================================================================== +-- http://alexzeng.wordpress.com/2013/07/16/enqueue-waits-in-oracle-database-10g/ +--============================================================================== +set verify off +set linesize 130 pagesize 300 + +define WAITNAME='&1' + +prompt +prompt Parameter 1 = WAITNAME => &&WAITNAME. +prompt + +column KSQSTRSN format a30 +column KSQSTEXPL format a50 + +select KSQSTTYP + , KSQSTRSN + , KSQSTEXPL + from X$KSQST +where upper(KSQSTRSN) like upper('%'||'&&WAITNAME'||'%') +/ + diff --git a/wallet.sql b/wallet.sql new file mode 100644 index 0000000..57ebb78 --- /dev/null +++ b/wallet.sql @@ -0,0 +1,84 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the Wallet Settings of the DB +-- +-- Must be run with dba privileges +-- Source see Step by Step Troubleshooting Guide for TDE Error ORA-28374 (Doc ID 1541818.1) +--============================================================================== +set linesize 130 pagesize 300 + +ttitle left "The Path to the Wallet" skip 2 + + +column WRL_TYPE format a10 heading "WRL|Type" +column WRL_PARAMETER format a20 heading "Wallet|Params" +column STATUS format a10 heading "Status" +column WALLET_TYPE format a10 heading "Wallet|type" +column WALLET_ORDER format a9 heading "Status" +column FULLY_BACKED_UP format a9 heading "Backup" +column CON_ID format 999 heading "Con|ID" +column inst_id format 999 heading "Inst|ID" + + +select inst_id + , WRL_TYPE + ,WRL_PARAMETER + ,STATUS + ,WALLET_TYPE + ,WALLET_ORDER + ,FULLY_BACKED_UP + ,CON_ID +from gv$encryption_wallet +/ + + +ttitle left "Get the Master Keys " skip 2 +column key_id format a60 +select key_id + ,to_char(activation_time,'dd.mm.yyyy hh24:mi') as activation_time + from v$encryption_keys +/ + + +column name format a40 +column masterkeyid_base64 format a60 + +ttitle left "Get the Master Key for Tablespaces" skip 2 + +select name + ,utl_raw.cast_to_varchar2( utl_encode.base64_encode('01'||substr(mkeyid,1,4))) || utl_raw.cast_to_varchar2( utl_encode.base64_encode(substr(mkeyid,5,length(mkeyid)))) masterkeyid_base64 + FROM (select t.name, RAWTOHEX(x.mkid) mkeyid + from v$tablespace t + , x$kcbtek x + where t.ts#=x.ts#) +/ + + +ttitle left "Get the Master Key for the Controlfile" skip 2 + +select utl_raw.cast_to_varchar2( utl_encode.base64_encode('01'||substr(mkeyid,1,4))) || utl_raw.cast_to_varchar2( utl_encode.base64_encode(substr(mkeyid,5,length(mkeyid)))) masterkeyid_base64 + FROM (select RAWTOHEX(mkid) mkeyid + from x$kcbdbk) +/ + + +ttitle left "Get the Master Key for Tables" skip 2 + +select mkeyid from enc$; + + +ttitle left "Witch Columns are encrypted?" skip 2 + +column owner format a15 heading "Owner" +column table_name format a15 heading "Table|Name" +column column_name format a15 heading "Column|Name" +column ENCRYPTION_ALG format a35 heading "Encryption|Algo" + +select owner + ,table_name + ,column_name + ,ENCRYPTION_ALG +from dba_encrypted_columns +/ + +ttitle off \ No newline at end of file diff --git a/xmldb.sql b/xmldb.sql new file mode 100644 index 0000000..7a8a2f4 --- /dev/null +++ b/xmldb.sql @@ -0,0 +1,15 @@ +--============================================================================== +-- GPI - Gunther Pippèrr +-- Desc: get the xml DB Configuration +-- Date: November 2013 +--============================================================================== +set linesize 130 pagesize 4000 + +ttitle "XML DB Configuration" SKIP 2 + +set long 100000 + +select dbms_xdb.cfg_get from dual +/ + +ttitle off