Thursday, January 15, 2009

How to make partitioning in Oracle more Quickly

As the table size grows and full table scans happens more frequently then there is no alternative than partitioning in oracle. Partition greatly enhance performance of a query. I will start my partitioning system simply with an example.

In my database the following query took 30~35 seconds to complete. After partitioning the performance increased amazingly and it then took only 1 second.

My query was,
SELECT DISTINCT fs.type, fs.id
, fs.pid, fs.cid
, fs.cr_id, fs.created_date
FROM summary fs where fs.id in
(select fa.id from forms fa where fa.sar in
(select la.sar from login la where la.login_id=1 and fa.created_date BETWEEN to_date('1-MAY-2008') AND to_date('21-SEP-2008') and fs.created_date BETWEEN to_date('1-MAY-2008') AND to_date('21-SEP-2008') )
)and mode=0;

After seeing above query I decide to make range partition on column created_date both in summary table and forms table.

Below is the list of procedures of making partition of forms table

1)Get a creation script of the original Table.
I get it by using DBMS_METADATA package.
SQL>SET LONG 99999
SQL>SELECT DBMS_METADATA.GET_DDL('TABLE','FORMS') FROM DUAL;

CREATE TABLE "PROD"."FORMS"
( "ID" NUMBER NOT NULL ENABLE,
"SAR" VARCHAR2(32) NOT NULL ENABLE,
"CREATED_DATE" TIMESTAMP (3) NOT NULL ENABLE
) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 NOCOMPRESS LOGGING
STORAGE(INITIAL 10485760 NEXT 10485760 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "DATA"

2)Get the creation script of the associated Indexes of the table.

SQL> select dbms_metadata.get_ddl('INDEX',index_name) from dba_indexes where owner='PROD' and table_name='FORMS';

DBMS_METADATA.GET_DDL('INDEX',INDEX_NAME)
--------------------------------------------------------------------------------

CREATE INDEX "PROD"."FA_DATE" ON "PROD"."FORMS" ("CREATED_DATE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 10485760 NEXT 10485760 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "DATA02"


CREATE INDEX "PROD"."TF_SAR_I" ON "PROD"."FORMS" ("SAR")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 10485760 NEXT 10485760 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "DATA02"

3)Get the creation script of the associated Constraints.

SQL> select dbms_metadata.get_ddl('CONSTRAINT',constraint_name)from dba_constraints where owner='PROD' and table_name='FORMS';

DBMS_METADATA.GET_DDL('CONSTRAINT',CONSTRAINT_NAME)
--------------------------------------------------------------------------------

ALTER TABLE "PROD"."FORMS" MODIFY ("ID" NOT NULL ENABLE)

ALTER TABLE "PROD"."FORMS" MODIFY ("CREATED_DATE" NOT NULL ENABLE)

4)Now create a temporary Partitioned Table
Define the range of date to make a partitioned table. Here I made 11 partitions. It's structure will be same as of FORMS table. I named here of partition table as FORMS_PART.

CREATE TABLE "FORMS_PART"
( "ID" NUMBER NOT NULL ENABLE,
"SAR" VARCHAR2(32) NOT NULL ENABLE,
"CREATED_DATE" TIMESTAMP (3) NOT NULL ENABLE
)partition by range (created_date)
(
partition fa_part1 values less than (to_date('01-JAN-2006','DD-MON-YYYY')) tablespace DATA02,
partition fa_part2 values less than (to_date('01-JUN-2006','DD-MON-YYYY')) tablespace DATA02,
partition fa_part3 values less than (to_date('01-SEP-2006','DD-MON-YYYY')) tablespace DATA02,
partition fa_part4 values less than (to_date('01-DEC-2006','DD-MON-YYYY')) tablespace DATA02,
partition fa_part5 values less than (to_date('01-MAR-2007','DD-MON-YYYY')) tablespace DATA02,
partition fa_part6 values less than (to_date('01-JUN-2007','DD-MON-YYYY')) tablespace DATA02,
partition fa_part7 values less than (to_date('01-SEP-2007','DD-MON-YYYY')) tablespace DATA02,
partition fa_part8 values less than (to_date('01-DEC-2007','DD-MON-YYYY')) tablespace DATA02,
partition fa_part9 values less than (to_date('01-MAR-2008','DD-MON-YYYY')) tablespace DATA02,
partition fa_part10 values less than (to_date('01-JUN-2008','DD-MON-YYYY')) tablespace DATA02,
partition fa_part11 values less than (maxvalue) tablespace DATA02);

5)Load data into the temporary partitioned table.

In order to minimize to load time greatly I gave append and nologging hints. Append hints will not generate undo data and nologging hint will generate a minimal redo log. So my data load will be faster.

insert /*+APPEND NOLOGGING */ into FORMS_PART select * from forms;
78474831 rows created.

6) After load data into paritioned table rename original table to a new one. Here I gave it a name from FORMS to FROMS_BAK. You later can dropped it. Also rename the temporary partitioned table to original table name.

SQL> rename forms to forms_bak;
Table renamed.

SQL> rename forms_part to forms;
Table renamed.

7)Rebuild the index as well as create constraints if any.
alter index FA_DATE rebuild;
alter index TF_SAR_I rebuild;


8)Gather partitioned table statistics.
EXEC DBMS_STATS.gather_table_stats('PROD', 'FORMS', cascade => TRUE);

Now have a test your original query and compare performance with the one not partitioned.

No comments:

Post a Comment