Skip to content

Commit

Permalink
home sync
Browse files Browse the repository at this point in the history
  • Loading branch information
xtender committed Jul 14, 2020
1 parent d2077d5 commit cab7132
Show file tree
Hide file tree
Showing 12 changed files with 182 additions and 26 deletions.
2 changes: 1 addition & 1 deletion ddl_simple.sql
Original file line number Diff line number Diff line change
Expand Up @@ -49,7 +49,7 @@ prompt dbms_metadata.get_ddl for &_type &_owner..&_object....
set timing off ver off feed off head off lines 10000 pagesize 0 newpage none
exec DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM,'PRETTY',false);
-------------- Spooling ------------------
@inc/ddl.inc &_OWNER &_OBJECT
@inc/ddl.inc &_OWNER &_OBJECT &_type
-------------- End Spooling ------------------
undef _OWNER;
undef _OBJECT;
Expand Down
35 changes: 19 additions & 16 deletions error_logging/on_database.sql
Original file line number Diff line number Diff line change
Expand Up @@ -22,23 +22,26 @@ declare
sql_text dbms_standard.ora_name_list_t;
v_sql_text clob;
begin
v_sql_text:=null;
n := ora_sql_txt(sql_text);
for i in 1..n loop
v_sql_text := v_sql_text || sql_text(i);
end loop;
-- only if plsql_debug is set to TRUE:
for r in (select * from v$parameter p where p.name='plsql_debug' and upper(p.value)='TRUE') loop
v_sql_text:=null;
n := ora_sql_txt(sql_text);
for i in 1..n loop
v_sql_text := v_sql_text || sql_text(i);
end loop;

for i in 1.. ora_server_error_depth
loop
if i=1 then
insert into error_log(id,seq,tmstmp,username,errcode,msg,sql_text)
values( v_id, i, v_tmstmp, user, ora_server_error(i), ora_server_error_msg(i), v_sql_text);
else
insert into error_log(id,seq,tmstmp,username,errcode,msg)
values( v_id, i, v_tmstmp, user, ora_server_error(i), ora_server_error_msg(i) );
end if;
end loop;
commit;
for i in 1.. ora_server_error_depth
loop
if i=1 then
insert into error_log(id,seq,tmstmp,username,errcode,msg,sql_text)
values( v_id, i, v_tmstmp, user, ora_server_error(i), ora_server_error_msg(i), v_sql_text);
else
insert into error_log(id,seq,tmstmp,username,errcode,msg)
values( v_id, i, v_tmstmp, user, ora_server_error(i), ora_server_error_msg(i) );
end if;
end loop;
commit;
end loop;
END;
/
select object_name,object_type,status from user_objects o where object_name='TRG_ERROR_LOGGING'
Expand Down
7 changes: 5 additions & 2 deletions events/snap_histograms.sql
Original file line number Diff line number Diff line change
Expand Up @@ -78,8 +78,11 @@ begin
100*sum(nvl(v2.WAIT_COUNT,0)-nvl(v1.WAIT_COUNT,0))
over(partition by nvl(v2.EVENT , v1.EVENT )
order by nvl(v2.WAIT_TIME_MILLI , v1.WAIT_TIME_MILLI))
/sum(nvl(v2.WAIT_COUNT,0)-nvl(v1.WAIT_COUNT,0))
over(partition by nvl(v2.EVENT , v1.EVENT )))
/nullif(
sum(nvl(v2.WAIT_COUNT,0)-nvl(v1.WAIT_COUNT,0))
over(partition by nvl(v2.EVENT , v1.EVENT ))
,0)
)
as "running_total(%)"
,nvl(v2.LAST_UPDATE_TIME, v1.LAST_UPDATE_TIME) LAST_UPDATE_TIME
from v1
Expand Down
43 changes: 43 additions & 0 deletions jobs/check_scheduler.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
col param for a25;
col value for a80;

with
function get_scheduler_attribute(param in varchar2) return varchar2 is
res varchar2(100);
begin
dbms_scheduler.get_scheduler_attribute(param,res);
return res;
end;
current_values(param,value,status) as (
select 'SCHEDULER_DISABLED'
,nvl(get_scheduler_attribute('SCHEDULER_DISABLED'),'FALSE')
,case when nvl(upper(get_scheduler_attribute('SCHEDULER_DISABLED')),'FALSE')='FALSE' then 'ok'
else 'error'
end
from dual
union all
select name
,value
,case when value>0 then 'ok' else 'error' end
from v$parameter where name like 'job_queue_processes'
union all
select 'last_start_date'
,to_char(max(j.last_start_date),'yyyy-mm-dd hh24:mi:ss')
,case when max(j.last_start_date)>sysdate-interval'5' minute then 'ok' else 'error' end
from all_scheduler_jobs j
where j.owner='TMDDBA'
and job_name like 'DR$%'
union all
select index_name
,status||'/'||i.DOMIDX_STATUS||'/'||i.domidx_opstatus
,'error'
from all_indexes i
where owner='TMDDBA'
and index_type='DOMAIN'
and (status!='VALID'
or domidx_status!='VALID'
or domidx_opstatus!='VALID')
)
select *
from current_values
/
43 changes: 43 additions & 0 deletions jobs/sched_check.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
col param for a25;
col value for a80;

with
function get_scheduler_attribute(param in varchar2) return varchar2 is
res varchar2(100);
begin
dbms_scheduler.get_scheduler_attribute(param,res);
return res;
end;
current_values(param,value,status) as (
select 'SCHEDULER_DISABLED'
,nvl(get_scheduler_attribute('SCHEDULER_DISABLED'),'FALSE')
,case when nvl(upper(get_scheduler_attribute('SCHEDULER_DISABLED')),'FALSE')='FALSE' then 'ok'
else 'error'
end
from dual
union all
select name
,value
,case when value>0 then 'ok' else 'error' end
from v$parameter where name like 'job_queue_processes'
union all
select 'last_start_date'
,to_char(max(j.last_start_date),'yyyy-mm-dd hh24:mi:ss')
,case when max(j.last_start_date)>sysdate-interval'5' minute then 'ok' else 'error' end
from all_scheduler_jobs j
where j.owner='TMDDBA'
and job_name like 'DR$%'
union all
select index_name
,status||'/'||i.DOMIDX_STATUS||'/'||i.domidx_opstatus
,'error'
from all_indexes i
where owner='TMDDBA'
and index_type='DOMAIN'
and (status!='VALID'
or domidx_status!='VALID'
or domidx_opstatus!='VALID')
)
select *
from current_values
/
1 change: 1 addition & 0 deletions jobs/sched_disable.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
exec dbms_scheduler.set_scheduler_attribute('SCHEDULER_DISABLED','TRUE');
1 change: 1 addition & 0 deletions jobs/sched_enable.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
exec dbms_scheduler.set_scheduler_attribute('SCHEDULER_DISABLED','FALSE');
18 changes: 18 additions & 0 deletions jobs/sched_jobs.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
col owner format a30;
col "JOB_NAME/SUBNAME" format a40;
col last_start_date format a45;
col last_run_duration format a16;
col next_run_date format a45;

-------------------- ------------------------------ ------------------------------ --------------------------------- --------------- ---------- ---------- ------ ---------------- ----------------- -
select
jr.OWNER
,jr.JOB_NAME||nvl2(jr.JOB_SUBNAME,'('||jr.JOB_SUBNAME||')','') "JOB_NAME/SUBNAME"
,last_start_date
,cast(last_run_duration AS INTERVAL DAY(1) TO SECOND(3)) as last_run_duration
,next_run_date
from dba_scheduler_jobs jr
where 1=1
;
col owner clear;
col "JOB_NAME/SUBNAME" clear;
13 changes: 8 additions & 5 deletions ls.sql
Original file line number Diff line number Diff line change
@@ -1,30 +1,33 @@
set serverout on;

accept _dir_name prompt "Directory name: ";
accept _f_mask prompt "File mask: ";
accept _max_files prompt "Max number of files to output[100] :" default 100;
declare
PROCEDURE LIST_FILES (lp_string IN VARCHAR2 default null)
PROCEDURE LIST_FILES (dir_name in varchar2, file_mask IN VARCHAR2 default null, max_files in number default 100)
AS
lv_pattern VARCHAR2(1024);
lv_ns VARCHAR2(1024);
BEGIN
SELECT directory_path
INTO lv_pattern
FROM dba_directories
WHERE directory_name = '&1';
WHERE directory_name LIKE list_files.dir_name;

SYS.DBMS_BACKUP_RESTORE.SEARCHFILES(lv_pattern, lv_ns);

FOR file_list IN (
SELECT FNAME_KRBMSFT AS file_name
FROM sys.X$KRBMSFT
WHERE FNAME_KRBMSFT LIKE '%'|| lp_string||'%'
WHERE FNAME_KRBMSFT LIKE '%'|| file_mask||'%'
and rownum< max_files
)
LOOP
dbms_output.put_line(file_list.file_name);
END LOOP;

END;
begin
list_files('');
list_files('&_dir_name', '&_f_mask', &_max_files);
end;
/
set serverout off
38 changes: 38 additions & 0 deletions ls2.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,38 @@
--set serverout on;
accept _dir_name prompt "Directory name: ";
accept _f_mask prompt "File mask: ";
accept _max_files prompt "Max number of files to output[100] :" default 100;
declare
PROCEDURE LIST_FILES (dir_name in varchar2, file_mask IN VARCHAR2 default null, max_files in number default 100)
AS
lv_pattern VARCHAR2(1024);
lv_ns VARCHAR2(1024);
BEGIN
SELECT directory_path
INTO lv_pattern
FROM dba_directories
WHERE directory_name LIKE list_files.dir_name;

SYS.DBMS_BACKUP_RESTORE.SEARCHFILES(lv_pattern, lv_ns);

FOR file_list IN (
)
LOOP
dbms_output.put_line(file_list.file_name);
END LOOP;

END;
begin
list_files('&_dir_name', '&_f_mask', &_max_files);
end;
/
--set serverout off

SELECT FNAME_KRBMSFT AS file_name
FROM sys.X$KRBMSFT
WHERE FNAME_KRBMSFT LIKE '%&_f_mask%'
and rownum< &_max_files;

SELECT count(*) cnt
FROM sys.X$KRBMSFT
WHERE FNAME_KRBMSFT LIKE '%&_f_mask%';
4 changes: 2 additions & 2 deletions server/cpu_util.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
col begin_time for a19;
col end_time for a8;
col sec for 999.00;
col_metric_name for a28;
col metric_name for a28;
col value for 9999999.00;
select to_char(begin_time,'yyyy-mm-dd hh24:mi:ss') begin_time
,to_char(end_time,'hh24:mi:ss') end_time
Expand All @@ -14,5 +14,5 @@ where metric_name like '%CPU%';
col begin_time clear;
col end_time clear;
col sec clear;
col_metric_name clear;
col metric_name clear;
col value clear;
3 changes: 3 additions & 0 deletions server/log_files_all.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
col MEMBER for a45;
select * from v$logfile order by group#,member;
col MEMBER clear;

0 comments on commit cab7132

Please sign in to comment.