Let's explore what sort of Unique Indexes you can create on a Partitioned Table.
There are three types of partitioning for Indexes :
a Global (Non-Partitioned)
b Global Partitioned
c Local Partitioned
Can a Unique Index be created using either type ?
Let me start with another table, SALES_DATA_2 which has the same structure and Partition Key as SALES_DATA, except that it doesn't have the Primary Key definition that builds the Unique Index.
Next, I try a Global (Non-Partitioned) Unique Index on SALE_ID. Note that the "GLOBAL" Keyword is optional if it is Non-Partitioned.
Effectively, this Global Index is the same as the Primary Key index on SALES_DATA that I built earlier.
Next, I try a Unique Global Partitioned Index on the same column.
So, that is a valid Unique Global Partitioned Index.
The next attempt is a Unique Local Partitioned Index -- i.e. partitioned by the same key as the Table.
So, a Unique Local Partitioned Index must include the Table Partition Key as a subset of the Index Key columns. This is something you must consider when Partitioning the Table and Index both.
(Also, note how USER_PART_KEY_COLUMNS doesn't show SALE_ID as a Partition Key. This is in 11.2.0.4)
There are three types of partitioning for Indexes :
a Global (Non-Partitioned)
b Global Partitioned
c Local Partitioned
Can a Unique Index be created using either type ?
Let me start with another table, SALES_DATA_2 which has the same structure and Partition Key as SALES_DATA, except that it doesn't have the Primary Key definition that builds the Unique Index.
SQL> l 1 CREATE TABLE SALES_DATA_2 2 ( SALE_ID NUMBER, 3 SALE_DATE DATE, 4 INVOICE_NUMBER VARCHAR2(21), 5 CUSTOMER_ID NUMBER, 6 PRODUCT_ID NUMBER, 7 SALE_VALUE NUMBER 8 ) 9 TABLESPACE HEMANT 10 PARTITION BY RANGE (SALE_DATE) 11 (PARTITION P_2018 VALUES LESS THAN (TO_DATE(' 2019-01-01','YYYY-MM-DD')) 12 TABLESPACE TBS_YEAR_2018 , 13 PARTITION P_2019 VALUES LESS THAN (TO_DATE(' 2020-01-01','YYYY-MM-DD')) 14 TABLESPACE TBS_YEAR_2019 , 15 PARTITION P_2020 VALUES LESS THAN (TO_DATE(' 2021-01-01','YYYY-MM-DD')) 16 TABLESPACE TBS_YEAR_2020 , 17 PARTITION P_MAXVALUE VALUES LESS THAN (MAXVALUE) 18* TABLESPACE HEMANT ) SQL> / Table created. SQL>
Next, I try a Global (Non-Partitioned) Unique Index on SALE_ID. Note that the "GLOBAL" Keyword is optional if it is Non-Partitioned.
SQL> create unique index sales_2_uk 2 on sales_data_2 (sale_id) global 3 tablespace hemant 4 / Index created. SQL> SQL> select partitioned, status 2 from user_indexes 3 where index_name = upper('sales_2_uk') 4 / PAR STATUS --- -------- NO VALID SQL> drop index sales_2_uk; Index dropped. SQL>
Effectively, this Global Index is the same as the Primary Key index on SALES_DATA that I built earlier.
Next, I try a Unique Global Partitioned Index on the same column.
SQL> create unique index sales_2_uk 2 on sales_data_2 (sale_id) global 3 partition by range (sale_id) 4 (partition p_1mill values less than (1000001) tablespace new_indexes, 5 partition p_2mill values less than (2000001) tablespace new_indexes, 6 partition p_3mill values less than (3000001) tablespace new_indexes, 7 partition p_maxval values less than (maxvalue) tablespace new_indexes) 8 / Index created. SQL> SQL> select uniqueness, partitioned, status 2 from user_indexes 3 where index_name = upper('sales_2_uk') 4 / UNIQUENES PAR STATUS --------- --- -------- UNIQUE YES N/A SQL> SQL> l 1 select column_position, column_name 2 from user_part_key_columns 3 where name = upper('sales_2_uk') 4* order by column_position SQL> / COLUMN_POSITION COLUMN_NAME --------------- ---------------- 1 SALE_ID SQL> SQL> select partition_name, status 2 from user_ind_partitions 3 where index_name = upper('sales_2_uk') 4 order by partition_position 5 / PARTITION_NAME STATUS ------------------------------ -------- P_1MILL USABLE P_2MILL USABLE P_3MILL USABLE P_MAXVAL USABLE SQL>
So, that is a valid Unique Global Partitioned Index.
The next attempt is a Unique Local Partitioned Index -- i.e. partitioned by the same key as the Table.
SQL> create unique index sales_2_uk 2 on sales_data_2 (sale_id) local 3 / on sales_data_2 (sale_id) local * ERROR at line 2: ORA-14039: partitioning columns must form a subset of key columns of a UNIQUE index SQL> !oerr ora 14039 14039, 00000, "partitioning columns must form a subset of key columns of a UNIQUE index" // *Cause: User attempted to create a UNIQUE partitioned index whose // partitioning columns do not form a subset of its key columns // which is illegal // *Action: If the user, indeed, desired to create an index whose // partitioning columns do not form a subset of its key columns, // it must be created as non-UNIQUE; otherwise, correct the // list of key and/or partitioning columns to ensure that the index' // partitioning columns form a subset of its key columns SQL> SQL> create unique index sales_2_uk 2 on sales_data_2 (sale_id, sale_date) local 3 / Index created. SQL> SQL> select uniqueness, partitioned, status 2 from user_indexes 3 where index_name = upper('sales_2_uk') 4 / UNIQUENES PAR STATUS --------- --- -------- UNIQUE YES N/A SQL> select column_position, column_name 2 from user_part_key_columns 3 where name = upper('sales_2_uk') 4 order by column_position 5 / COLUMN_POSITION COLUMN_NAME --------------- ---------------- 1 SALE_DATE SQL> select column_position, column_name 2 from user_ind_columns 3 where index_name = upper('sales_2_uk') 4 order by column_position 5 / COLUMN_POSITION COLUMN_NAME --------------- ---------------- 1 SALE_ID 2 SALE_DATE SQL> SQL> select partition_name, tablespace_name, status 2 from user_ind_partitions 3 where index_name = upper('sales_2_uk') 4 order by partition_position 5 / PARTITION_NAME TABLESPACE_NAME STATUS ------------------------------ ------------------------------ -------- P_2018 TBS_YEAR_2018 USABLE P_2019 TBS_YEAR_2019 USABLE P_2020 TBS_YEAR_2020 USABLE P_MAXVALUE HEMANT USABLE SQL>
So, a Unique Local Partitioned Index must include the Table Partition Key as a subset of the Index Key columns. This is something you must consider when Partitioning the Table and Index both.
(Also, note how USER_PART_KEY_COLUMNS doesn't show SALE_ID as a Partition Key. This is in 11.2.0.4)
2 comments:
Is the sales_2_uk a local prefixed or local non-prefixed index ? Is the partition name based on the date column? What happens when a new partition is created?
The LOCAL index is non-prefixed. Index Partition names follow the Table Partition names by default. Creating a new Table Partition results in a corresponding new Index Partition.
Post a Comment