分类: Oracle
2008-01-25 11:49:20
默认情况下,oracle的分区表对于分区字段是不允许进行update操作的,如果有对分区字段行进update,就会报错——ORA-14402: 更新分区关键字列将导致分区的更改。但是可以通过打开表的row movement属性来允许对分区字段的update操作。 例:创建分区表test_part进行实验 create table TEST_PART ( A1 NUMBERnot null, A2 DATE not null, A3 VARCHAR2(6) not null, A4 DATE not null, A5 NUMBER not null, ) partition by range (A1) ( partition P1 values less than (1000), partition P2 values less than (2000), partition P3 values less than (3000), partition P4 values less than (4000), partition P5 values less than (5000), partition P6 values less than (MAXVALUE) ); 插入如下的数据 SQL> select * from test_part; A1 A2 A3 A4 A5 ---------- ----------- ------ ----------- ---------- 123 2006-06-30 123456 2006-06-30 123 456 2006-06-30 asdfgh 2006-06-30 456 1 2006-06-30 234123 2006-06-30 1 2 2006-06-30 234234 2006-06-30 2 1234 2006-06-30 456789 2006-06-30 1234 1111 2006-06-30 ewrqwe 2006-06-30 1111 2222 2006-06-30 fdafda 2006-06-30 2222 3333 2006-06-30 342342 2006-06-30 3333 5678 2006-06-30 qwerty 2006-06-30 5678 9 rows selected 分区P1、P2的数据分别为: SQL> select rowid,t.* from test_part partition(p1) t; ROWID A1 A2 A3 A4 A5 ------------------ ---------- ----------- ------ ----------- ---------- AAAGLoAAGAAAtsEAAB 456 2006-06-30 asdfgh 2006-06-30 456 AAAGLoAAGAAAtsEAAC 1 2006-06-30 234123 2006-06-30 1 AAAGLoAAGAAAtsEAAD 2 2006-06-30 234234 2006-06-30 2 AAAGLoAAGAAAtsEAAE 123 2006-06-30 123456 2006-06-30 123 SQL> select rowid,t.* from test_part partition(p2) t; ROWID A1 A2 A3 A4 A5 ------------------ ---------- ----------- ------ ----------- ---------- AAAGLwAAGAAA+8MAAC 1234 2006-06-30 456789 2006-06-30 1234 AAAGLwAAGAAA+8MAAD 1111 2006-06-30 ewrqwe 2006-06-30 1111 直接update提示错误 SQL> update test_part set a1=1123 where a1=123; update test_part set a1=1123 where a1=123 ORA-14402: 更新分区关键字列将导致分区的更改 打开row movement属性 SQL> alter table test_part enable row movement; Table altered 再次执行update操作 SQL> update test_part set a1=1123 where a1=123; 1 row updated 执行是成功的并迁移到分区P2上了,且这时候rowid也发生了变化 SQL> select rowid,t.* from test_part partition(p2) t; ROWID A1 A2 A3 A4 A5 ------------------ ---------- ----------- ------ ----------- ---------- AAAGLwAAGAAA+8MAAC 1234 2006-06-30 456789 2006-06-30 1234 AAAGLwAAGAAA+8MAAD 1111 2006-06-30 ewrqwe 2006-06-30 1111 AAAGLwAAGAAA+8PAAB 1123 2006-06-30 123456 2006-06-30 123 SQL> enable row movement可以允许数据段的压缩、update分区字段的数据(跨分区的) 但是,也是有限制性的:对于普通表(heap-organized)行迁移后rowid会发生变化,对于索引表(index-organized)rowid虽然依然有效,但是其实际对应的物理构成是错误的。 |