Operating System - HP-UX
1752802 Members
5490 Online
108789 Solutions
New Discussion юеВ

Hourly Partition in Oracle

 
Vikas Thakur
New Member

Hourly Partition in Oracle

Hi,

my oracle version is
BANNER

Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - Prod
PL/SQL Release 10.2.0.3.0 - Production
CORE 10.2.0.3.0 Production
TNS for Linux: Version 10.2.0.3.0 - Production
NLSRTL Version 10.2.0.3.0 - Production


I have few logging tables where close 2 millions records will be logged/inserted daily.
though this table is for logging purpose only, we need to query these tables occasionally and few reports are also based on these logging tables.

Now we want to create hourly partitions in these tables all of these have timestamp columns. So how can i do this.

Thanks in advance
Vikas
3 REPLIES 3
Volker Borowski
Honored Contributor

Re: Hourly Partition in Oracle

Hmmm,

check
http://www.oracle.com/technology/oramag/oracle/07-sep/o57partition.html
the is a date-field example.
In your case, you would need the time-qualification in addition.


CREATE TABLE whatever_the_name_is
(
tista date,
...
...
)
partition by range ( tista )
(
partition start_somewhere values less than
(TO_DATE('06/01/2009 00:00:00','mm/dd/yyyy hh24:mi:ss')),

partition 06012009_00_01 values
less than
(TO_DATE('06/01/2009 01:00:00','mm/dd/yyyy hh24:mi:ss')),

partition 06012009_01_02 values
less than
(TO_DATE('06/01/2009 02:00:00','mm/dd/yyyy hh24:mi:ss')),

:
:
:

partition future_unaccounted values
less than (MAXVALUE)
);

This would require some maintanance jobs to
a) export expired partitions
b) burn the exports to cd
c) drop expired exported partitions
d) create new partitions for the next period

But there might be several additional ways to
solve this.

Volker
Hein van den Heuvel
Honored Contributor

Re: Hourly Partition in Oracle

Vikas,

This Oracle usage question is completely platfort independent. For now. May I suggest that you tackle this problem in an Oracle focuess forum first. Later, when you know exactly what needs to be done and wonder how for example you might use HP-UX cron to run a task, then please do come back, But quite possible you can solve this all without ever leaving Oracle (It has tasks, queues, schedulers).

btw... 2 million records would not seem much at all. That perhpas warrants a partition as a whole IMHO, but cetrtainly not one chopped down futher down to hourly.

As you think about solutions you may also want to consider alternatives like EXTERNAL TABLES and Detachable/exported tablespaces.
Soound like you may want to have some sort of rolling window with new, hot, warm, and cold data on the appropriate storage/accessibility.

Hope this helps some,
Regards,

Hein van den Heuvel ( at gmail dot com )
HvdH Performance Consulting


Yogeeraj_1
Honored Contributor

Re: Hourly Partition in Oracle

hi Vikas,


you can create a script that generates the command SQL command for creating the partition daily and run that script accordingly.

Suppose you have a table with the following partitions:
CREATE TABLE tab1
(
dt date,
x int,
y varchar2(25)
)
PARTITION BY RANGE (dt)
(
PARTITION part_tab1_20090602_00 VALUES LESS THAN (to_date('02-jun-2009 00:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_01 VALUES LESS THAN (to_date('02-jun-2009 01:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_02 VALUES LESS THAN (to_date('02-jun-2009 02:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_03 VALUES LESS THAN (to_date('02-jun-2009 03:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_04 VALUES LESS THAN (to_date('02-jun-2009 04:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_05 VALUES LESS THAN (to_date('02-jun-2009 05:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_06 VALUES LESS THAN (to_date('02-jun-2009 06:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_07 VALUES LESS THAN (to_date('02-jun-2009 07:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_08 VALUES LESS THAN (to_date('02-jun-2009 08:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_09 VALUES LESS THAN (to_date('02-jun-2009 09:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_10 VALUES LESS THAN (to_date('02-jun-2009 10:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_11 VALUES LESS THAN (to_date('02-jun-2009 11:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_12 VALUES LESS THAN (to_date('02-jun-2009 12:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_13 VALUES LESS THAN (to_date('02-jun-2009 13:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_14 VALUES LESS THAN (to_date('02-jun-2009 14:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_15 VALUES LESS THAN (to_date('02-jun-2009 15:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_16 VALUES LESS THAN (to_date('02-jun-2009 16:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_17 VALUES LESS THAN (to_date('02-jun-2009 17:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_18 VALUES LESS THAN (to_date('02-jun-2009 18:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_19 VALUES LESS THAN (to_date('02-jun-2009 19:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_20 VALUES LESS THAN (to_date('02-jun-2009 20:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_21 VALUES LESS THAN (to_date('02-jun-2009 21:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_22 VALUES LESS THAN (to_date('02-jun-2009 22:00','dd-mon-yyyy hh24:mi')) ,
PARTITION part_tab1_20090602_23 VALUES LESS THAN (to_date('02-jun-2009 23:00','dd-mon-yyyy hh24:mi')) ,
PARTITION the_rest VALUES LESS THAN (MAXVALUE)
)
/

Now, create a script of commands (create_partitions.sql) for creating partitions for tomorrow.

spool create_partitions.sql;
select 'alter table tab1 split partition the_rest at ( to_date( '''||(trunc(trunc(sysdate+1)+(00+(00/60))/24,'HH24'))||''', ''dd/mm/yyyy hh24:mi'')) into ( partition part_tab1_'||to_char(sysdate+1,'yyyymmdd')||'_00, partition the_rest);' from dual;
--
select 'alter table tab1 split partition the_rest at ( to_date( '''||(trunc(trunc(sysdate+1)+(01+(00/60))/24,'HH24'))||''', ''dd/mm/yyyy hh24:mi'')) into ( partition part_tab1_'||to_char(sysdate+1,'yyyymmdd')||'_01, partition the_rest);' from dual;
--
select 'alter table tab1 split partition the_rest at ( to_date( '''||(trunc(trunc(sysdate+1)+(02+(00/60))/24,'HH24'))||''', ''dd/mm/yyyy hh24:mi'')) into ( partition part_tab1_'||to_char(sysdate+1,'yyyymmdd')||'_02, partition the_rest);' from dual;
--
...
...
--
select 'alter table tab1 split partition the_rest at ( to_date( '''||(trunc(trunc(sysdate+1)+(21+(00/60))/24,'HH24'))||''', ''dd/mm/yyyy hh24:mi'')) into ( partition part_tab1_'||to_char(sysdate+1,'yyyymmdd')||'_21, partition the_rest);' from dual;
--
select 'alter table tab1 split partition the_rest at ( to_date( '''||(trunc(trunc(sysdate+1)+(22+(00/60))/24,'HH24'))||''', ''dd/mm/yyyy hh24:mi'')) into ( partition part_tab1_'||to_char(sysdate+1,'yyyymmdd')||'_22, partition the_rest);' from dual;
--
select 'alter table tab1 split partition the_rest at ( to_date( '''||(trunc(trunc(sysdate+1)+(23+(00/60))/24,'HH24'))||''', ''dd/mm/yyyy hh24:mi'')) into ( partition part_tab1_'||to_char(sysdate+1,'yyyymmdd')||'_23, partition the_rest);' from dual;
--
spool off;


You can automate this script execution accordingly.

hope this helps!
kind regards
yogeeraj

No person was ever honoured for what he received. Honour has been the reward for what he gave (clavin coolidge)