您好,登錄后才能下訂單哦!
Oracle12.2版本之前,對表做move操作時會對表加exclusive鎖,表上無法執行DML操作。雖然move操作有ONLINE子句,但只適用于IOT表,不適用于堆表。這就意味著在對表做move操作時,無法執行任何DML操作,如果對關鍵表做move操作時只能停業務來完成。到了Oracle12.2版本,推出了一個新特性----在線move表,對于普通堆表可以在move過程中執行DML操作。
下面以11.2.0.4和12.2.0.1這兩個版本為對比,觀察這一新特性。
1、11.2.0.4版本的move操作
--創建測試表 zx@ORA11G>create table t as select * from dba_objects; Table created. Elapsed: 00:00:00.26 zx@ORA11G>insert into t select * from t; 79608 rows created. Elapsed: 00:00:00.22 zx@ORA11G>/ 159216 rows created. Elapsed: 00:00:00.38 zx@ORA11G>/ 318432 rows created. Elapsed: 00:00:03.63 zx@ORA11G>/ 636864 rows created. Elapsed: 00:00:05.40 zx@ORA11G>/ 1273728 rows created. Elapsed: 00:00:24.57 zx@ORA11G>select bytes/1024/1024 from user_segments; BYTES/1024/1024 --------------- 392 Elapsed: 00:00:00.07 zx@ORA11G>commit; Commit complete. Elapsed: 00:00:00.01 zx@ORA11G>alter system flush buffer_cache; System altered. Elapsed: 00:00:27.90 --不做move操作時delete操作時間 zx@ORA11G>delete from t where object_name='T'; 32 rows deleted. Elapsed: 00:00:00.13 zx@ORA11G>rollback; Rollback complete. --執行move --session 1 zx@ORA11G>select userenv('sid') from dual; USERENV('SID') -------------- 1150 --session 2 zx@ORA11G>select userenv('sid') from dual; USERENV('SID') -------------- 15 --session 1 zx@ORA11G>alter table t move tablespace examples; Table altered. Elapsed: 00:00:02.45 --session 2 zx@ORA11G>delete from t where object_name='T'; 32 rows deleted. Elapsed: 00:00:02.18 zx@ORA11G>rollback; Rollback complete. --session 3 sys@ORA11G>select /*+ rule */ sid,lmode,request,type,block from v$lock where sid in (1150,15); SID LMODE REQUEST TY BLOCK ---------- ---------- ---------- -- ---------- 1150 6 0 TM 1 1150 4 0 AE 0 1150 6 0 TS 0 1150 6 0 TX 0 1150 2 0 XR 0 15 4 0 AE 0 15 0 3 TM 0 7 rows selected
從上面的查詢中可以看出表move操作阻塞了delete操作。
2、下面來看12.2版本的在線move操作,需要添加online關鍵字。
--創建測試表 zx@ORA12C>select segment_name,bytes/1024/1024 from user_segments; SEGMENT_NAME BYTES/1024/1024 ------------------------------ --------------- T 392 --在沒有move時delete操作時間 zx@ORA12C>delete from t where object_name='USER_TABLES'; 256 rows deleted. Elapsed: 00:00:00.44 zx@ORA12C>rollback; Rollback complete. --session 1 zx@ORA12C>select userenv('sid') from dual; USERENV('SID') -------------- 23 --session 2 zx@ORA12C>select userenv('sid') from dual; USERENV('SID') -------------- 27 --執行move操作 --session 1 zx@ORA12C>alter table t move online tablespace examples; Table altered. Elapsed: 00:00:34.73 --session 2 zx@ORA12C>delete from t where object_name='USER_TABLES'; 256 rows deleted. Elapsed: 00:00:00.97 zx@ORA12C>rollback; Rollback complete. --session 3 sys@ORA12C>select /*+ rule */ sid,lmode,request,type,block from v$lock where sid in (23,27); SID LMODE REQUEST TY BLOCK ---------- ---------- ---------- -- ---------- 27 3 0 TM 0 27 4 0 AE 0 27 6 0 TX 0 23 4 0 AE 0 23 6 0 OD 0 23 3 0 DL 0 23 3 0 DL 0 23 6 0 TS 0 23 6 0 TM 0 23 4 0 TM 0 23 6 0 TM 0 23 3 0 TM 0 23 6 0 TX 0 23 6 0 TX 0 23 3 0 TM 0 23 3 0 TM 0 16 rows selected.
從上面的操作可以看出12.2的move操作沒有阻塞delete操作。
參考:http://docs.oracle.com/database/122/NEWFT/new-features.htm#GUID-BEEEA34D-3D81-4360-887C-A92BC711816D
免責聲明:本站發布的內容(圖片、視頻和文字)以原創、轉載和分享為主,文章觀點不代表本網站立場,如果涉及侵權請聯系站長郵箱:is@yisu.com進行舉報,并提供相關證據,一經查實,將立刻刪除涉嫌侵權內容。