Files
mip/Data/BulkLoad/EFT/Nominations/plsql/run_stats.bdy

100 lines
3.5 KiB
Plaintext

CREATE OR REPLACE PACKAGE BODY EFT_NOM.run_stats IS
g_header CONSTANT VARCHAR2(160) := '$Header: /Isle Of Grain/database/PLSQL/run_stats.pck 1 7/01/05 12:54 Gilberta $';
g_revision CONSTANT VARCHAR2(160) := '$Revision: 1 $';
g_max_run_time_seconds NUMBER := 60 * 100;
g_interval NUMBER := 1 / (24 * 60);
PROCEDURE gather_table_stats(p_table_name IN VARCHAR2) IS
BEGIN
dbms_stats.gather_table_stats(ownname => USER
,tabname => p_table_name
,method_opt => 'FOR ALL INDEXED COLUMNS'
,granularity => 'ALL'
,cascade => TRUE);
EXECUTE IMMEDIATE 'ALTER TABLE ' || USER || '.' || p_table_name ||
' MONITORING';
END;
PROCEDURE gather_table_stats(p_tables_processed OUT NUMBER) IS
v_start_time NUMBER := dbms_utility.get_time;
v_tables_processed NUMBER := 0;
BEGIN
FOR v_table IN (SELECT rownum
,table_name
FROM user_tables
WHERE monitoring <> 'YES'
AND temporary = 'N'
AND table_name NOT IN ('CG_REF_CODES')) LOOP
gather_table_stats(p_table_name => v_table.table_name);
v_tables_processed := v_table.rownum;
EXIT WHEN v_start_time + g_max_run_time_seconds < dbms_utility.get_time;
END LOOP;
p_tables_processed := v_tables_processed;
END;
PROCEDURE setup_stats IS
v_job_no NUMBER;
v_tables_processed NUMBER;
BEGIN
IF USER = 'SYS' THEN
dbms_output.put_line('Do not try to analyze SYS');
dbms_stats.delete_schema_stats(ownname => 'SYS');
ELSE
gather_table_stats(v_tables_processed);
dbms_stats.delete_table_stats(ownname => USER
,tabname => 'CG_REF_CODES');
FOR v_existing IN (SELECT job
FROM user_jobs
WHERE what LIKE '%run_stats.refresh_stats%') LOOP
dbms_job.remove(job => v_existing.job);
END LOOP;
dbms_job.submit(job => v_job_no
,what => 'begin run_stats.refresh_stats(p_job_no => job, p_next_date => next_date);end;'
,next_date => SYSDATE);
dbms_output.put_line('Created job ' || v_job_no);
END IF;
END setup_stats;
PROCEDURE refresh_stats(p_job_no IN BINARY_INTEGER
,p_next_date IN OUT DATE) IS
v_tables_processed NUMBER;
BEGIN
IF USER = 'SYS' THEN
dbms_output.put_line('Do not try to analyze SYS');
dbms_stats.delete_schema_stats(ownname => 'SYS');
ELSE
gather_table_stats(v_tables_processed);
IF v_tables_processed = 0 THEN
p_next_date := trunc(SYSDATE) + 1;
ELSE
p_next_date := SYSDATE + g_interval;
END IF;
dbms_stats.gather_schema_stats(ownname => USER
,cascade => TRUE
,options => 'gather empty');
dbms_stats.gather_schema_stats(ownname => USER
,cascade => TRUE
,options => 'gather stale');
dbms_stats.delete_table_stats(ownname => USER
,tabname => 'CG_REF_CODES');
END IF;
END;
BEGIN
-- Initialization
NULL;
END run_stats;
/