|
| 1 | +#!/bin/bash |
| 2 | + |
| 3 | +. ~/.bash_profile |
| 4 | + |
| 5 | +sqlplus -s / as sysdba <<EOF |
| 6 | +SET LINES 1000 |
| 7 | +SET PAGES 0 |
| 8 | +WHENEVER SQLERROR EXIT FAILURE |
| 9 | +
|
| 10 | +GRANT EXECUTE ON dbms_shared_pool TO delius_user_support; |
| 11 | +
|
| 12 | +GRANT SELECT ON sys.v_\$sqlarea TO delius_user_support; |
| 13 | +
|
| 14 | +GRANT SELECT ON sys.v_\$sql_shared_cursor TO delius_user_support; |
| 15 | +
|
| 16 | +SET SERVEROUT ON |
| 17 | +
|
| 18 | +DECLARE |
| 19 | + l_owner CONSTANT VARCHAR2(128) := 'DELIUS_USER_SUPPORT'; |
| 20 | + l_program_name CONSTANT VARCHAR2(128) := 'MV_REFRESH_PURGE_CHILD_CURSORS'; |
| 21 | + l_job_name CONSTANT VARCHAR2(128) := l_program_name || '_JOB'; |
| 22 | +BEGIN |
| 23 | +
|
| 24 | + FOR x IN (SELECT job_name |
| 25 | + FROM dba_scheduler_jobs |
| 26 | + WHERE owner = l_owner |
| 27 | + AND job_name = l_job_name ) |
| 28 | + LOOP |
| 29 | + DBMS_SCHEDULER.drop_job( |
| 30 | + job_name => l_owner || '.' || l_job_name |
| 31 | + ); |
| 32 | + END LOOP; |
| 33 | +
|
| 34 | + FOR x IN (SELECT program_name |
| 35 | + FROM dba_scheduler_programs |
| 36 | + WHERE owner = l_owner |
| 37 | + AND program_name = l_program_name ) |
| 38 | + LOOP |
| 39 | + DBMS_SCHEDULER.drop_program( |
| 40 | + program_name => l_owner || '.' || l_program_name |
| 41 | + ); |
| 42 | + END LOOP; |
| 43 | +
|
| 44 | + DBMS_SCHEDULER.create_program ( |
| 45 | + program_name => l_owner || '.' || l_program_name |
| 46 | + ,program_type => 'PLSQL_BLOCK' |
| 47 | + ,program_action => q'{ |
| 48 | +DECLARE |
| 49 | + l_count INTEGER := 0; |
| 50 | + l_sharable_mem INTEGER := 0; |
| 51 | +BEGIN |
| 52 | + /* |
| 53 | + We identify cursors to purge by the following criteria: |
| 54 | + 1. They contain an MV_REFRESH comment, and |
| 55 | + 2. They are not sharable due to the use of Flashback, and |
| 56 | + 3. They have a child version count above 5 |
| 57 | + */ |
| 58 | + FOR x IN ( |
| 59 | + SELECT |
| 60 | + sql_id, |
| 61 | + address, |
| 62 | + hash_value, |
| 63 | + sharable_mem, |
| 64 | + version_count |
| 65 | + FROM |
| 66 | + v\$sqlarea s |
| 67 | + WHERE |
| 68 | + upper(s.sql_text) LIKE '/* MV_REFRESH (MRG) */%' |
| 69 | + AND s.version_count > 5 |
| 70 | + AND EXISTS ( |
| 71 | + SELECT |
| 72 | + 1 |
| 73 | + FROM |
| 74 | + v\$sql_shared_cursor c |
| 75 | + WHERE |
| 76 | + c.sql_id = s.sql_id |
| 77 | + AND c.flashback_cursor = 'Y' |
| 78 | + ) |
| 79 | + ) LOOP |
| 80 | + sys.DBMS_SHARED_POOL.purge(x.address|| ','|| x.hash_value, 'C'); |
| 81 | +
|
| 82 | + l_count := l_count + x.version_count; |
| 83 | + l_sharable_mem := l_sharable_mem + x.sharable_mem; |
| 84 | + END LOOP; |
| 85 | +
|
| 86 | + DBMS_OUTPUT.put_line('Purged ' |
| 87 | + || l_count |
| 88 | + || ' unsharable cursors and released ' |
| 89 | + || round(l_sharable_mem / 1024 / 1024, 2) |
| 90 | + || 'Mb of memory.'); |
| 91 | +
|
| 92 | +END; |
| 93 | +}' |
| 94 | + ,enabled => TRUE |
| 95 | + ,comments => 'See '||l_job_name||' comments.'); |
| 96 | +
|
| 97 | + DBMS_SCHEDULER.create_job( |
| 98 | + job_name => l_owner || '.' || l_job_name |
| 99 | + ,program_name => l_owner || '.' || l_program_name |
| 100 | + ,start_date => SYSTIMESTAMP |
| 101 | + ,repeat_interval => 'FREQ=HOURLY;' |
| 102 | + ,end_date => NULL |
| 103 | + ,comments => 'Materialized View refresh cursors are not sharable as they use flashback query. '|| |
| 104 | + 'This means that regular MV refreshes will gradually consume a large amount of '|| |
| 105 | + 'shared pool memory but will never be reused. This job detects such cursors and '|| |
| 106 | + 'purges them to ensure this memory may be reallocated to other components.' |
| 107 | + ,enabled => TRUE); |
| 108 | +
|
| 109 | +END; |
| 110 | +/ |
| 111 | +
|
| 112 | +EXIT |
| 113 | +EOF |
0 commit comments