25 March, 2019

Partitioning -- 14 : Converting a non-Partitioned Table to a Partitioned Table

Pre-12cRelease2, there were only three methods to convert a non-Partitioned Table to a Partitioned Table

(a) Create a new, empty, Partitioned Table and copy (using INSERT .... AS SELECT ... ) all the data from the non-Partitioned Table to the new, Partitioned Table (and subsequently rename the new Partitioned Table after renaming or dropping the old non-Partitioned Table)

(b) Create a new, empty, Partitioned Table and use EXCHANGE PARTITION to switch the non-Partitioned Table into the Partitioned Table (and then run subsequent SPLIT PARTITION or ADD PARTITION commands as needed to create the additional Partitions)

(c) Create an interim Partitioned Table and use DBMS_REDEFINITION to do an online copy of the data to the interim Partitioned Table and automatically switch the name at the end


12.2 introduced the ability to use ALTER TABLE  ... MODIFY PARTITION ... to convert a non-Partitioned Table to a Partitioned Table

I start with a non-Partitioned Table :

SQL> select table_name, partitioned
  2  from user_tables
  3  where table_name = 'SALES_DATA_NONPARTITIONED'
  4  /

TABLE_NAME                     PAR
------------------------------ ---
SALES_DATA_NONPARTITIONED      NO

SQL> select index_name, uniqueness, partitioned
  2  from user_indexes
  3  where table_name = 'SALES_DATA_NONPARTITIONED'
  4  /

INDEX_NAME                     UNIQUENES PAR
------------------------------ --------- ---
SALES_DATA_UK                  UNIQUE  NO

SQL> 


I then convert it to a Range-Partitioned Table.

SQL> alter table sales_data_nonpartitioned
  2  modify 
  3  partition by range (sale_date)
  4  (
  5  partition P_2015 values less than (to_date('01-JAN-2016','DD-MON-YYYY')),
  6  partition P_2016 values less than (to_date('01-JAN-2017','DD-MON-YYYY')),
  7  partition P_2017 values less than (to_date('01-JAN-2018','DD-MON-YYYY')),
  8  partition P_2018 values less than (to_date('01-JAN-2019','DD-MON-YYYY')),
  9  partition P_2019 values less than (to_date('01-JAN-2020','DD-MON-YYYY')),
 10  partition p_MAXVALUE values less than (MAXVALUE) 
 11  )
 12  online 
 13  update indexes
 14  /

Table altered.

SQL> 
SQL> alter table sales_data_nonpartitioned rename to sales_data;

Table altered.

SQL>
SQL> select partition_name, high_value
  2  from user_tab_partitions
  3  where table_name = 'SALES_DATA'
  4  order by partition_position
  5  /

PARTITION_NAME   HIGH_VALUE
---------------- --------------------------
P_2015           TO_DATE(' 2016-01-01 00:00
P_2016           TO_DATE(' 2017-01-01 00:00
P_2017           TO_DATE(' 2018-01-01 00:00
P_2018           TO_DATE(' 2019-01-01 00:00
P_2019           TO_DATE(' 2020-01-01 00:00
P_MAXVALUE       MAXVALUE

6 rows selected.

SQL> 
SQL> select index_name, partitioned, uniqueness, status
  2  from user_indexes
  3  where table_name = 'SALES_DATA'
  4  /

INDEX_NAME                     PAR UNIQUENES STATUS
------------------------------ --- --------- --------
SALES_DATA_UK                  NO  UNIQUE    VALID

SQL> 


The SALES_DATA_NONPARTITIONED was converted to a Range Partitioned Table.  If I didn't have to rename the table (e.g. if the table name was actually, properly SALES_DATA only), then there would be no need to lock the table as the RENAME command does.



No comments: