Another new feature of 23ai is the ability to rename a LOB (Segment) in-place without having to use the MOVE clause.
A quick demo :
SQL> -- Version 23ai Free Edition SQL> select banner from v$version; BANNER --------------------------------------------------------------------------------------------------------------------------------- Oracle Database 23ai Free Release 23.0.0.0.0 - Develop, Learn, and Run for Free SQL> SQL> SQL> DROP TABLE my_lob_objects purge; Table dropped. SQL> SQL> -- create the table with a LOB, column name "c", lob segment name also "c" SQL> CREATE TABLE my_lob_objects (object_id NUMBER primary key, c CLOB) 2 lob (c) STORE AS SECUREFILE c 3 ( TABLESPACE users 4 DISABLE STORAGE IN ROW 5 NOCACHE LOGGING 6 RETENTION AUTO 7 COMPRESS 8 ); Table created. SQL> SQL> -- query the data dictionary SQL> select table_name, column_name, segment_name, tablespace_name from user_lobs; TABLE_NAME COLUMN_NAME SEGMENT_NAME TABLESPACE_NAME ---------------- ---------------- -------------------- ---------------- MY_LOB_OBJECTS C C USERS SQL> SQL> -- insert three rows SQL> insert into my_lob_objects values (1, dbms_random.string('X',100)); 1 row created. SQL> insert into my_lob_objects values (2, dbms_random.string('X',100)); 1 row created. SQL> insert into my_lob_objects values (3, dbms_random.string('X',100)); 1 row created. SQL> SQL> -- verify the column name when querying the table SQL> select * from my_lob_objects; OBJECT_ID C ---------- -------------------------------------------------------------------------------- 1 IBGOGKA9QKK56O746IJL3C56ZK9LEO0G1W4LWBN11T8EWCFTTLUW9TPIVQAU8BPSGPQ2ZV57BS0ZPK0S 2 7K04DVVYDQB1URIQ1OQ2458M8ZOURHWW50XIZDMVGAZH6XVN2KKN4PIGKPY5CSVIQ9KU45LHZPJB33AA 3 2G5194Z7TSR3XG0K698G587AOZOJ8VN6KFCTCH3074TNCOWCSMOPRJLRGTLIZMDD73XAY4KDD14IW4MG SQL> SQL> -- now rename the column SQL> alter table my_lob_objects rename column c to clob_col; Table altered. SQL> SQL> -- query the data dictionary SQL> select table_name, column_name, segment_name, tablespace_name from user_lobs; TABLE_NAME COLUMN_NAME SEGMENT_NAME TABLESPACE_NAME ---------------- ---------------- -------------------- ---------------- MY_LOB_OBJECTS CLOB_COL C USERS SQL> SQL> -- now rename the lob segment SQL> alter table my_lob_objects rename lob(clob_col) c to my_lob_objects_clob; Table altered. SQL> SQL> -- query the data dictionary SQL> select table_name, column_name, segment_name, tablespace_name from user_lobs; TABLE_NAME COLUMN_NAME SEGMENT_NAME TABLESPACE_NAME ---------------- ---------------- -------------------- ---------------- MY_LOB_OBJECTS CLOB_COL MY_LOB_OBJECTS_CLOB USERS SQL> SQL> -- verify the column name when querying the table SQL> select * from my_lob_objects; OBJECT_ID CLOB_COL ---------- -------------------------------------------------------------------------------- 1 IBGOGKA9QKK56O746IJL3C56ZK9LEO0G1W4LWBN11T8EWCFTTLUW9TPIVQAU8BPSGPQ2ZV57BS0ZPK0S 2 7K04DVVYDQB1URIQ1OQ2458M8ZOURHWW50XIZDMVGAZH6XVN2KKN4PIGKPY5CSVIQ9KU45LHZPJB33AA 3 2G5194Z7TSR3XG0K698G587AOZOJ8VN6KFCTCH3074TNCOWCSMOPRJLRGTLIZMDD73XAY4KDD14IW4MG SQL> SQL> -- identify the segment SQL> select tablespace_name, segment_name, segment_type, bytes/1024 Size_KB 2 from user_segments 3 where segment_name = 'MY_LOB_OBJECTS_CLOB' 4 / TABLESPACE_NAME SEGMENT_NAME SEGMENT_TYPE SIZE_KB ---------------- -------------------- ------------------ --------- USERS MY_LOB_OBJECTS_CLOB LOBSEGMENT 2304 SQL>
First I create a Table where the Column and LOB (Segment) are both called "C". In recent versions, SECUREFILE is the default and recommended for LOBs (e.g. with the COMPRESS, DEDUPLICATION and ENCRYPTION advantages).
Then I insert 3 rows.
I then rename the column "C" to "CLOB_COL".
Next, I rename the LOB (Segment) to "MY_LOB_OBJECTS_CLOB". I include the Table Name because the LOB segment is an independent segment that I might query in USER_SEGMENTS (where Table Name) is not available. This RENAME LOB clause is new in 23ai and does not require the use of MOVE LOB.
I then verify the new Segment Name for the LOB as well.
Yes, the 2,304KB "size" seems excessive but this will make sense (with the COMPRESS attribute) when the LOB grows much much larger as new rows with long Character-Strings are inserted.
No comments:
Post a Comment