|
| 1 | +/* |
| 2 | +truncate table t_sql_stats drop storage; |
| 3 | +truncate table t_session_stats drop storage; |
| 4 | +truncate table t_session_events drop storage; |
| 5 | +*/ |
| 6 | + |
| 7 | +---------------------------------------------------------------------------------------------------- |
| 8 | + |
| 9 | +declare |
| 10 | + c_run_id_list constant sys.ora_mining_number_nt := sys.ora_mining_number_nt(10, 11, 12, 13, 20, 21, 22, 23, 30, 31, 32, 33, 40, 41, 42, 43, 44); |
| 11 | + l_run_ix pls_integer; |
| 12 | + |
| 13 | + c_show_xplan constant boolean := false; |
| 14 | + c_gather_sql_stats constant boolean := false; |
| 15 | + c_gather_session_stats constant boolean := true; |
| 16 | + c_gather_session_events constant boolean := true; |
| 17 | + |
| 18 | + c_rows_to_insert_sqrt constant integer := 1000; |
| 19 | + c_rows_to_delete constant integer := c_rows_to_insert_sqrt * c_rows_to_insert_sqrt / 3; |
| 20 | + |
| 21 | + l_sql_id v$session.prev_sql_id%type; |
| 22 | + l_child_no v$session.prev_child_number%type; |
| 23 | + c_run_id integer; |
| 24 | + c_module constant dbms_id := '2023-12-05.mass_delete_bench.'||to_char(sysdate, 'hh24-mi-ss'); |
| 25 | + |
| 26 | + l_session_par_name dbms_sql.varchar2s; |
| 27 | + l_session_par_value dbms_sql.varchar2a; |
| 28 | + |
| 29 | + --============================================================================================-- |
| 30 | + -- note: contents of the following routines are completely up to tester's decision |
| 31 | + |
| 32 | + procedure execute_test_startup |
| 33 | + is |
| 34 | + begin |
| 35 | + execute immediate 'truncate table t_index_test drop storage'; |
| 36 | + |
| 37 | + insert --+ append |
| 38 | + into t_index_test (id, col_1, col_2, col_8, col_32) |
| 39 | + with data$ as ( |
| 40 | + select 1 |
| 41 | + from dual |
| 42 | + connect by level <= c_rows_to_insert_sqrt |
| 43 | + ) |
| 44 | + select rownum, dbms_random.string('x', 1), dbms_random.string('x', 2), dbms_random.string('x', 8), dbms_random.string('x', 32) |
| 45 | + from data$ |
| 46 | + cross join data$ |
| 47 | + ; |
| 48 | + |
| 49 | + dbms_output.put_line('run '||c_run_id||': '||sql%rowcount||' rows inserted'); |
| 50 | + |
| 51 | + commit; |
| 52 | + end; |
| 53 | + |
| 54 | + procedure execute_test |
| 55 | + is |
| 56 | + type arr_integer is table of integer index by pls_integer; |
| 57 | + l_ids arr_integer; |
| 58 | + l_deleted_from integer; |
| 59 | + l_deleted_up_to integer; |
| 60 | + begin |
| 61 | + if c_run_id >= 10 and c_run_id < 20 then |
| 62 | + for i in 1..c_rows_to_delete loop |
| 63 | + delete from t_index_test where id = i; |
| 64 | + end loop; |
| 65 | + dbms_output.put_line('run '||c_run_id||': '||c_rows_to_delete||' rows deleted'); |
| 66 | + commit; |
| 67 | + |
| 68 | + elsif c_run_id >= 20 and c_run_id < 30 then |
| 69 | + l_deleted_from := 1; |
| 70 | + while l_deleted_from <= c_rows_to_delete loop |
| 71 | + l_deleted_up_to := least(l_deleted_from + 10000 - 1, c_rows_to_delete); |
| 72 | + |
| 73 | + l_ids.delete(); |
| 74 | + for i in l_deleted_from..l_deleted_up_to loop |
| 75 | + l_ids(i - l_deleted_from + 1) := i; |
| 76 | + end loop; |
| 77 | + |
| 78 | + forall i in indices of l_ids |
| 79 | + delete from t_index_test where id = l_ids(i); |
| 80 | + |
| 81 | + dbms_output.put_line('run '||c_run_id||': '||sql%rowcount||' rows deleted'); |
| 82 | + |
| 83 | + l_deleted_from := l_deleted_up_to + 1; |
| 84 | + end loop; |
| 85 | + commit; |
| 86 | + |
| 87 | + elsif c_run_id >= 30 and c_run_id < 40 then |
| 88 | + delete from t_index_test where id between 1 and c_rows_to_delete; |
| 89 | + dbms_output.put_line('run '||c_run_id||': '||sql%rowcount||' rows deleted'); |
| 90 | + commit; |
| 91 | + |
| 92 | + elsif c_run_id >= 40 and c_run_id < 50 then |
| 93 | + -- drop whatever you can |
| 94 | + for cv in ( |
| 95 | + select * |
| 96 | + from xmltable('/ROWSET/ROW' |
| 97 | + passing dbms_xmlgen.getXmlType(q'{ |
| 98 | + select partition_name, partition_position, high_value |
| 99 | + from user_tab_partitions |
| 100 | + where table_name = 'T_INDEX_TEST' |
| 101 | + }') |
| 102 | + columns |
| 103 | + partition_name varchar2(128), |
| 104 | + partition_position integer, |
| 105 | + high_value number |
| 106 | + ) X |
| 107 | + where X.high_value < c_rows_to_delete |
| 108 | + order by partition_position |
| 109 | + ) loop |
| 110 | + if cv.partition_position = 1 then |
| 111 | + execute immediate 'alter table t_index_test truncate partition "'||sys.dbms_assert.simple_sql_name(cv.partition_name)||'" drop storage update indexes'; |
| 112 | + dbms_output.put_line('run '||c_run_id||': partition '||cv.partition_name||' truncated'); |
| 113 | + else |
| 114 | + execute immediate 'alter table t_index_test drop partition "'||sys.dbms_assert.simple_sql_name(cv.partition_name)||'" update indexes'; |
| 115 | + dbms_output.put_line('run '||c_run_id||': partition '||cv.partition_name||' dropped'); |
| 116 | + end if; |
| 117 | + end loop; |
| 118 | + |
| 119 | + -- delete the rest |
| 120 | + delete from t_index_test where id between 1 and c_rows_to_delete; |
| 121 | + dbms_output.put_line('run '||c_run_id||': '||sql%rowcount||' rows deleted'); |
| 122 | + commit; |
| 123 | +/* |
| 124 | + if c_gather_sql_stats and i = 1 and l_sql_id is null then |
| 125 | + select prev_sql_id, prev_child_number into l_sql_id, l_child_no from v$session where sid = sys_context('userenv','sid'); |
| 126 | + save_sql_stats_pre(c_run_id, l_sql_id, l_child_no); |
| 127 | + end if; |
| 128 | +*/ |
| 129 | + else |
| 130 | + dbms_output.put_line('run '||c_run_id||': ELSE branch hit!'); |
| 131 | + end if; |
| 132 | + end; |
| 133 | + |
| 134 | + procedure execute_test_teardown |
| 135 | + is |
| 136 | + begin |
| 137 | + rollback; |
| 138 | + execute immediate 'truncate table t_index_test drop storage'; |
| 139 | + end; |
| 140 | + |
| 141 | + --============================================================================================-- |
| 142 | +begin |
| 143 | + rollback; |
| 144 | + select name, value bulk collect into l_session_par_name, l_session_par_value from v$parameter P where name in ('nls_comp','nls_sort'); |
| 145 | + |
| 146 | + if c_run_id_list is not null then |
| 147 | + l_run_ix := c_run_id_list.first(); |
| 148 | + <<iterate_c_run_id_list>> |
| 149 | + while l_run_ix is not null loop |
| 150 | + c_run_id := c_run_id_list(l_run_ix); |
| 151 | + |
| 152 | + ------------------------------------------------------------------------------------------------ |
| 153 | + -- the test startup phase |
| 154 | + |
| 155 | + dbms_application_info.set_module(c_module, 'run.'||c_run_id||'.pre'); |
| 156 | + execute_test_startup(); |
| 157 | + dbms_application_info.set_module(c_module, null); |
| 158 | + |
| 159 | + ------------------------------------------------------------------------------------------------ |
| 160 | + |
| 161 | + if c_show_xplan then |
| 162 | + execute immediate 'alter session set statistics_level = ALL'; |
| 163 | + execute immediate 'alter session set nls_comp = binary'; |
| 164 | + execute immediate 'alter session set nls_sort = binary'; |
| 165 | + end if; |
| 166 | + |
| 167 | + if c_gather_session_events then |
| 168 | + api_bench.save_session_events_pre( |
| 169 | + i_run_id => c_run_id, |
| 170 | + i_session_id => sys_context('userenv', 'sid') |
| 171 | + ); |
| 172 | + end if; |
| 173 | + |
| 174 | + if c_gather_sql_stats and l_sql_id is not null then |
| 175 | + api_bench.save_sql_stats_pre( |
| 176 | + i_run_id => c_run_id, |
| 177 | + i_sql_id => l_sql_id |
| 178 | + ); |
| 179 | + end if; |
| 180 | + |
| 181 | + if c_gather_session_stats then |
| 182 | + api_bench.save_session_stats_pre( |
| 183 | + i_run_id => c_run_id, |
| 184 | + i_session_id => sys_context('userenv', 'sid') |
| 185 | + ); |
| 186 | + end if; |
| 187 | + |
| 188 | + ------------------------------------------------------------------------------------------------ |
| 189 | + |
| 190 | + dbms_application_info.set_module(c_module, 'run.'||c_run_id||'.exe'); |
| 191 | + execute_test(); |
| 192 | + dbms_application_info.set_module(c_module, null); |
| 193 | + |
| 194 | + ------------------------------------------------------------------------------------------------ |
| 195 | + |
| 196 | + if c_show_xplan or c_gather_sql_stats then |
| 197 | + select prev_sql_id, prev_child_number into l_sql_id, l_child_no from v$session where sid = sys_context('userenv','sid'); |
| 198 | + end if; |
| 199 | + |
| 200 | + if c_gather_session_stats then |
| 201 | + api_bench.save_session_stats_post( |
| 202 | + i_run_id => c_run_id, |
| 203 | + i_session_id => sys_context('userenv', 'sid') |
| 204 | + ); |
| 205 | + end if; |
| 206 | + |
| 207 | + if c_gather_sql_stats then |
| 208 | + api_bench.save_sql_stats_post( |
| 209 | + i_run_id => c_run_id, |
| 210 | + i_sql_id => l_sql_id |
| 211 | + ); |
| 212 | + end if; |
| 213 | + |
| 214 | + if c_gather_session_events then |
| 215 | + api_bench.save_session_events_post( |
| 216 | + i_run_id => c_run_id, |
| 217 | + i_session_id => sys_context('userenv', 'sid') |
| 218 | + ); |
| 219 | + end if; |
| 220 | + |
| 221 | + for i in 1..l_session_par_name.count loop |
| 222 | + execute immediate 'alter session set '||l_session_par_name(i)||' = '||l_session_par_value(i); |
| 223 | + end loop; |
| 224 | + |
| 225 | + ------------------------------------------------------------------------------------------------ |
| 226 | + |
| 227 | + dbms_application_info.set_module(c_module, 'run.'||c_run_id||'.post'); |
| 228 | + execute_test_teardown(); |
| 229 | + dbms_application_info.set_module(c_module, null); |
| 230 | + |
| 231 | + ------------------------------------------------------------------------------------------------ |
| 232 | + l_run_ix := c_run_id_list.next(l_run_ix); |
| 233 | + end loop iterate_c_run_id_list; |
| 234 | + end if; |
| 235 | + |
| 236 | + for i in 1..l_session_par_name.count loop |
| 237 | + execute immediate 'alter session set '||l_session_par_name(i)||' = '||l_session_par_value(i); |
| 238 | + end loop; |
| 239 | + |
| 240 | + dbms_application_info.set_module(null, null); |
| 241 | +end; |
| 242 | +/ |
0 commit comments