I've uploaded my Oracle Diagnostics Presentations from the years 2010-2011 into slideshare.
I hope that they are useful.
.
.
.
I hope that they are useful.
.
.
.
I am an Oracle Database Specialist in Singapore.
Please note that this site uses cookies.
SQL> drop table test_partitioned_table purge; Table dropped. SQL> SQL> -- create test table with 5+1 partitions SQL> create table test_partitioned_table 2 ( 3 id_column number, 4 data_column varchar2(15) 5 ) 6 partition by range (id_column) 7 ( 8 partition p_100 values less than (101), 9 partition p_200 values less than (201), 10 partition p_300 values less than (301), 11 partition p_400 values less than (401), 12 partition p_500 values less than (501), 13 partition p_max values less than (MAXVALUE) 14 ) 15 / Table created. SQL> SQL> -- populate the first 4 partitions SQL> insert into test_partitioned_table 2 select rownum, to_char(rownum) 3 from dual 4 connect by level < 379 5 / 378 rows created. SQL> SQL> -- identify the segments that did get created SQL> -- note : Use DBA_SEGMENTS as HEADER_% information is not available in USER_SEGMENTS SQL> select partition_name, header_file, header_block 2 from dba_segments 3 where owner = 'HEMANT' 4 and segment_name = 'TEST_PARTITIONED_TABLE' 5 and segment_type = 'TABLE PARTITION' 6 order by partition_name 7 / PARTITION_NAME HEADER_FILE HEADER_BLOCK ------------------------------ ----------- ------------ P_100 11 34449 P_200 11 35473 P_300 11 36497 P_400 11 38417 SQL> SQL> -- identify the objects SQL> -- use the DBA_OBJECTS view for consistency with previous query on DBA_SEGMENTS SQL> select subobject_name, object_id, data_object_id 2 from dba_objects 3 where owner = 'HEMANT' 4 and object_name = 'TEST_PARTITIONED_TABLE' 5 and object_type = 'TABLE PARTITION' 6 order by subobject_name 7 / SUBOBJECT_NAME OBJECT_ID DATA_OBJECT_ID ------------------------------ ---------- -------------- P_100 114541 114541 P_200 114542 114542 P_300 114543 114543 P_400 114544 114544 P_500 114545 114545 P_MAX 114546 114546 6 rows selected. SQL>
SQL> -- split the first partition SQL> alter table test_partitioned_table 2 split partition p_100 3 at (51) 4 into (partition p_50, partition p_100) 5 / Table altered. SQL> SQL> -- identify the segments SQL> select partition_name, header_file, header_block 2 from dba_segments 3 where owner = 'HEMANT' 4 and segment_name = 'TEST_PARTITIONED_TABLE' 5 and segment_type = 'TABLE PARTITION' 6 and partition_name in ('P_50','P_100') 7 order by partition_name 8 / PARTITION_NAME HEADER_FILE HEADER_BLOCK ------------------------------ ----------- ------------ P_100 11 40465 P_50 11 39441 SQL> SQL> -- identify the objects SQL> select subobject_name, object_id, data_object_id 2 from dba_objects 3 where owner = 'HEMANT' 4 and object_name = 'TEST_PARTITIONED_TABLE' 5 and object_type = 'TABLE PARTITION' 6 and subobject_name in ('P_50','P_100') 7 order by subobject_name 8 / SUBOBJECT_NAME OBJECT_ID DATA_OBJECT_ID ------------------------------ ---------- -------------- P_100 114541 114548 P_50 114547 114547 SQL>
SQL> -- insert one row into the 5th partition SQL> insert into test_partitioned_table 2 select 450, to_char(450) from dual 3 / 1 row created. SQL> SQL> -- identify the segment SQL> select partition_name, header_file, header_block 2 from dba_segments 3 where owner = 'HEMANT' 4 and segment_name = 'TEST_PARTITIONED_TABLE' 5 and segment_type = 'TABLE PARTITION' 6 and partition_name = 'P_500' 7 order by partition_name 8 / PARTITION_NAME HEADER_FILE HEADER_BLOCK ------------------------------ ----------- ------------ P_500 11 34449 SQL> SQL> -- identify the object SQL> select subobject_name, object_id, data_object_id 2 from dba_objects 3 where owner = 'HEMANT' 4 and object_name = 'TEST_PARTITIONED_TABLE' 5 and object_type = 'TABLE PARTITION' 6 and subobject_name = 'P_500' 7 order by subobject_name 8 / SUBOBJECT_NAME OBJECT_ID DATA_OBJECT_ID ------------------------------ ---------- -------------- P_500 114545 114545 SQL>
SQL> -- split the 5th partition SQL> -- now p_450 will have the 1 row and p_500 no rows SQL> alter table test_partitioned_table 2 split partition p_500 3 at (451) 4 into (partition p_450, partition p_500) 5 / Table altered. SQL> SQL> -- identify the segments SQL> select partition_name, header_file, header_block 2 from dba_segments 3 where owner = 'HEMANT' 4 and segment_name = 'TEST_PARTITIONED_TABLE' 5 and segment_type = 'TABLE PARTITION' 6 and partition_name in ('P_450','P_500') 7 order by partition_name 8 / PARTITION_NAME HEADER_FILE HEADER_BLOCK ------------------------------ ----------- ------------ P_450 11 34449 P_500 11 41489 SQL> SQL> -- identify the objects SQL> select subobject_name, object_id, data_object_id 2 from dba_objects 3 where owner = 'HEMANT' 4 and object_name = 'TEST_PARTITIONED_TABLE' 5 and object_type = 'TABLE PARTITION' 6 and subobject_name in ('P_450','P_500') 7 order by subobject_name 8 / SUBOBJECT_NAME OBJECT_ID DATA_OBJECT_ID ------------------------------ ---------- -------------- P_450 114549 114545 P_500 114545 114550 SQL>
SQL> select * from test_partitioned_table partition (p_450); ID_COLUMN DATA_COLUMN ---------- --------------- 450 450 SQL> select * from test_partitioned_table partition (p_500); no rows selected SQL>
SQL> l 1 select partition_name, extents 2 from dba_segments 3 where owner = 'HEMANT' 4 and segment_name = 'TEST_PARTITIONED_TABLE' 5 and segment_type = 'TABLE PARTITION' 6* order by partition_name SQL> / PARTITION_NAME EXTENTS ------------------------------ ---------- P_100 1 P_200 1 P_300 1 P_400 1 P_450 1 P_50 1 P_500 1 7 rows selected. SQL>