Skip to Main Content

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Brian.

Asked: October 12, 2001 - 1:16 pm UTC

Last updated: October 19, 2021 - 9:36 am UTC

Version: 8.1.7

Viewed 10K+ times! This question is

You Asked

Let's say we have a table of documents with key of doc_id. This table contains millions of documents(rows). There is also a

table that assigns one or more industry codes to each doc:

create table doc_ind
( doc_id integer,
ind_code varchar2(10)
)

This table will therefore also contain millions of rows.

The industry code is a part of the default set of industry codes used by our business.

Now let's say that we sign deals with clients that want to use their own industry classifications. I don't want to create new tables for each client (there could eventually be hundreds of clients and therefore hundreds of new tables) and have some scheme where logic is built into the application to derive the correct table_name to query based on the client.

My first thought is to create a table like:

create table doc_client_ind
( client_id varchar2(10),
doc_id integer,
ind_code varchar2(10)
)

The client id could be any value - usually resembling the client name.

Because each new client would add millions of rows to this table, I want to use partitioning. After reading up on partitioning in your book, my situation does not seem to fit perfectly into standard scenarios. At first, it seemed I would need to use hash partitioning. However, the number of distinct client_id values in this table will be very small to start with and grow over time. It is not clear how I would easily manage hash partitioning well over time.

In order to use range partitioning, it seems to me that client_id's would need to be assigned with values that have a natural ascending sort value (i.e., c0001, c0002, etc.). Then I could have one partition per client and create them on an ongoing as

needed basis.

I have three questions:

1. Are there other options (with or without partitioning) I don't see to manage this?
2. Is there a way to manage this effectively using the original essentially random client id values?
3. What do you suggest given the limited info above?
4. Given your suggestion in question 3, what are the disadvantages, caveats I need to be aware of?

Thanks - Brian



and Tom said...

Well, in 9i, there is LIST partitioning as well, that maybe something to consider. Here each client_id could be targeted to a specific partition.


If you just want to achieve a nice distribution of data across many disks/partitions, you could hash right now on DOC_ID. There will be millions of unique values for that from the get go -- that will hash very nicely. Since you'll always join on doc_id and client_id, partition elimination will take place just as effectively.

So, either look at 9i with list partitioning if you feel you would gain some advantage to partition by client_id (one would be that if you drop a client, gettng rid of their data is trivial -- drop the partition).

Or, hash partition on the doc_id to achieve a good overall spread of data.


Rating

  (267 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Thanks

Brian, October 12, 2001 - 3:10 pm UTC

Actually the table will mainly be used to query for docs that have a certain industry tagged to them:

select doc_id
from doc_client_ind
where client_id = 'ABC'
and ind_code = 'IND01'.

All queries against this table will only be meaningful if
where client_id =
is part of the statement.

Given this use, I don't think hash partitioning on doc_id gives me what I am looking for. That is why I want to partition on client_id to handle that level of elimination and then index on ind_code will be used within that partition.

Thanks for the suggestion of LIST partitioning with 9i. Until we implement 9i, is my only option to assign client ids as suggested in my original question (i.e., c0001, cooo2, etc.)?



Tom Kyte
October 12, 2001 - 4:17 pm UTC

How many IND_CODE values are there (what would select count(distinct ind_code) from t return?)

Thanks

Brian, October 12, 2001 - 6:43 pm UTC

Anywhere from 50 - 100

Tom Kyte
October 12, 2001 - 7:09 pm UTC

Then yes, in the meantime, you would be best served using a range partition with specific ranges based on customer id.

One idea to play with might also be an IOT (index organized table) whose primary key is CLIENT_ID, IND_CODE, DOC_ID using index key compression. In this fashion, the CLIENT_ID, IND_CODE would almost be factored out of the table all together and we would just have doc_ids in the IOT.

Instructional as always

Brian, October 12, 2001 - 8:37 pm UTC

Thanks Tom

More light

A reader, June 12, 2003 - 7:49 pm UTC

Hi tom,

I did not understand the link between getting the count of distinct ind_code and the partition based on specific ranges of customer id as explained by you.

"Then yes, in the meantime, you would be best served using a range partition with
specific ranges based on customer id. "

Also, can you also shed some light on key compression and when you say "
One idea to play with might also be an IOT (index organized table) whose primary
key is CLIENT_ID, IND_CODE, DOC_ID using index key compression." and especially "In this
fashion, the CLIENT_ID, IND_CODE would almost be factored out of the table all
together and we would just have doc_ids in the IOT."

Tom Kyte
June 12, 2003 - 8:32 pm UTC

I wanted to know if client id was a small domain, something manageable. If not, they would not be able to range partition by it as it would be an ongoing job just to split and partition the table.

50 -- they could do it.
500,000 -- they would have a hard time at it (but hash partitioning would start to come into play).

values in between with ranges/hashes -- not practical at some point.


Index key compression is a feature whereby repeating fields on the leading edge of the index are removed from the leaf block row entries. Compresses the data.

If you create an index on (owner,object_type,object_type) on a copy of all_objects - with compress 2, we would store the owner, object type ONCE per leaf block, rather then once per ROW per leaf block -- leading to significant savings in space.



Thanks Tom!!!

A reader, June 13, 2003 - 1:08 pm UTC



IOT with Hash Partitioning

A reader, June 20, 2003 - 12:54 pm UTC

Hi tom,

is Index Organized table possible with Hash partitioning? If not, why not?

Thanks
Venkat.

Tom Kyte
June 20, 2003 - 5:37 pm UTC

ops$tkyte@ORA920> create table t
  2  (
  3    object_id        number primary key,
  4    object_type      varchar2(18)
  5  )
  6  organization index
  7  partition by hash(object_id) partitions 8
  8  /

Table created.

ops$tkyte@ORA920>
ops$tkyte@ORA920> insert into t select object_id, object_type from all_objects
  2  /

31595 rows created.
 

How about in 8i....

A reader, June 23, 2003 - 7:47 pm UTC

Hi tom,

I am sorry i missed out the version. Is it possible to do it in 8i.

Thanks
Venkat.

Tom Kyte
June 24, 2003 - 7:38 am UTC

ops$tkyte@ORA817DEV> @test
partition by hash(object_id) partitions 8
                                        *
ERROR at line 7:
ORA-25198: only range partitioning is supported for index-organized table


was not a feature in that release  

null values...

Alvin, June 27, 2003 - 5:19 am UTC

Greetings,

couple of questions for you,

1.What if the column that i'm partitioning contains null entries ? is this allowed ? how will oracle know where to place the data ?

2. in Page 620 of the expert one on one book an error 01502 was raised because the local_nonprefixed index was unusable why ? are "queries" on Partitioned Tables (PT) index dependent ?

3. say i have a table
create table detail
( cust_id number
, cust_balance number
, some other columns.....
)

and cust_id has 65 distinct values over 7 million records. Will partitioning hash ( cust_id ) be of any use assuming that the Front-End apps issues out a dynamic query that will not use any indexed columns on any of its predicate ?

one advantage that i see in using PT's is data will be forced group by partition.



Tom Kyte
June 27, 2003 - 9:08 am UTC

1) yes allowed, it'll put them where it "wants".  

ops$tkyte@ORA920> create table t
  2  (
  3    object_id        number ,
  4    object_type      varchar2(18)
  5  )
  6  partition by hash(object_id) partitions 8
  7  /

Table created.

ops$tkyte@ORA920>
ops$tkyte@ORA920> insert into t select object_id, object_type from all_objects;

31589 rows created.

ops$tkyte@ORA920> insert into t select NULL, 'xxx' from all_users;

47 rows created.

ops$tkyte@ORA920>
ops$tkyte@ORA920> declare
  2      l_cnt number;
  3  begin
  4      for x in ( select partition_name
  5                   from user_tab_partitions
  6                  where table_name = 'T' )
  7      loop
  8          execute immediate
  9          'select count(*)
 10             from t partition(' || x.partition_name || ')'
 11             into l_cnt;
 12          dbms_output.put_line
 13          ( x.partition_name || ' ' || l_cnt || ' rows...' );
 14
 15          execute immediate
 16          'select count(*)
 17             from t partition(' || x.partition_name || ')
 18            where object_id is null'
 19            into l_cnt;
 20          dbms_output.put_line
 21          ( x.partition_name || ' ' || l_cnt || ' NULL rows...' );
 22      end loop;
 23  end;
 24  /
SYS_P347 3965 rows...
SYS_P347 47 NULL rows...
SYS_P348 3948 rows...
SYS_P348 0 NULL rows...
SYS_P349 4042 rows...
SYS_P349 0 NULL rows...
SYS_P350 3930 rows...
SYS_P350 0 NULL rows...
SYS_P351 3868 rows...
SYS_P351 0 NULL rows...
SYS_P352 3895 rows...
SYS_P352 0 NULL rows...
SYS_P353 4072 rows...
SYS_P353 0 NULL rows...
SYS_P354 3916 rows...
SYS_P354 0 NULL rows...

PL/SQL procedure successfully completed.


for example -- they all went into the "first" partition in that case.

2) page 640 maybe?  it was raised because

   a) the index was unusable
   b) the query plan said "i need to read that index"

queries against partitioned tables are no more or less "index dependent" then queries against unpartitioned tables.  same thing would happen against a "normal" table if its indexes were unusable and query plan said "i want to use that index"

3) 65 is too small in all likelyhood, unless you are really lucky.  It would be far too easy to have this happen:

ops$tkyte@ORA920> select count(distinct object_id) from t;

COUNT(DISTINCTOBJECT_ID)
------------------------
                      65

ops$tkyte@ORA920>
ops$tkyte@ORA920> declare
  2      l_cnt number;
  3  begin
  4      for x in ( select partition_name
  5                   from user_tab_partitions
  6                  where table_name = 'T' )
  7      loop
  8          execute immediate
  9          'select count(*)
 10             from t partition(' || x.partition_name || ')'
 11             into l_cnt;
 12          dbms_output.put_line
 13          ( x.partition_name || ' ' || l_cnt || ' rows...' );
 14      end loop;
 15  end;
 16  /
SYS_P395 65 rows...
SYS_P396 0 rows...
SYS_P397 0 rows...
SYS_P398 0 rows...
SYS_P399 0 rows...
SYS_P400 0 rows...
SYS_P401 0 rows...
SYS_P402 0 rows...

PL/SQL procedure successfully completed.


All 7million rows could be in the same hash partition.  You would use range or list instead. 

cont.

Alvin, June 27, 2003 - 5:21 am UTC

therefore minimizing physical i/o block reads.

Why a different index?

Kamal Kishore, June 29, 2003 - 8:20 am UTC

Hi Tom,
I was trying your examples on pages 639-640 of Expert one-on-one Oracle and for the query using both coluns A and B, it seems to be using the NONPREFIXED index (the example in book shows it using the PREFIXED index)?

Is there something in my test runs that makes it use the other index (or Oracle init.ora settings)?
Thanks,

ops$kkishore @ ORA817.WORLD > create table partitioned_table
2 (
3 a int,
4 b int
5 )
6 partition by range(a)
7 (
8 partition part_1 values less than (2),
9 partition part_2 values less than (3)
10 )
11 /

Table created.

ops$kkishore @ ORA817.WORLD >
ops$kkishore @ ORA817.WORLD > create index idx_local_prefixed on partitioned_table (a, b) local ;

Index created.

ops$kkishore @ ORA817.WORLD > create index idx_local_nonprefixed on partitioned_table (b) local ;

Index created.

ops$kkishore @ ORA817.WORLD >
ops$kkishore @ ORA817.WORLD > insert into partitioned_table values (1, 1) ;

1 row created.

ops$kkishore @ ORA817.WORLD >
ops$kkishore @ ORA817.WORLD > alter index idx_local_prefixed modify partition part_2 unusable
2 /

Index altered.

ops$kkishore @ ORA817.WORLD > alter index idx_local_nonprefixed modify partition part_2 unusable
2 /

Index altered.

ops$kkishore @ ORA817.WORLD >
ops$kkishore @ ORA817.WORLD > set autotrace on explain
ops$kkishore @ ORA817.WORLD > select * from partitioned_table where a = 1 and b = 1 ;

A B
---------- ----------
1 1

1 row selected.


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=1 Card=1 Bytes=26)
1 0 TABLE ACCESS (BY LOCAL INDEX ROWID) OF 'PARTITIONED_TABLE' (Cost=1 Card=1 Byte
s=26)

2 1 INDEX (RANGE SCAN) OF 'IDX_LOCAL_NONPREFIXED' (NON-UNIQUE) (Cost=1 Card=1)



ops$kkishore @ ORA817.WORLD > select * from partitioned_table where b = 1 ;
ERROR:
ORA-01502: index 'OPS$KKISHORE.IDX_LOCAL_NONPREFIXED' or partition of such index is in unusable
state



no rows selected


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=1 Card=2 Bytes=52)
1 0 PARTITION RANGE (ALL)
2 1 TABLE ACCESS (BY LOCAL INDEX ROWID) OF 'PARTITIONED_TABLE' (Cost=1 Card=2 By
tes=52)

3 2 INDEX (RANGE SCAN) OF 'IDX_LOCAL_NONPREFIXED' (NON-UNIQUE) (Cost=3 Card=2)



ops$kkishore @ ORA817.WORLD >


Tom Kyte
June 29, 2003 - 9:39 am UTC

it is able to -- it used A = 1 to do partition elimination (which can do both LOCAL INDEX and TABLE partition elimination).  So, it only read part_1 of the idx_local_nonprefixed.

In 9i, if you analyze the table you might find this to be the behavior:

ops$tkyte@ORA920> set autotrace on explain
ops$tkyte@ORA920> select * from partitioned_table where a = 1 and b = 1 ;

         A          B
---------- ----------
         1          1


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=1 Bytes=4)
   1    0   INDEX (RANGE SCAN) OF 'IDX_LOCAL_PREFIXED' (NON-UNIQUE) (Cost=2 Card=1 Bytes=4)



ops$tkyte@ORA920> select * from partitioned_table where b = 1 ;
ERROR:
ORA-01502: index 'OPS$TKYTE.IDX_LOCAL_PREFIXED' or partition of such index is in unusable state



no rows selected


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=1 Bytes=4)
   1    0   PARTITION RANGE (ALL)
   2    1     INDEX (SKIP SCAN) OF 'IDX_LOCAL_PREFIXED' (NON-UNIQUE) (Cost=2 Card=1 Bytes=4)



ops$tkyte@ORA920> set autotrace off


In 817, if you analyze it, you'll get:

ops$tkyte@ORA817DEV> set autotrace on explain
ops$tkyte@ORA817DEV> select * from partitioned_table where a = 1 and b = 1 ;

         A          B
---------- ----------
         1          1


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=1 Card=1 Bytes=4)
   1    0   INDEX (RANGE SCAN) OF 'IDX_LOCAL_PREFIXED' (NON-UNIQUE) (Cost=1 Card=1 Bytes=4)



ops$tkyte@ORA817DEV> select * from partitioned_table where b = 1 ;
ERROR:
ORA-01502: index 'OPS$TKYTE.IDX_LOCAL_PREFIXED' or partition of such index is in unusable state



no rows selected


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=1 Card=1 Bytes=4)
   1    0   PARTITION RANGE (ALL)
   2    1     INDEX (FULL SCAN) OF 'IDX_LOCAL_PREFIXED' (NON-UNIQUE) (Cost=1 Card=1 Bytes=4)



ops$tkyte@ORA817DEV> set autotrace off


<b>bottom line is -- plans can and will change.  even though you get a subtly different plan, the mechanics were identical.  We achieved partition elimination and one query worked where as the other (cause it could not achieve this elimination) did not.</b>


 

analyze was the key...

Kamal Kishore, June 29, 2003 - 1:17 pm UTC

Hi Tom,
This looks like an example in support of your statement:
<quote>
bottom line is -- plans can and will change.
</quote>

And it did change.

The plan came out to be different even though the steps performed were same.

In this particular case, as pointed out by you, the analyze was the key. Once I analyzed the table and did it again, it picked up the PREFIXED index.

It looks like that you are saying that even the use of NONPREFIXED index by the optimizer is NOT a sub-optimal execution plan and is acceptable, correct?
Thanks,


Tom Kyte
June 29, 2003 - 1:43 pm UTC

in light of the fact there were no stats, yes, it was perfectly acceptable.

And note that in 9i, the plans change yet again to something completely different (new feature index skip scan)

Null values again...

Alvin, July 01, 2003 - 10:05 pm UTC

In pp638 of your book you said that non-prefixed local indexes may or may not allow partition elimination.

If the column partition containing null values such a case for not using partition elimination ? because as you've said in my ealier question ( see 2 post earlier of this one ) that it places null values where it wants.

1. Will Null values scattered in diff partitions ?

2. Or NOT because when it places null values at a particular partition it ALWAYS puts ALL null valued columns in the SAME partition ?

Tom Kyte
July 02, 2003 - 7:56 am UTC

range:
</code> http://docs.oracle.com/docs/cd/B10501_01/server.920/a96524/c12parti.htm#461507

goes into the "max value" partition

list:
http://docs.oracle.com/docs/cd/B10501_01/server.920/a96524/c12parti.htm#466634 <code>

goes into the "default" partition

hash:

not defined.



I would suggest you want to partition on a NOT NULL column in any case

Partitioning

vj, July 10, 2003 - 3:53 am UTC

Tom,

I mean overall how efficient is to use the RANGE Partitioning for NON-NUMERIC Columns ? I guess Oracle has to convert to ASCII and do the same right...

Also got a question of how can i take a call of when i go for Hash..Between Range and Hash most of the times i get beaten..Kindly help me..i might have around 1 mil records..


Tom Kyte
July 10, 2003 - 9:43 am UTC

it is a binary compare, no more or less efficient then numbers really (numbers in Oracle are like packed decimal "strings" with 2 digits per byte).


The decisions on hash, range or list are based on HOW you use the data, WHAT you want to accomplish via partitioning.

Suppose you wanted to accomplish:

o aging of data, allowing for easy purge

then range partitioning is the only thing that made sense.


Suppose you wanted to accomplish

o administrative ease of use
o increased concurrency on an OLTP table (keyed reads)

then hashing by the key with some global indexes that are range partitioned by their respective keys would be appropriate.


You have to state what it is you want to accomplish via partitioning, then the answer will be "obvious" or at least "more obvious"

to change the range values ...

reader, September 17, 2003 - 12:45 pm UTC

Tom, We have partitioned tables based on range value with primary key that is a number. Currently the range is like, 1-100000 in one partition and each partition is expected to have 100000 records . We wanted to change the range like 1-200000 in the first partition and each of the other partitions will have 200000 records. How do i do this? Thanks.

Tom Kyte
September 17, 2003 - 5:17 pm UTC

Partitioning/ storage parameters

wasey, November 03, 2003 - 11:50 am UTC

I have tables in one schema 'A' for each year as follows using single table space
Y00(id number, account_no number, trans_date date) -- There are indexes on id, account_no, trans_date
Y01(id number, account_no number, trans_date date) -- There are indexes on id, account_no, trans_date
Y02(id number, account_no number, trans_date date) -- There are indexes on id, account_no, trans_date
Y03(id number, account_no number, trans_date date) -- There are indexes on id, account_no, trans_date
There are approximately 1.5 million records in each table


I would like to create a single table in schema 'B' with partition on Date range and would like to migrate the data from schema 'A' to schema 'B', so that each partition will have its own table space and I would like to create a single
table space for all the indexes representing all the partitions.
What should be my approach to define the storage parameters or sizing of table space
PCTFREE ..
STORAGE (
INITIAL ....
MINEXTENTS ....
MAXEXTENTS ....
)

As I am getting the following error creating a index on one of the tables
CREATE INDEX ID_1 ON TABLE1
*
ERROR at line 1:
ORA-01659: unable to allocate MINEXTENTS beyond 18 in tablespace TBS_1


Tom Kyte
November 03, 2003 - 5:55 pm UTC

use locally managed tablespaces

do not use storage parameters

1.5 million records is pretty small if that is table -- 2 numbers and a date. Just use 1 or 2 megabyte uniform extents.

no initial
no next
no pctincrease

ever again!



Partitioning/ storage parameters

wsaey, November 04, 2003 - 4:19 pm UTC

Can you please elaborate
why we do not need the storage parameters? and create only local table spaces.

Regards,

Tom Kyte
November 05, 2003 - 7:29 am UTC

locally MANAGED tablespaces.

there are two types:

a) uniform extents. all extents are exactly the same size.
b) system allocated. Oracle decides how big extents should be based on growth patterns.


In both cases, the only storage parameters I like to see are:

( initial 1k next 1k pctincrease 0 minextents 1 )

that makes sure the initial segment create will get one extent and grow from there an extent at a time.

creation of partition table

Ashiq Shamsudeen A, November 05, 2003 - 8:21 am UTC

Hi Tom,

I've a partition table a_part ,if i try to create table b_part (using the syntax create table b_part as select * from a_part) .Its creating ordinary table instead of partition one,why?


Tom Kyte
November 05, 2003 - 9:44 am UTC

because you told it to.

you said "hey, create a table b_part please"

you didn't say "hey, create a partitioned table b_part using these rules"

you just created a table, nothing more, nothing less. if you want a partitioned table, create a partitioned table and populate it with "as select * from a_part".

partitioning/storage parameters

wasey, November 05, 2003 - 11:08 am UTC

Thanks Tom
based on my previous question, lets say I have more tha three columns and in each of my Y00, Y01 ... tables

I would like to create the indexes as following

CREATE INDEX ID1 ON Y00
(ACCOUNT_NO)
INITRANS 2
MAXTRANS 255
LOCAL (
PARTITION Y00
LOGGING
NOCOMPRESS
TABLESPACE TBS1
PCTFREE 10
INITRANS 2
MAXTRANS 255
STORAGE (
INITIAL 32M
MINEXTENTS 1
MAXEXTENTS 2147483645
FREELISTS 1
FREELIST GROUPS 1
BUFFER_POOL DEFAULT
),
PARTITION Y01
LOGGING
NOCOMPRESS
TABLESPACE TBS1
PCTFREE 10
INITRANS 2
MAXTRANS 255
STORAGE (
INITIAL 32M
MINEXTENTS 1
MAXEXTENTS 2147483645
FREELISTS 1
FREELIST GROUPS 1
BUFFER_POOL DEFAULT
),
PARTITION Y02
LOGGING
NOCOMPRESS
TABLESPACE TBS1
PCTFREE 10
INITRANS 2
MAXTRANS 255
STORAGE (
INITIAL 32M
MINEXTENTS 1
MAXEXTENTS 2147483645
FREELISTS 1
FREELIST GROUPS 1
BUFFER_POOL DEFAULT
),

.......

Based on your explanation
should I use
INITIAL 32M
NEXT 32M
MINEXTENTS 1
MAXEXTENTS 2147483645 (remove this ?)
FREELISTS 1 (remove ?)
FREELIST GROUPS 1 (remove ?)
BUFFER_POOL DEFAULT (remove ?)

What is the best way to modify and I would like make sure that the index creation does not fail due to tablespace size

Thanks,


Tom Kyte
November 05, 2003 - 6:16 pm UTC

i would use initial 1k next 1k minextents 1 and a LMT (lmts have unlimited extents already)

(as i sort of said above :)

or on CREATE (as opposed to a alter index rebuild or alter table move), just LEAVE THE STORAGE CLAUSE OFF, you don't need it at all

Partitions/Storage Parameters

wasey, November 05, 2003 - 6:06 pm UTC

Tom,
Can you please clarify your comments

I have the following Revenue Information table
CREATE TABLE REV_INF (
ACT_ID NUMBER (20) ,
ACT_NO NUMBER (10) ,
CG_QTY NUMBER (6),
CG_AMT NUMBER (12,2),
BILL_DT DATE,
--
--
--
CG_ACC_CD_1 VARCHAR2 (2),
CG_ACC_CD_2 VARCHAR2 (2),

TABLESPACE TBS1
PCTFREE 10
PCTUSED 40
INITRANS 1
MAXTRANS 255
PARTITION BY RANGE (BILL_DT)
(
PARTITION RD_PREV VALUES LESS THAN (TO_DATE(' 1980-01-01', 'YYYY-MM-DD')) TABLESPACE TB80
PCTFREE 10
PCTUSED 40
INITRANS 1
MAXTRANS 255
STORAGE (
INITIAL 94371840
MINEXTENTS 1
MAXEXTENTS 2147483645
),
PARTITION Y90 VALUES LESS THAN (TO_DATE(' 1990-01-01', 'YYYY-MM-DD')) TABLESPACE TB90
PCTFREE 10
PCTUSED 40
INITRANS 1
MAXTRANS 255
STORAGE (
INITIAL 94371840
MINEXTENTS 1
MAXEXTENTS 2147483645
),
PARTITION Y00 VALUES LESS THAN (TO_DATE('2000-01-01', 'YYYY-MM-DD'))TABLESPACE TB00
PCTFREE 10
PCTUSED 40
INITRANS 1
MAXTRANS 255
STORAGE (
INITIAL 94371840
MINEXTENTS 1
MAXEXTENTS 2147483645
),
PARTITION Y10 VALUES LESS THAN (TO_DATE('2010-01-01', 'YYYY-MM-DD')) TABLESPACE TB10
PCTFREE 10
PCTUSED 40
INITRANS 1
MAXTRANS 255
STORAGE (
INITIAL 94371840
MINEXTENTS 1
MAXEXTENTS 2147483645
),
);


CREATE INDEX ACTNO_IX ON
REV_INF(ACT_NO)
LOCAL
(
PARTITION RD_PREV TABLESPACE TBS_IX
PCTFREE 10
PCTUSED 40

STORAGE (
INITIAL 94371840
MINEXTENTS 1
MAXEXTENTS 2147483645
),
PARTITION Y90 TABLESPACE TBS_IX
PCTFREE 10
PCTUSED 40
STORAGE (
INITIAL 94371840
MINEXTENTS 1
MAXEXTENTS 2147483645
),
PARTITION Y00 TABLESPACE TBS_IX
PCTFREE 10
PCTUSED 40
STORAGE (
INITIAL 94371840
MINEXTENTS 1
MAXEXTENTS 2147483645
),
PARTITION Y10 TABLESPACE TBS_IX
PCTFREE 10
PCTUSED 40
STORAGE (
INITIAL 94371840
MINEXTENTS 1
MAXEXTENTS 2147483645
)
);





/***************************** /
with your comment --

no initial
no next
no pctincrease
ever again!

/*****************************/
Should the table be reconstructed as follows with locally managed TABLESPACES by removing the all the storage parameters.

CREATE TABLE REV_INF (
ACT_ID NUMBER (20) ,
ACT_NO NUMBER (10) ,
BILL_DT DATE,
--
--
--
CG_ACC_CD_1 VARCHAR2 (2),
CG_ACC_CD_2 VARCHAR2 (2),

TABLESPACE TBS1
PCTFREE 10
PCTUSED 40
INITRANS 1
MAXTRANS 255
PARTITION BY RANGE (BILL_DT)
(
PARTITION RD_PREV VALUES LESS THAN (TO_DATE(' 1980-01-01', 'YYYY-MM-DD')) TABLESPACE TB80,

PARTITION Y90 VALUES LESS THAN (TO_DATE(' 1990-01-01', 'YYYY-MM-DD')) TABLESPACE TB90
,
,
PARTITION Y00 VALUES LESS THAN (TO_DATE(' 2000-01-01', 'YYYY-MM-DD'TABLESPACE TB00
,
,
PARTITION Y10 VALUES LESS THAN (TO_DATE(' 2010-01-01', 'YYYY-MM-DD')) TABLESPACE TB10

);


CREATE INDEX ACTNO_IX ON
REV_INF(ACT_NO)
LOCAL
(
PARTITION RD_PREV TABLESPACE TBS_IX,

PARTITION Y90 TABLESPACE TBS_IX,

PARTITION Y00 TABLESPACE TBS_IX,

PARTITION Y10 TABLESPACE TBS_IX
);


Thanks,
Wasey


range partitioning indexes

A reader, January 12, 2004 - 12:23 pm UTC

Hi

We want to partition some of our tables and indexes. We are going to hash partition our tables since the data distribution is not very uniform, i.e no logical range.

However we want to GLOBAL partition our indexes because this is a OLTP database. Many of indexes have no logical range neither. My question if I want to use logical ranges I will end up having partitions of different size, for example

account_no between 1 and 100000 I will have 400000 rows
account_no between 100001 and 200000 I will have 100000 rows

and so on

Does this affect performance?

I have another way to distribute the data uniformly using range partition (using the NTILE function) however my range will be very "DODGY"

something like this



--------------------------------------------------------------------------------
NT MIN(ID) MAX(ID) COUNT(*) MAX(ID)-MIN(ID)
---------- ---------- ---------- ---------- ---------------
1 1 175108 984025 175107
2 175108 310148 984025 135040
3 310148 445173 984025 135025
4 445173 586530 984025 141357
5 586530 773611 984025 187081
6 773611 1004361 984025 230750
7 1004362 1220448 984025 216086
8 1220449 1533474 984025 313025
9 1533474 1814891 984025 281417
10 1814891 2081213 984025 266322
11 2081214 2317213 984025 235999
12 2317213 2549731 984025 232518
13 2549731 2771108 984025 221377
14 2771108 2973580 984024 202472
15 2973580 3259862 984024 286282
--------------------------------------------------------------------------------


To distribute the number of rows uniformly across partitions I have to use min(id) and max(id) as ranges... As you can see number of rows is uniform however range not...

Which way is better? Or none of them is feasible?

Tom Kyte
January 12, 2004 - 1:39 pm UTC

they do not have to be "even". it'll not really affect performance.

what is your goal -- why are you partitioning the index. is it "huge".

if this is an increasing number (like a sequence) -- you'll be constantly splitting and adding partitions at the end.

we have heavy contention problems

A reader, January 12, 2004 - 2:00 pm UTC

Hi

Our goal is to aliviate contention problems. Our database resources are heavily contended. Very high number of buffer busy waits and cache buffer chain latches (these two accounts 80% of total waits, wait time is as high as CPU time). We have rebuilt the tables and indexes and increased freelists and initrans with no improvement.

The indexes are roughly 100mb ~ 400mb in size. The root blocks are heavily contended that's why we wish to partition them.

I was reading the administrator guide and it says to achieve best performance make sure the data is distributed in range partitions, that's why I thought we need to have even partitions.

Tom Kyte
January 13, 2004 - 1:05 am UTC

buffer busy/cache buffer chains waits can happen for lots of reasons - it could be all about reads.

Have you ascertained that it is INSERT contention here -- and not READ contention?

partitioning problem

SR, February 18, 2004 - 6:58 am UTC

Tom,

We have a table T(SEQ NUMBER, C1 VARCHAR2(1), C2 VARCHAR2(1), V NUMBER). Its not partitioned now. However we have huge buffer busy wait problem (p3=130). It seem to arise from the fact multiple daemons are trying to read blocks of T, using T_SI index (C1,C2). However T_PK is SEQ. It seems like range scan on T_SI is working correctly, however rows r1 belongs to Daemon1, r2 belongs to Daemon2 and they are on the same block. Another problem is after they are done with the processing, C1 and C2 become null. Thus partitioning on C1,C2 won't work either. Only thing I can think of hash partition on SEQ and hope the rows will get dispersed (I think bbw may still occur but much lesser?).

Do you have any suggestion? T_PK is primary for insert, its not used in lookups as such.

Thanks in advance

Tom Kyte
February 18, 2004 - 8:43 pm UTC

how do you divvy up the rows? little more detail please.

9i Table Partitioning

Denise, February 18, 2004 - 3:51 pm UTC

Tom

I'm in the the process of transporting some of our
8.1.7 tables to the new db I created on a testserver
that runs Oracle 9i.

One of the tables(prospect)has approx 3mil records.
Those records are basically split into two separate
clients(ACLJ,ACGA)which is stored in the usercode1 column.

I'm planning to create a hash partitioned table
on the 9i database and I have a threefold question:

1) can I import a nonpartitioned table from 8.1.7
into a hash partitioned table on 9i.
Or would I have to do an insert statement?

2) can the 2 partitions be stored within the same tablespace?
some of the examples indicate separate tablespaces for each partition.

3) do I have to hash other tables that are referenced
from this hash partitioned table..such as the GIFT
and ADDRESS tables?


thanks


Tom Kyte
February 18, 2004 - 9:35 pm UTC

1) yes, just create the new table and use ignore=yes on the import

2) sure, they can by -- but it limits the availability features of partitioning.

3) no.

partitioning issue

SR, February 19, 2004 - 1:54 pm UTC

Hi Tom,
insert is done by various clients. There is one-to-one relation between a row and a daemons (they don't stomp on each other and they don't enqueue either) Select is done using C1=:1 and C2=:2. Once done with the work they are set to null. While reading your 1-on-1 book, you mention enabling row movement, we can use partitioning approach. I am kind of interested in that. only thing is almost each and every row will get twice inserted and once deleted. potentially deleted as it gets purged. I am not sure I understood your question on divvying rows.

Thanks again,

Tom Kyte
February 19, 2004 - 2:40 pm UTC

are you sure your bbw's are on the read -- how did you determine that -- how many concurrent "inserts" do you have and are you using ASSM or manual segment space mgt. If doing it manually -- what do you have set for freelists and freelist groups for this set of segments (table, indexes).

why do you believe partitioning will help?

just looking for information.

the divvy up is -- how do you assign rows to the consumers of this data, the guys "selecting" data out.

bitmap index

Shankar, February 19, 2004 - 6:51 pm UTC

Tom, in 9i R2 can we create bitmap Global index? Thanks.

local index partition.

A reader, March 24, 2004 - 11:26 am UTC

Hi tom,

Can you Please tell me from which data-dictionary view
I can find out that the index partition is local or global ?
I tried user_ind_partitions but i can't figure out this partition is local or global ? (if it is not global why there is that key word LOCAL ?)

CREATE INDEX IDX_005 ON t
(ENTITY_ID,CURRENCY)
TABLESPACE FDATA01
INITRANS 2
MAXTRANS 255
STORAGE (
INITIAL 320K
NEXT 320K
MINEXTENTS 1
MAXEXTENTS 1024
PCTINCREASE 0
)
NOLOGGING
LOCAL (
PARTITION Y2000
NOLOGGING
TABLESPACE FDATA01
PCTFREE 0
INITRANS 2
MAXTRANS 255
STORAGE (
INITIAL 20M
NEXT 15M
MINEXTENTS 1
MAXEXTENTS 1024
PCTINCREASE 0
FREELISTS 1
FREELIST GROUPS 1
BUFFER_POOL DEFAULT
),
PARTITION Y2001Q1
NOLOGGING
TABLESPACE FDATA01
PCTFREE 10
INITRANS 2
MAXTRANS 255
STORAGE (
INITIAL 1280K
NEXT 1280K
MINEXTENTS 1
MAXEXTENTS 1024
PCTINCREASE 0
FREELISTS 1
FREELIST GROUPS 1
BUFFER_POOL DEFAULT
)
)
PARALLEL ( DEGREE DEFAULT INSTANCES DEFAULT );



Tom Kyte
March 24, 2004 - 1:10 pm UTC

select index_name, locality from user_part_indexes

Thanks !!

A reader, March 24, 2004 - 1:52 pm UTC


how about function based index ?

A reader, March 24, 2004 - 7:11 pm UTC

if I query the user_ind_coumns for function based index
it gives me alpha numeric #
how can I get the actual column name and property like
asc or desc. (what is the table name where I can find this.)

CREATE INDEX T_IDX_008 ON T
(ID1, "ENTRY_DATE" DESC, ID3)

and like

CREATE INDEX T_IDX_0030 ON T
("FADD"("ID","ID2"))


Thanks,


Tom Kyte
March 25, 2004 - 8:45 am UTC

ops$tkyte@ORA10G> desc user_ind_expressions
 Name                                 Null?    Type
 ------------------------------------ -------- -------------------------
 INDEX_NAME                                    VARCHAR2(30)
 TABLE_NAME                                    VARCHAR2(30)
 COLUMN_EXPRESSION                             LONG
 COLUMN_POSITION                               NUMBER
 

thanks tom.

A reader, March 25, 2004 - 10:05 am UTC


how do I convert ?

A reader, March 25, 2004 - 10:48 am UTC

how can I convert long to varchar or varchar to long ?

select decode(column_expression,null,column_name,column_expression)
from user_ind_expressions uie,user_ind_columns uic
where uic.index_name = uie.index_name (+)
and index_name = 'T_IDX_0030'

select decode(column_expression,null,column_name,column_expression)
*
ERROR at line 1:
ORA-00932: inconsistent datatypes


Tom Kyte
March 25, 2004 - 9:08 pm UTC

You cannot, they are "not the same" and "not convertable"

see
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:55212348054 <code>


thanks,

A reader, March 26, 2004 - 8:57 am UTC

hi tom.

so Oracle developer should not use LONG then why does oracle use it ? and why does oracle put the value in that column ?. From the above question the need of conversion from long to varchar2 is fair I think ? how does oracle displays the "column name" of the function based index ? writing a whole PL/SQL routine ? shouldn't it be done in single query ?(i mean it is just a simle outer join) I tried case stmt too it a same error....

Tom Kyte
March 26, 2004 - 9:35 am UTC

because if we go back and change fundemental things like that, in views that have been around longer than I've been typing code into a terminal, "bad things" could happen.


you can use dbms_metadata to see what you need as well.

Partition table on multiple block size

Vivek Sharma, May 25, 2004 - 8:11 am UTC

Dear Tom,

Chapter 3 of Oracle Documentation states about partition tables that
"All partitions of a partitioned object must reside in tablespaces of a single block size".

What is the reason behind it ? We are planning to create a partition table of an object would like to assign some parititions specific to past data to bigger block size tablespace (non standard block size) and partition specific to present data to standard block size but it seems that it is not possible.

What could be the reason behind it ?

Regards
Vivek

Tom Kyte
May 25, 2004 - 8:38 am UTC

(there are over 100 pieces of Oracle Doc, might want to list the name next time too :)

don't know, but multi-block tablespaces were designed for one purpose only -- to transport tablespaces from blocksize N to blocksize M for some "ETL" processing. They were not really designed in support of anything else.

what were you hoping to achieve? what was the goal?

Oracle Doc.Link

Vivek Sharma, May 25, 2004 - 10:43 am UTC

Dear Tom,

This is the Oracle 9i Documentation, I was talking about.

</code> http://download-west.oracle.com/docs/cd/B10501_01/server.920/a96524/c04space.htm#924 <code>

Our Aim was to make use of Bigger Block Sizes for accessing past data which are read only. To access large number of rows in a single I/O.

Regards
Vivek



Tom Kyte
May 25, 2004 - 11:22 am UTC

oracle uses db_file_multiblock_read_count to do that for you.


when full scanning, we read N blocks at a time. It already "just happens". You don't need a bigger block for that.

Oracle Documentation on Partition Keys

Vivek Sharma, June 19, 2004 - 3:23 pm UTC

Dear Tom,

Oracle 9i Documentation

</code> http://download-west.oracle.com/docs/cd/B10501_01/server.920/a96524/c12parti.htm <code>says

"A partition key: Consists of an ordered list of 1 to 16 columns"

does it mean that if I have a table with columns A to Z then I can create partitions on either of the following keys

1. A, B, C
2. A,B,C,D,E,F,G,H,I,J,K,L,M,N,O,P (16 Keys)

I cannot create partitions on following

1. A,C,F
2. A-R 18 Keys
i.e. there are limitations that the partition keys can have at the most 16 columns and that too they should be ordered as per the table columns.

Thanks and Regards
Vivek


Tom Kyte
June 19, 2004 - 3:35 pm UTC

it means you can pick any 16 columns, in any order, and put them in an ordered list and call that your partition key.


You can create a partition using the key a,c,f
You cannot use 18 columns.





Peterson John, June 21, 2004 - 2:04 pm UTC

Guru,

What is the difference between hash and List partitioning? How do I decide which partition method to use?

Thanks in advance

Tom Kyte
June 21, 2004 - 8:36 pm UTC

well, with hash you are saying "oracle please place my data randomly in these N partitions"

with list you are saying "oracle - please put x=5 in this one, x=6, x=7 in that one and x=8,x=9,x=10 in this other one..."


hash is good for "split it up"
list is good for "you tell us how to split it up"


you'd need to say what your goals are before I could say which is right for you.

Using last_day in range partitioning DDL?

A reader, September 06, 2004 - 6:57 pm UTC

Why cant I use last_day() in the range partitioning DDL?

I know DDL is one-time only but it would be really nice if I could do for example

partition by range (dt)
(partition jan2004 values less than (last_day(to_date('1-jan-2004','dd-mon-yyyy'))+1)

instead of

partition by range (dt)
(partition jan2004 values less than (to_date('1-feb-2004','dd-mon-yyyy'))

Makes it easier to generate a DDL script if each partition DDL contains only one month?

Or maybe I am missing something? Thanks



Tom Kyte
September 07, 2004 - 7:12 am UTC

well, not that i agree with "it makes it easier" (i mean, I know 1-feb-2004, I know 1-aug-2004, I *know* all of the first days -- they are static, they are all "ones"). if you have a function that can generate JAN, it can generate FEB just as easily.

that aside

last_day is a function that just cannot be used there. In general -- functions cannot be used in a partitioning scheme unless they are "known" to return a VALUE. It needs a "value", not an expression.



ones

A reader, September 07, 2004 - 9:23 am UTC

Um, that was my whole point. First days of a month are all well-known, they are all 1! Last days are not, they are sometimes 30, 31, 28 (or 29), etc. So, if I am generating a DDL script to create 48 monthly partitions, I need to take all this into account.

It would have been very convenient to allow last_day() here.

It does return a value just like to_date() does. I mean why is to_date(dt,'format') allowed but last_day(dt) not allowed. Both return a known DATE value?

Thanjs

Tom Kyte
September 07, 2004 - 9:57 am UTC

No more than you need to take into account the fact you are doing 48 months?!?

I mean -- hey, you are already generating the list of months right? So, if you can do that -- you obviously can generate

a) this month (you are -- and you know you can generate next month since you are doing to do next month)
b) next month


to_date is "special", it is recognized as a VALUE (not all of the time, only sometimes -- depends on the date format). to_date has a fixed set of circumstances whereby it can be known to be constant.

last_day is just a function - it is not special. The parser would have to

decompose last_day( expression ) into
expression is really value
last_day( value ) is a value


at some point you just say "sorry, value is needed here, not a function"


Only when to_date is a VALUE -- a constant -- is the "function" to_date permitted. last_day just doesn't have the check "if the input is a value, then so shall be the output".


to_date

A reader, September 07, 2004 - 10:21 am UTC

"to_date has a fixed set of circumstances whereby it can be known to be constant"

"Only when to_date is a VALUE -- a constant -- is the "function" to_date permitted"

Thanks for explaining the last_day() part, but now that you bring up to_date's magicness, what are the cases where it would NOT be allowed? i.e. what situations would make it NOT return a constant?

Thanks


Tom Kyte
September 07, 2004 - 12:03 pm UTC

to_date( '01-jan-04', 'dd-mon-rr' )
to_date( '01-jan-04', 'dd-mon-yy' )


will return different answers depending on what time it is RIGHT NOW.

today -- 7-sept-2004, both will return 2004

5 years ago, the first would return 2004, the second 1904

in 46 years, the first will return 2104, the second 2004




  PARTITION part1 VALUES LESS THAN (to_date('13-mar-03','dd-mon-yy')) tablespace users,
                                            *
ERROR at line 10:
ORA-14120: incompletely specified partition bound for a DATE column
 
 
ops$tkyte@ORA9IR2> !oerr ora 14120
14120, 00000, "incompletely specified partition bound for a DATE column"
// *Cause:  An attempt was made to use a date expression whose format
//          does not fully (i.e. day, month, and year (including century))
//          specify a date as a partition bound for a DATE column.
//          The format may have been specified explicitly (using
//          TO_DATE() function) or implicitly (NLS_DATE_FORMAT).
// *Action: Ensure that date format used in a partition bound for a
//          DATE column supports complete specification of a date
//          (i.e. day, month, and year (including century)).
//          If NLS_DATE_FORMAT does not support complete
//          (i.e. including the century) specification of the year,
//          use TO_DATE() (e.g. TO_DATE('01-01-1999', 'MM-DD-YYYY')
//          to fully express the desired date.
 

 

Thanks

A reader, September 07, 2004 - 1:17 pm UTC


Ron, September 11, 2004 - 11:56 am UTC

Hi Tom
I am summing up data from a huge partitioned table T(range by date..each partition has one day's worth of data).It has 2 years worth of data partitioned by date..



my query goes somethin like this

select
client_id,acct_no,
decode(effective_dt,sysdate,amount,0)yesterday_brokerage,
decode(effective_dt,sysdate-1,amount,0)todays_brokerage,
..
decode(effective_dt,sysdate-11,amount,0)eleven_days_brokerage
from
T
group by
client_id,acct_no

there is an local-partitioned index on client_id,acct_no
is there a better way to write the above query? It takes around 2 hrs to run now.

Also..if i use parallel hint,,would it be of any help
thanks
Ron


Tom Kyte
September 11, 2004 - 1:01 pm UTC

must be a sum or something in there right....

PQ might be useful here -- you are going after all of the data after all

(if you have an existing index on 2 or 3 of the columns -- you might consider adding the third/fourth columns to it so you could index fast full scan instead of tablescan, that is, if the index on client_id, acct_no was extented to include effective_dt,amount....)

Ron, September 11, 2004 - 2:45 pm UTC

sorry...the query actually has a sum
like..
sum(decode(effective_dt,sysdate,amount,0))yesterday_brokerage,
sum(decode(effective_dt,sysdate-1,amount,0))todays_brokerage,
..
there is a primary key on client_id,acct_no and effective_dt..so..adding a non-unique composite index on the all the fields i am pulling(client_id,acct_no,effective_dt,amt) should go for a index fast full scan right?..
Will this add a index maintenance overhead on table T?
The primary key is really not needed in table T..I am planning to drop that and create the non-unique composite index? looking forward to your suggestion?


Tom Kyte
September 11, 2004 - 3:31 pm UTC

you said you already had an index on this table(client_id,acct_no) so you would be just making an already existing index a tad bigger. Yes, it will add overhead -- but you have to decide

a) ping the modification
b) or make the query go faster

Oracle would be able to use the index as a "skinnier version" of the table, reducing the IO needed to scan. PQ would still be applicable here as well. Also, it might be able to make some use of the fact that the data is already "grouped" in the index (maybe)

Is local indexes really local?

Wayne, October 28, 2004 - 2:13 am UTC

Tom,
I have a partitioned table. I disabled (mark them unusable) the bitmap indexes for one partition and started a massive update. While the updating was running (no commit yet), I tried to disable bitmap indexes in another partition, but I got an error: ORA-00054 Resource busy and acquire NOWAIT specified.
Could you explain why? Are local indexes still kind of linked globally?

Thanks,

Tom Kyte
October 28, 2004 - 7:49 am UTC

you are altering the index, setting a partition.....

you are not so much altering the partition, you are alerting the index -- to modify one of its partitions.

they are "really local" (local meaning there is a 1/1 relationship between an index partition and table partition)

Question on index tablespace for partitioned table

A reader, January 13, 2005 - 1:55 pm UTC

I am building a partitioned table (partitioned by month ). I have created a tablespace. for each year for the table, 12 partitions per tablespace.

Can you recommend a best practice for the local indexes and their storage?

Would you recommend the same for the indexes?

Tom Kyte
January 13, 2005 - 2:09 pm UTC

the best practice is "what works best for you"

tablespaces are all about administrative ease of use.

parity works for me. advantage is you can just rebuild an index tablespace rather then restore it if you like.

Question on index tablespace for partitioned table

A reader, January 13, 2005 - 2:50 pm UTC

>>parity works for me

Could you elaborate?

Tom Kyte
January 13, 2005 - 3:44 pm UTC

parity -- do to the indexes that which you are doing to the tables...

Can one partition cluster tables Index or hash clusters? Thanks

reader, January 20, 2005 - 9:34 am UTC


Nice

A reader, January 31, 2005 - 11:45 am UTC

Hi Tom,
Can a particular partition of a partitioned table
be made unavailable?



Tom Kyte
January 31, 2005 - 11:57 am UTC

swap it with an empty table -- is that what you mean? do you just want to take it away for some reason?

Thanks

A reader, January 31, 2005 - 12:05 pm UTC

Hi Tom,
The reason is we need to update it which points to a different geographical location.Actually it is a
Purchase Order vendor Table(po_vendor_sites).Some updation
need to be performed for vendor sites.Any help you can
provide??

Tom Kyte
January 31, 2005 - 12:17 pm UTC

insufficient data.

if you just need to update data -- go ahead, lock the table, update it if you want, or just update it.

Partition of tables in LMT and DMT at same time

George, February 15, 2005 - 2:03 am UTC

Hi Tom,
One simple(silly ?) question on partitioning?. If I create few partiions of table in Dictionary Managed tablespace and few others on Locally Manged tablespace , will it create any problem?

Regards
George/India

Tom Kyte
February 15, 2005 - 3:15 pm UTC

should not, each segment is managed separately, each partition is a segment

Should i go for Non-partitioned index or partitioned index?

Sujit, February 17, 2005 - 3:45 am UTC

I have a partitioned table as given below,

create table TEST_TAB
(
A_CAT NUMBER(3),
A_NUM VARCHAR2(20),
DISC_DATE DATE,
SPARE_1 NUMBER(1),
SPARE_2 NUMBER(2),
SPARE_3 NUMBER(1),
SPARE_4 NUMBER(5),
SPARE_5 NUMBER(5)
)
partition by range (DISC_DATE)
(
partition p1 values less than (to_date('2001021000','yyyymmddhh24')) tablespace UTILD01,
partition p2 values less than (to_date('2001021100','yyyymmddhh24')) tablespace UTILD02,
partition p3 values less than (to_date('2001021200','yyyymmddhh24')) tablespace UTILD03
);

I have primary key on the table like given below,

CREATE UNIQUE INDEX TEST_TAB_PK ON TEST_TAB
(DISC_DATE, A_NUM, A_CAT)
LOCAL (partition p1 tablespace UTILD01_IDX,
partition p2 tablespace UTILD02_IDX,
partition p3 tablespace UTILD03_IDX);

ALTER TABLE TEST_TAB ADD (
CONSTRAINT TEST_TAB_PK PRIMARY KEY (DISC_DATE, A_NUM, A_CAT)
USING INDEX );


Now i have inserted some 50 rows in my table.

When i query the table using A_NUM, it does not use the index (TEST_TAB_PK),

select * from test_tab where a_num = '0';

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=CHOOSE 3 1
PARTITION RANGE ALL 1 3
TABLE ACCESS FULL SCOTT.TEST_TAB 3 2 K 1 1 3

So i created a PARTITIONED Index on TEST_TAB.

CREATE INDEX A_NUM_IDX ON TEST_TAB
(A_NUM) LOCAL (partition p1 tablespace UTILD01_IDX,
partition p2 tablespace UTILD02_IDX,
partition p3 tablespace UTILD03_IDX);

Now when i execute the same query. The index A_NUM_IDX is used but it's cost is showing 4.

select * from test_tab where a_num = '0';

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=CHOOSE 3 1
PARTITION RANGE ALL 1 3
TABLE ACCESS BY LOCAL INDEX ROWID SCOTT.TEST_TAB 3 2 K 1 1 3
INDEX RANGE SCAN SCOTT.A_NUM_IDX 3 4 1 3


No i dropped the index and created a GLOBAL, non-partitioned index on A_NUM.

drop index a_num_idx;

CREATE INDEX A_NUM_IDX ON CDR
(A_NUM)
TABLESPACE UTILD01;

Now when i issue the same query,

select * from test_tab where a_num = '0';

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=CHOOSE 3 1
TABLE ACCESS BY GLOBAL INDEX ROWID SCOTT.CDR 3 2 K 1 ROWID ROW L
INDEX RANGE SCAN SCOTT.A_NUM_IDX 3 1


Now the cost is showing 1 and also the index is used.



So my questions are,

1. Why the index TEST_TAB_PK is not used in the query? (My dba told me only the first column of a composite index will be used in 8i.)

2. Why the partitioned index is showing more cost than the non-partitioned one ? My presumption is as the table has different partition key (DISC_DATE).

3. I have a job ruuning daily which drops the oldest partition of the table and creates new partition. Will my non-partitioned index become UNUSABLE/INVALID? Do i need to rebuilt my index as many times as i drop/create new partitions on the table?

I am using Oracle 8i 8.1.7.4.

Thanx in advance...

Sujit

Tom Kyte
February 17, 2005 - 9:16 am UTC

1) your dba is mostly correct.

think about it -- in general how could an index on (a,b,c) be used for "where b = VALUE"?

the index is sorted by A, within A by B, within B by C.

Suppose A has 1,000,000 values -- there would be 1,000,000 places in the index to look for B=VALUE

In 9i, there is an index skip scan, so the optimizer says "if A has few values, say '10', we can skip scan as we believe there would be 10 places to look for B=VALUE". If A has 1,000,000 values, the optimizer would say "nope, not going to use the index, too many places to look"


In 8i, if you changed the query to

select DISC_DATE, A_NUM, A_CAT from t where a_num = '0'

you would probably be able to show your DBA "you are almost correct", for it would likely use an index fast full scan since all of the columns referenced in the query are in the index itself.


2) because there are N indexes to scan. It has 3 indexes to range scan, the global index - at most 1 partition to scan.

3 partitions more expense than 1.


3) yes. it'll need to be rebuilt. in 9i you can do these operations and maintain the global indexes without having to rebuild.

Using Bind Variables in Partitioned Table

Pradeep Anirudhan, March 24, 2005 - 10:49 am UTC

Hi Tom

I had a query , While using partitioning, should we
use bind variables? For e.g If I have a table having
the sales detail partitioned on sale_date , so while
querying this table based on the sale_date should I be
using bind variable for or not .

Tom Kyte
March 24, 2005 - 3:57 pm UTC

do you run this query over and over and over -- if you are running queries per second, you have to bind.

if you are running queries that take many many seconds, you need not bind.

if this is oltp, you must bind

if this is data warehouse and this is one of the big nasty queries, you need not (might not even want to)

Multi Dimensional Partitions

John Dunn, March 28, 2005 - 4:48 pm UTC

IBM DB2 provides a capability to create multidimension clusters, which are nothing but Partitions and subpartitions at multiple levels, i.e. more than two levels. I know Oracle does allow you to do this at two levels. How can you accomplish this multi level partitioning in Oracle currently indeirectly?? Will oracle be providing this feature in future releases?

Thanks!!

Tom Kyte
March 28, 2005 - 6:22 pm UTC

can you point me to the db2 docs that describe this on the IBM website so I can see what you mean more clearly?

I googled

"multidimensional partitions" db2
"multi dimensional partitions" db2

but could find nothing about them.

partition keys,

sns, March 28, 2005 - 6:23 pm UTC

I have a pretty big table which is range partitioned on couple of columns. I want to know on what columns it is partitioned on. I tried to extract DDL using 3rd party tools and also using dbms_metadata and didn't work.

Is there a easy to figure out what columns the table is partitioned on?

thanks,

Tom Kyte
March 28, 2005 - 6:41 pm UTC

ops$tkyte@ORA9IR2> CREATE TABLE t
  2  (
  3    dt  date,
  4    x   int,
  5    y   varchar2(25)
  6  )
  7  PARTITION BY RANGE (dt)
  8  subpartition by hash(x)
  9  (
 10    PARTITION part1 VALUES LESS THAN (to_date('13-mar-2003','dd-mon-yyyy')) tablespace users,
 11    PARTITION part2 VALUES LESS THAN (to_date('14-mar-2003','dd-mon-yyyy')) tablespace tools,
 12    PARTITION junk VALUES LESS THAN (MAXVALUE)
 13  )
 14  /
 
Table created.
 
ops$tkyte@ORA9IR2> select * from USER_PART_KEY_COLUMNS;
 
NAME                           OBJEC COLUMN_NAM COLUMN_POSITION
------------------------------ ----- ---------- ---------------
T                              TABLE DT                       1
 
ops$tkyte@ORA9IR2> select * from USER_subPART_KEY_COLUMNS;
 
NAME                           OBJEC COLUMN_NAM COLUMN_POSITION
------------------------------ ----- ---------- ---------------
T                              TABLE X                        1
 
ops$tkyte@ORA9IR2>
 

IBM DB2

John Dunn, March 29, 2005 - 10:19 am UTC

Tom,

I believe it is called Multi-Dimensional Clusters or MDC according to the Article I read. I did not make it a point to read the IBM wesite though.. Here is the link to the article on the dbazine website.

</code> http://www.dbazine.com/beulke4.shtml <code>

It talks about the concept of MDC and UNION ALL.

Thanks!!

Tom Kyte
March 29, 2005 - 11:04 am UTC

In Oracle, we would use range partitioning to do that 27 way partition:

ops$tkyte@ORA10G> create table t
  2  ( customer  varchar2(1),
  3    sku_id    number,
  4    region    varchar2(4),
  5    data      varchar2(80)
  6  )
  7  partition by range(customer,sku_id,region)
  8  (
  9   partition part_A_1 values less than ( 'A', 1, 'EU' ),
 10   partition part_A_2 values less than ( 'A', 1, 'US' ),
 11   partition part_A_3 values less than ( 'A', 1, MAXVALUE ),
 12   partition part_A_4 values less than ( 'A', 2, 'EU' ),
 13   partition part_A_5 values less than ( 'A', 2, 'US' ),
 14   partition part_A_6 values less than ( 'A', 2, MAXVALUE ),
 15   partition part_A_7 values less than ( 'A', 3, 'EU' ),
 16   partition part_A_8 values less than ( 'A', 3, 'US' ),
 17   partition part_A_9 values less than ( 'A', 3, MAXVALUE ),
 18   partition part_B_1 values less than ( 'B', 1, 'EU' ),
 19   partition part_B_2 values less than ( 'B', 1, 'US' ),
 20   partition part_B_3 values less than ( 'B', 1, MAXVALUE ),
 21   partition part_B_4 values less than ( 'B', 2, 'EU' ),
 22   partition part_B_5 values less than ( 'B', 2, 'US' ),
 23   partition part_B_6 values less than ( 'B', 2, MAXVALUE ),
 24   partition part_B_7 values less than ( 'B', 3, 'EU' ),
 25   partition part_B_8 values less than ( 'B', 3, 'US' ),
 26   partition part_B_9 values less than ( 'B', 3, MAXVALUE ),
 27   partition part_C_1 values less than ( 'C', 1, 'EU' ),
 28   partition part_C_2 values less than ( 'C', 1, 'US' ),
 29   partition part_C_3 values less than ( 'C', 1, MAXVALUE ),
 30   partition part_C_4 values less than ( 'C', 2, 'EU' ),
 31   partition part_C_5 values less than ( 'C', 2, 'US' ),
 32   partition part_C_6 values less than ( 'C', 2, MAXVALUE ),
 33   partition part_C_7 values less than ( 'C', 3, 'EU' ),
 34   partition part_C_8 values less than ( 'C', 3, 'US' ),
 35   partition part_C_9 values less than ( 'C', 3, MAXVALUE )
 36  )
 37  /
 
Table created.
 
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> insert into t
  2  select c.*, s.*, r.*, 42 from
  3  (select 'A' cust from dual union all select 'B' from dual union all select 'C' from dual ) c,
  4  (select 1 sk from dual union all select 2 from dual union all select 3 from dual ) s,
  5  (select 'EU' reg from dual union all select 'US' from dual union all select 'Asia' from dual ) r
  6  /
 
27 rows created.
 
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> select * from t partition( part_a_1);
 
C     SKU_ID REGI DATA
- ---------- ---- -----
A          1 Asia 42
 
ops$tkyte@ORA10G> select * from t partition(part_b_5);
 
C     SKU_ID REGI DATA
- ---------- ---- -----
B          2 EU   42
 
ops$tkyte@ORA10G> select * from t partition(part_c_9);
 
C     SKU_ID REGI DATA
- ---------- ---- -----
C          3 US   42



If I had the dimensions, I would be able to easily generate the partition clause using "sql" to generate it. 

John Dunn, March 29, 2005 - 11:31 am UTC

Tom,

Thanks. Should have thought about concatenated Range Partitioning myself. Again proves the point Oracle is far and above any other database out there on the market.



Limitation of partitions

Sagar, March 30, 2005 - 3:25 am UTC

Hi Tom,
Do we have any practical limitations on the number of partitions on a table? Also will increasing number of partitons hamper performance, maintenance or any other area you might think of?

Thanks in Advance
Sagar

Tom Kyte
March 30, 2005 - 7:19 am UTC

thousands is perfectly acceptable, 10's of thousands even.

in 10g and beyond -- even more.

the number of partitions is not nearly as relevant as the partition design (do you have Effective Oracle by Design? I discuss the physics of partitioning in there)

how to transfer data

Raaghid, March 31, 2005 - 9:19 am UTC

Now, I have got a good idea about partition. (also gone through your book). (Thanks to Tom)
So now I understood, 1) For what kind of table partition is required 2) What kind of partition type to be created for which nature of table-transaction 3) what kind of index to be created etc...

Now my question is How to convert existing (multiple schema) data to partition based? - client requirement

1- Currently I have schema for each year - say 5 years (5 schema for transaction and 1 schema for master)

2- Client requirement is to merge all data of 5 years, so that they can retrieve across year information through same schema (screen)

3- So i need to put master table into the partition based master tables (it is 1 to 1 only)
and also I need to put all transaction from 5 schema in to one table. ie.(from 5 schema table 'a' data --> will be merged in to new partition schema table 'a') --> And also it is not simple merge in some of the tables, so it will be based on the nature of transaction table.

4- I have decided to do the following:
a- Not allowing transaction for 'x' hours
b- Create new schema with partition table
c- with constraints / but no triggers
d- To write a batch procedure to transfer data from each schema table to the partition schema table..
e- Doing the above in test server before doing it in main server.
d- enable triggers

5- Is this ok, please tell me other ideas and how to go about it.
Thanks in advance/




Tom Kyte
March 31, 2005 - 9:40 am UTC

have you considered a quick and dirty UNION ALL view of the 5 schemas?

followup

Raaghid, April 01, 2005 - 12:40 am UTC

yes. now it is working on that logic only.

While transfering the data from 5 schemas to new partion schema, i am using the same method only but inside the stored procedure.

please confirm the above steps (method of transfering data), whether it is ok.

Tom Kyte
April 01, 2005 - 8:27 am UTC

what is wrong with the union all?

followup

Raaghid, April 02, 2005 - 1:28 am UTC

union all is working fine. The issue is, in some table, the records are repeating. (eg., from schema03-04 some records have been brought in to schema04-05 and while merging we need to take only the latest schema04-05 record. This logic has to be used while combining all data)
That is the reason why, I am going for pl sql stored procedure, in that most of the tables are simple merge and few tables to be merged with certain specific conditions.

Ok now I understood that, union all+view is the best approach and if any specific condition exists, we can go for pl-sql procedure. Is that right Tom.

Tom Kyte
April 02, 2005 - 9:21 am UTC

why don't you just cleanse the data once and for all?

good idea

Raaghid, April 03, 2005 - 12:43 am UTC

This is a good idea. I can make the data perfect (in those tables), and after that, I will do just unionall+view. So that same logic is used for all tables data merging.


(for making data perfect to support union all &view, i will use temporary tables)

Thanks a ton.

Partitioning Question

A reader, April 26, 2005 - 11:02 pm UTC

In one of our databases, we are storing various measurements being collected at every 5-minute interval. The business requirements is to have the data online for the last 13 months. The actual requirements is like this:

Say we want to keep data for months M01, M02 ... M13. (M01 is the most recent month)
For the most recent 3 months (M01,M02,M03) they need all detailed-level data. For the next 3 months (M04-M06), they want to have data aggregated on hourly basis and purge all minute-level data. For the remaining 7 months (M07-M13), the requirement is to have data aggregated at day-level and get rid of minute-level or hourly-level aggregated data.

Now, the team is simple thinking of doing a simple DELETE statement to do this type of work, but I want to use some kind of partitioning so that to purge old data I can use DDL instead of DML. Consider that we will have close to 500K rows each day.

Any suggestions?

Tom Kyte
April 27, 2005 - 7:37 am UTC

partition by month -- sliding window partition.

At the end of each month, follow this process:

a) add next months partition (it'll be empty).

b) take the 4th months partition and do a create table as select to aggregate it up to the hourly level (do the CTAS with the compress option to make it smaller even). Index it if you index.

c) exchange the 4th months details with the 4th month table aggregated up to the hour level.

d) take the 7th month hourly observation and do a create table as select to aggregate it up to the daily lavel.....

e) exchange it.


No DELETES, just create table as selects to aggregate and exchange partitions to slide the aggregated, comressed results back in.

Thanks

A reader, April 27, 2005 - 11:37 am UTC

Thanks Tom.

I did not think of exchange option. Thank you.

decreasing maxvalue in a partition

A reader, April 29, 2005 - 11:00 am UTC

Hi Tom,

I have a table

create table x
(
id number,
xxx varchar2(20)
)
PARTITION BY RANGE(ID)
( PARTITION x_01 VALUES LESS THAN (10000) TABLESPACE X01
);

By mistake I created the partition with a maxvalue of 10000. How can I decrease this to 1000? The max(id) in x right now in 900.

Thanks.

Tom Kyte
April 29, 2005 - 11:07 am UTC

you'd split it and drop the one you didn't want.

A reader, April 29, 2005 - 11:55 am UTC

Hi Tom,

I have never tried it before. Can you show me with an example please?

Thanks.

Tom Kyte
April 29, 2005 - 12:03 pm UTC

alter table split partition is documented.

even has examples
</code> http://docs.oracle.com/docs/cd/B10501_01/server.920/a96540/statements_32a.htm#2110368 <code>




David Aldridge, April 29, 2005 - 3:28 pm UTC

It would be a handy-dandy feature to be able to add a populated and indexed table as a new partition, instead of having to create an empty partition and then exchange it with the table -- it seems to be a logical gap in the partitioning functionality that this operation is not permitted.

Time to write an enhancement request ...

Rebuild indexes and partitions

Wanderer, May 17, 2005 - 11:56 am UTC

Tom,
I am a developer (with some DBA exp) and was recently asked to do a DBA job. Here it is :
Get a 1)partition name on a table,
2)drop that partition
3)rename the indexes on this table to index_name_TEMP
4)recreate the partition exactly as it was
5)rename the indexes back to index_name from index_name_temp.
in Oracle 9i.

I was looking at Data Dictionary for Oracle 9i and found DBA_IND_PARTITIONS and DBA_PART_INDEXES for getting index names for that partition and somewhat confused on how to
go ahead. Can you show me with an example on how to achieve this and from what table i should look for indexes?

I really appreciate your help on this ..
Thanks,

Tom Kyte
May 17, 2005 - 2:14 pm UTC

you can skip 3 and 4, they don't do anything but waste time in this example.

but not sure what this will accomplish. if they just want to empty a partition (which is what it sounds like this is) truncate it. one command.

Wanderer, May 17, 2005 - 2:29 pm UTC

Tom, Thanks for your response. What they need is to see if data exist in old partition (find oldest partiton for this table) and if data exist transfer that data into some file or other table, remove data from this partition , drop that partition and recreate it with same name. I think like you said, truncate makes much sense. So can i just x'fer that data and truncate that partition without reindexes getting affected? or should i worry about indexes?

If truncate is the way ,then can i just truncate the partition like i do table ?

Thanks,


Tom Kyte
May 17, 2005 - 3:01 pm UTC

ok, so you need to swap it out. all you need to do is

a) create a new empty table that looks like the current table
b) create indexes on this table
c) alter table partition_table exchange ....

search for

"exchange partition"

on this site for examples.

How to drop a table partitioning

Irina, May 18, 2005 - 9:30 pm UTC

Hi Tom,

Thank you very much for your site. I do use it quite often for finding answers.

I wonder if it's possible to drop/remove a table partitioning?

I've got a table that has been partitioned by list and I would like to remove this partitioning now.

Thanks

Irina

Tom Kyte
May 19, 2005 - 7:37 am UTC

You could get it to a single partition, but it would still "be a partitioned table"

You would either

a) use create table as select, copy the data, index/grant/constrain it, drop old table and rename new table or

b) use dbms_redefinition (search site for that) to online redefine the partitioned table into a new non-partitioned table.

List Partitioning

AD, May 21, 2005 - 6:12 am UTC

Hi Tom,

Goal : each week I would like to truncate the partitioned table and swap data readily available on a set of temporray tables.

  1  CREATE TABLE sales_list
  2  (salesman_id  NUMBER(5),
  3  salesman_name VARCHAR2(30),
  4  sales_state   VARCHAR2(20),
  5  sales_amount  NUMBER(10),
  6  sales_date    DATE)
  7  PARTITION BY LIST(sales_state)
  8  (
  9  PARTITION sales_west VALUES('California', 'Hawaii'),
 10  PARTITION sales_east VALUES ('New York', 'Virginia', 'Florida'),
 11  PARTITION sales_central VALUES('Texas', 'Illinois'),
 12  PARTITION sales_other VALUES(DEFAULT)
 13* )
SQL> /

Table created.


Now, let's say I have a temporary table that is of the following structure and I want to use this data to swap partition with the Partitioned table. 

  1  create table sales_west_temp
  2  (salesman_id  NUMBER,
  3  salesman_name VARCHAR2(30),
  4  sales_state   VARCHAR2(20),
  5  sales_amount  NUMBER,
  6* sales_date    DATE)
SQL> /

Table created.

SQL> insert into sales_west_temp values (1, 'sales1', 'California', 500, sysdate)
  2  /

1 row created.

SQL> select * from sales_west_temp;

SALESMAN_ID SALESMAN_NAME                  SALES_STATE          SALES_AMOUNT SALES_DATE
----------- ------------------------------ -------------------- ------------ ---------------
          1 sales1                         California                    500 21-MAY-05


SQL> alter table sales_list exchange partition sales_west with table sales_west_temp;
alter table sales_list exchange partition sales_west with table sales_west_temp
*
ERROR at line 1:
ORA-14097: column type or size mismatch in ALTER TABLE EXCHANGE PARTITION
  
  
The only difference in the above two tables are one is partitioned and the other is a regular table.
The other differences are :

sales_west_temp            sales_list
salesman_id  NUMBER          salesman_id  NUMBER(5)
sales_amount  NUMBER          sales_amount  NUMBER(10)

Since my temporary table gets created after a few manipulations etc., it does not have the same size for the number fields. This is causing an issue when I am doing exchange partition. The other option I have probably to use Insert /*+ Append */ .. , but I wanted to avoid this as I have to rebuild the indexes on the resultant partition table which is going to contain at least 10 million records every time I insert data. Could you please help.


Regards
 

Tom Kyte
May 21, 2005 - 8:55 am UTC

your datatypes are wrong.

create the table with the right precision.

I don't understand the comment about the index rebuilds, why would:

create table as select
insert it

be any different than

create table ( x.... )
insert /*+ append */ it
index it





How to select from more than one partition

Baiju Menon, May 23, 2005 - 11:25 pm UTC

Sir,
Say i have one table which has 3 partitions (in different tablespaces). Can i specify the values from three partitions in a single select statement by using the partition clause. Please help.
thanks.

Tom Kyte
May 24, 2005 - 7:35 am UTC

UNION ALL will work.

but -- the predicate would do this as well if you are using RANGE or LIST partitions (just use the proper predicate values)

Partitioning method

Jairo Ojeda, June 17, 2005 - 2:40 pm UTC

Tom, I have a table in witch I need least the last 5 years rows, but it will be query by the users only the last 3 months.
I think to create a range partitioning table by date with 6 partitions (maxvalue) and it is ok.
and I want to create a range subpartitions for quarts of year, but it is an invalid partitioning method --range-range partitioning.
the only near way to do something like that was to create the table with range-hash partitioning both on date column. but if I nee to query the 3rd quarter, it will need to scan more than one subpartition.
Do you have any idea?

Tom Kyte
June 17, 2005 - 4:14 pm UTC

just partition the data by month, I don't know why you are thinking you need composite partitioning?

expert one-on-one chapter 14 (Parititioning) page 638 (Wrox edition)

Menon, June 20, 2005 - 6:37 pm UTC

You say at the bottom:

"The Oracle documentation states that:
local prefixed indexes...


It should really read more like:

loaclly partitioned indexes that are used in QUERIES
that references the entire partition key in
them provide better performance tan for QUERIES
that do not reference the partition key".

Should the last statement be "locally prefixed indexes"
instead of "locally partitioned indexes"? Otherwise
it does not seem to make sense since the first statement
from the doc is talking about locally prefixed indexes
wheres your "correction" is talking about all locally
partitioned indexes".

Congrats on the Silver medal, btw - I think you
deserve nothing less than a gold!

Tom Kyte
June 21, 2005 - 8:01 am UTC

no, I meant partitioned - the comment about locally prefixed indexes in the documentation is misleading in my opinion. They are assuming some things.

they are assuming for example that you are NOT using a predicate on the partition key, in which case the difference between local prefix and local non-prefix is null and void.


if you use any locally partitioned index, and your predicate includes the key used to partition that locally partitioned index, it doesn't matter if it is prefixed or not. It can do the same partition elimination.

OK

Menon, June 20, 2005 - 6:41 pm UTC

Perhaps I misspoke above - still reading it - I think
subsequent lines explain it better...

partition creation SQL

Sandy, August 01, 2005 - 6:08 am UTC

Hi Tom,

I'm planning to code a script which will - after taking in some parameters - generate a DDL script to create a table
with "lots of partitions" - one for each day for the last 3 years.

I'm thinking of using PL/SQL to generate the script and then spool the DDL to an OS file - using UTL_FILE.

However... two things I'm concerned about:

1. Last time I created a big DDL, there were size
issues with using PL/SQL and had to do something else.
Anyway.. hopefully I'll find a way when the time comes
to cross that bridge :-)

2. More importantly - assuming the DDL script does get
created, will it possible to run a "huge" DDL thru
SQL*Plus? Are there any limits?

We are using 10g. If you have any (new?) ideas/ pointers/ recommendations - that will help greatly.

Thanks,
Sandy
P.S: please!!.. do NOT ask why I'm creating 1000's of
partitions... I've given my copy of "Effective Oracle Design" to the "consultant" driving this... and maybe we might get away with lesser... eventually!


Tom Kyte
August 01, 2005 - 7:44 am UTC

1) well, you are not using plsql to execute it, so should not apply. DBMS_SQL has a parse entry that takes a PLSQL table type -- and that can be very very very big indeed (execute immediate -- limited in size, dbms_sql, not so)

2) should be - sqlplus has line WIDTH issues, but not buffer size issues so much.

---- Off the record --- !!

A reader, August 03, 2005 - 4:59 am UTC

Hi Tom,
Wonder if someone has mentioned this before! - but looking at your photo on the books, I was for a moment reminded of David Caruso :-)... and to think of it - in my humble opinion, you are to the Oracle DB what he is to CSI !!
Best Regards,
Sandy

partitioning

reader, August 22, 2005 - 7:40 pm UTC

Is there a ROT for when should one consider partitioning the table? On what basis one should partition the table? any guideline that you could share would be appreciated.

Thanks.

Tom Kyte
August 24, 2005 - 3:42 am UTC

you first have to have a goal:

a) improved query performance (typically only in a warehouse, not OLTP)
b) ease of some admin function (purging of data)

for example. So, what is your goal? Otherwise tables can be quite large without major issues.

Tony

Tony, August 24, 2005 - 11:24 am UTC

I have to implement one logic for that if you can give me some hints that will be helpful.

The logic is...

We have tables with daily partitions... for that we have a retention period also..
For retention for the specific table we are created one table where have table name and retention period..
Every day we are running this mentance job..
What I want to do is
last 2 to 24 partition should go to a_table_space
25 to 48 partition should go to b_table_space
49 to 60 partition should go to c_table_space

only current partition should be there in the current partition...

any idea how to do that ..

I am using USER_tab_partitions to get the PARTITION_POSITION...


Tom Kyte
August 24, 2005 - 6:11 pm UTC

you actually want to move partitions on a schedule to different tablespaces?!?!

Partiotion

Tony, August 24, 2005 - 11:40 pm UTC

Yes Tom,

I am abel to do do the first part usinf the user_tab_partition but next part i am unabel to do...

Can you please help me in this..

Tony

Tom Kyte
August 25, 2005 - 3:32 am UTC

why do you want to move your data from tablespace to tablespace??? That was my point -- to what goal or end?

Why?

Partition

Tony, August 25, 2005 - 5:45 am UTC

Hi Tom,

we have some daily files and we are loading in to daily table.. with the daily partition names like (P20050101)

we have some retention period like 60 days. after that the first partition will be dropped..

and 2 to 23rd we are moving to some partition and 24 to 48 in some different partition etc...
If I am using only this month data I will hit only the current partition and daily we are getting 1 GB data..
In case if I want I can make some tablespace offline and work ...

Tony...




Tom Kyte
August 25, 2005 - 8:33 am UTC

why move -- that is what I want to know? why not just rotate tablespaces, no need to move massive amounts of data, rebuild indexes and so on - just rotate tablespaces.

Partition

Tony, August 26, 2005 - 4:25 am UTC

Rotate tablespace?

I am not aware of it.. How to do that? how it can give benefits?

Tom it will be gratefull if u can explain me this..

Tom Kyte
August 26, 2005 - 8:24 am UTC

Just create new partitions in new tablespaces, leave old partitions in old tablespaces, when old tablespaces get empty, drop them.

Don't move data from tablespace to tablespace, that would be an inefficient use of your time, resources and cause downtime as you move them.

Partition

Tony, August 26, 2005 - 8:39 am UTC

Tom,
Thanks,


kathrin, September 21, 2005 - 9:23 am UTC

I'm thinking about this tablespace rotation.
What are the benefits/trade-offs for:
1) have a fixed set of tablespaces. drop the oldest partition, put the new one in the tablespace that just became empty
2) drop oldest partition with oldest tablespace, create new partition with new tablespace

I'm thinking about catalog, control file, backup,...



Tom Kyte
September 21, 2005 - 7:30 pm UTC

well, tablespace names are not removed from sys.ts$, so over time, ts$ can grow - so if you planned on thousands and thousands of these over time -- rotate.

paritioning advice

Mark, October 20, 2005 - 4:42 pm UTC

Tom,

I have a date column that is frequently found in where clauses in the following ways:

1. finishedate is null
2. finishedate = to_date(...)
3. finishedate between to_date(...) and to_date(...) --usually a matter of days or weeks in the range
4. finishedate is not null

I am thinking about range partitioning the table that contains this date column to improve query performance. I will do a monthly or quarterly range - haven't decided yet. This table has hundreds of thousands of rows, and is selected frequently. (I have arranged the where clauses above by how frequently they appear in queries.)

I read your above answer to a followup from June 27, 2003 about how null values are handled in a hash partition. Does your answer apply to range partitioning as well? If so, do the nulls get thrown into an arbitrary range or are they separate? This could affect my choice of range, since we commonly query "where finisheddate is null"...I really need to get those nulls quickly as possible. Better to have as few non-nulls partitioned with the nulls as possible.

I'm sure that the #2 and #3 queries (search by date/dates) would benefit from this partitioning, but could the "finisheddate is not null" queries be hurt, since each partition is scanned separately? (A strong majority of values for finisheddate are not null.)

Also, about a different table I am considering partitioning: This table tens of thousands of rows, and about 50 distinct values of the clientid column, which appears frequently in where clauses (where clientid=x). But there are many queries that "group by clientid" - clientid does not appear in the where clause. My question: can queries that group in this way take advantage of partition pruning, even if there is no where clause? It seems sensible to me that it should be able to.

One last question while I've got you: Is it possible to both cluster and partition the same table, or are they mutually exclusive strategies? Searching the docs for both keywords gave me no results...

Of course I will run lots of tests/benchmarks, but a little advice in the hypothesizing stage couldn't hurt. :)

Thanks a lot,
Mark

Tom Kyte
October 21, 2005 - 7:51 am UTC

nulls are "BIG"

ops$tkyte@ORA10GR1> CREATE TABLE t
  2  (
  3    dt  date,
  4    x   int,
  5    y   varchar2(25)
  6  )
  7  PARTITION BY RANGE (dt)
  8  (
  9    PARTITION part1 VALUES LESS THAN (to_date('13-mar-2003','dd-mon-yyyy')) ,
 10    PARTITION part2 VALUES LESS THAN (to_date('14-mar-2003','dd-mon-yyyy')) ,
 11    PARTITION junk VALUES LESS THAN (MAXVALUE)
 12  )
 13  /

Table created.

ops$tkyte@ORA10GR1>
ops$tkyte@ORA10GR1> insert into t values ( null, 1, 1 );

1 row created.

ops$tkyte@ORA10GR1> select * from t partition (JUNK);

DT                 X Y
--------- ---------- -------------------------
                   1 1



they'll be in the "last" partition. and partition elmination will work for it:

ops$tkyte@ORA10GR1> @plan "select * from t where dt is null"
ops$tkyte@ORA10GR1> delete from plan_table;

3 rows deleted.

ops$tkyte@ORA10GR1> explain plan for &1;
old   1: explain plan for &1
new   1: explain plan for select * from t where dt is null

Explained.

ops$tkyte@ORA10GR1> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2931986080

---------------------------------------------------------------------------
| Id  | Operation              | Name | Rows  | Bytes |   | Pstart| Pstop |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |      |     1 |    36 |   |       |       |
|   1 |  PARTITION RANGE SINGLE|      |     1 |    36 |   |     3 |     3 |
|*  2 |   TABLE ACCESS FULL    | T    |     1 |    36 |   |     3 |     3 |
---------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("DT" IS NULL)

Note
-----
   - dynamic sampling used for this statement

18 rows selected.


The "finishdt is not null" has to full scan the entire table - the partitioning will be neither a plus nor minus for it.




The last table - you don't say HOW it is partitioned, but I'll assume "by clientid"

If you select all clientids, you cannot prune any partition, they all have data you need. 

RE: Partioning advice

Mark, October 21, 2005 - 9:08 am UTC

Thanks a lot Tom, that clears things up.

About the last table, yes, it would be hash (or possibly list) partitioned by clientid. I understand that all partitions need to be accessed - so no pruning can take place - I shouldn't have used the term "pruning". But I was wondering if these group by queries could take advantage of partitioning by clientid, since each clientid is located with its brethen, in its own happy little partition.

And I now found where you posted the link to the docs: "Oracle supports partitioning only for tables, indexes on tables, materialized views, and indexes on materialized views. Oracle does not support partitioning of clustered tables or indexes on clustered tables."

Thanks again!
Mark

Tom Kyte
October 21, 2005 - 10:16 am UTC

50 values isn't enough to hash on - they would not distributed very well in all likely hood.



global partitioned indexes

A reader, December 14, 2005 - 9:34 am UTC

tom,

i read sometimes about global partitioned indexes. but i never saw nor created one until now. are they really useful?

Tom Kyte
December 14, 2005 - 10:02 am UTC

they are vital.

here is a excerpt from my recent book "Expert Oracle: Database Architecture" on the topic:


<quote>
OLTP and Global Indexes

An OLTP system is characterized by the frequent occurrence of many small read and write transactions. In general, fast access to the row (or rows) you need is paramount. Data integrity is vital. Availability is also very important.
Global indexes make sense in many cases in OLTP systems. Table data can be partitioned by only one key—one set of columns. However, you may need to access the data in many different ways. You might partition EMPLOYEE data by LOCATION in the table, but you still need fast access to EMPLOYEE data by
    *    DEPARTMENT: Departments are geographically dispersed. There is no relationship between a department and a location.
    *    EMPLOYEE_ID: While an employee ID will determine a location, you don’t want to have to search by EMPLOYEE_ID and LOCATION, hence partition elimination cannot take place on the index partitions. Also, EMPLOYEE_ID by itself must be unique.
    *    JOB_TITLE: There is no relationship between JOB_TITLE and LOCATION. All JOB_TITLE values may appear in any LOCATION.
There is a need to access the EMPLOYEE data by many different keys in different places in the application, and speed is paramount. In a data warehouse, we might just use locally partitioned indexes on these keys and use parallel index range scans to collect a large amount of data fast. In these cases, we don’t necessarily need to use index partition elimination. In an OLTP system, however, we do need to use it. Parallel query is not appropriate for these systems; we need to provide the indexes appropriately. Therefore, we will need to make use of global indexes on certain fields.
The goals we need to meet are
    *    Fast access
    *    Data integrity
    *    Availability
Global indexes can us accomplish these goals in an OLTP system. We will probably not be doing sliding windows, auditing aside for a moment. We will not be splitting partitions (unless we have a scheduled downtime), we will not be moving data, and so on. The operations we perform in a data warehouse are not done on a live OLTP system in general.
Here is a small example that shows how we can achieve the three goals just listed with global indexes. I am going to use simple, “single partition” global indexes, but the results would not be different with global indexes in multiple partitions (except for the fact that availability and manageability would increase as we added index partitions). We start with a table that is range partitioned by location, LOC, according to our rules, which place all LOC values less than 'C' into partition P1, those less than 'D' into partition P2, and so on:
ops$tkyte@ORA10G> create table emp
  2  (EMPNO             NUMBER(4) NOT NULL,
  3   ENAME             VARCHAR2(10),
  4   JOB               VARCHAR2(9),
  5   MGR               NUMBER(4),
  6   HIREDATE          DATE,
  7   SAL               NUMBER(7,2),
  8   COMM              NUMBER(7,2),
  9   DEPTNO            NUMBER(2) NOT NULL,
 10   LOC               VARCHAR2(13) NOT NULL
 11  )
 12  partition by range(loc)
 13  (
 14  partition p1 values less than('C') tablespace p1,
 15  partition p2 values less than('D') tablespace p2,
 16  partition p3 values less than('N') tablespace p3,
 17  partition p4 values less than('Z') tablespace p4
 18  )
 19  /
Table created.
We alter the table to add a constraint on the primary key column:
ops$tkyte@ORA10G> alter table emp add constraint emp_pk
  2  primary key(empno)
  3  /
Table altered.
 A side effect of this is that there exists a unique index on the EMPNO column. This shows we can support and enforce data integrity, one of our goals. Finally, we create two more global indexes on DEPTNO and JOB, to facilitate accessing records quickly by those attributes.
ops$tkyte@ORA10G> create index emp_job_idx on emp(job)
  2  GLOBAL
  3  /
Index created.
 
ops$tkyte@ORA10G> create index emp_dept_idx on emp(deptno)
  2  GLOBAL
  3  /
Index created.
 
ops$tkyte@ORA10G> insert into emp
  2  select e.*, d.loc
  3    from scott.emp e, scott.dept d
  4   where e.deptno = d.deptno
  5  /
14 rows created.
Now let’s see what is in each partition:
ops$tkyte@ORA10G> break on pname skip 1
ops$tkyte@ORA10G> select 'p1' pname, empno, job, loc from emp partition(p1)
  2  union all
  3  select 'p2' pname, empno, job, loc from emp partition(p2)
  4  union all
  5  select 'p3' pname, empno, job, loc from emp partition(p3)
  6  union all
  7  select 'p4' pname, empno, job, loc from emp partition(p4)
  8  /
 
PN      EMPNO JOB       LOC
-- ---------- --------- -------------
p2       7499 SALESMAN  CHICAGO
         7698 MANAGER   CHICAGO
         7654 SALESMAN  CHICAGO
         7900 CLERK     CHICAGO
         7844 SALESMAN  CHICAGO
         7521 SALESMAN  CHICAGO
 
p3       7369 CLERK     DALLAS
         7876 CLERK     DALLAS
         7902 ANALYST   DALLAS
         7788 ANALYST   DALLAS
         7566 MANAGER   DALLAS
 
p4       7782 MANAGER   NEW YORK
         7839 PRESIDENT NEW YORK
         7934 CLERK     NEW YORK
14 rows selected.
This shows the distribution of data, by location, into the individual partitions. We can now review some query plans to see what we could expect performance-wise:
ops$tkyte@ORA10G> variable x varchar2(30);
ops$tkyte@ORA10G> begin
  2     dbms_stats.set_table_stats
  3     ( user, 'EMP', numrows=>100000, numblks => 10000 );
  4  end;
  5  /
PL/SQL procedure successfully completed.

ops$tkyte@ORA10G> delete from plan_table;
3 rows deleted.

ops$tkyte@ORA10G> explain plan for
  2  select empno, job, loc from emp where empno = :x;
Explained.

ops$tkyte@ORA10G> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------
| Operation                          | Name   |Rows |Bytes|Pstart|Pstop|
------------------------------------------------------------------------
| SELECT STATEMENT                   |        |    1|   27|      |     |
|  TABLE ACCESS BY GLOBAL INDEX ROWID| EMP    |    1|   27|ROWID |ROWID|
|   INDEX UNIQUE SCAN                | EMP_PK |    1|     |      |     |
------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("EMPNO"=TO_NUMBER(:X))
Note    The explain plan format has been edited to fit on the page. Columns in the report not relevant to the discussion have been omitted.
The plan here shows an INDEX UNIQUE SCAN of the nonpartitioned index EMP_PK that was created in support of our primary key. Then there is a TABLE ACCESS BY GLOBAL INDEX ROWID, with a PSTART and PSTOP of ROWID/ROWID, meaning that when we get the ROWID from the index, it will tell us precisely which index partition to read to get this row. This index access will be as effective as on a nonpartitioned table and perform the same amount of I/O to do so. It is just a simple, single index unique scan followed by “get this row by rowid.” Now, let’s look at one of the other global indexes, the one on JOB:
ops$tkyte@ORA10G> delete from plan_table;
3 rows deleted.

ops$tkyte@ORA10G> explain plan for
  2  select empno, job, loc from emp where job = :x;
Explained.

ops$tkyte@ORA10G> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------
| Operation                          |Name       |Rows |Bytes|Pstart|Pstop|
---------------------------------------------------------------------------
| SELECT STATEMENT                   |           | 1000|27000|      |     |
|  TABLE ACCESS BY GLOBAL INDEX ROWID|EMP        | 1000|27000|ROWID |ROWID|
|   INDEX RANGE SCAN                 |EMP_JOB_IDX|  400|     |      |     |
---------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("JOB"=:X)
Sure enough, we see a similar effect for the INDEX RANGE SCAN. Our indexes are used and can provide high-speed OLTP access to the underlying data. If they were partitioned, they would have to be prefixed and enforce index partition elimination; hence, they are scalable as well, meaning we can partition them and observe the same behavior. In a moment, we’ll look at what would happen if we used LOCAL indexes only. 
Lastly, let’s look at the area of availability. The Oracle documentation claims that globally partitioned indexes make for “less available” data than locally partitioned indexes. I don’t fully agree with this blanket characterization. I believe that in an OLTP system they are as highly available as a locally partitioned index. Consider the following:
ops$tkyte@ORA10G> alter tablespace p1 offline;
Tablespace altered.
 
ops$tkyte@ORA10G> alter tablespace p2 offline;
Tablespace altered.
 
ops$tkyte@ORA10G> alter tablespace p3 offline;
Tablespace altered.
 
ops$tkyte@ORA10G> select empno, job, loc from emp where empno = 7782;
 
     EMPNO JOB       LOC
---------- --------- -------------
      7782 MANAGER   NEW YORK
Here, even though most of the underlying data is unavailable in the table, we can still gain access to any bit of data available via that index. As long as the EMPNO we want is in a tablespace that is available, and our GLOBAL index is available, our GLOBAL index works for us. On the other hand, if we had been using the “highly available” local index in the preceding case, we might have been prevented from accessing the data! This is a side effect of the fact that we partitioned on LOC but needed to query by EMPNO. We would have had to probe each local index partition and would have failed on the index partitions that were not available.
Other types of queries, however, will not (and cannot) function at this point in time:
ops$tkyte@ORA10G> select empno, job, loc from emp where job = 'CLERK';
select empno, job, loc from emp where job = 'CLERK'
                            *
ERROR at line 1:
ORA-00376: file 13 cannot be read at this time
ORA-01110: data file 13: '/home/ora10g/oradata/…/o1_mf_p2_1dzn8jwp_.dbf'
The CLERK data is in all of the partitions, and the fact that three of the tablespaces are offline does affect us. This is unavoidable unless we had partitioned on JOB, but then we would have had the same issues with queries that needed data by LOC. Anytime you need to access the data from many different “keys,” you will have this issue. Oracle will give you the data whenever it can.
Note, however, that if the query can be answered from the index, avoiding the TABLE ACCESS BY ROWID, the fact that the data is unavailable is not as meaningful:
ops$tkyte@ORA10G> select count(*) from emp where job = 'CLERK';
 
  COUNT(*)
----------
         4
Since Oracle didn’t need the table in this case, the fact that most of the partitions were offline doesn’t affect this query. As this type of optimization (i.e., answer the query using just the index) is common in an OLTP system, there will be many applications that are not affected by the data that is offline. All we need to do now is make the offline data available as fast as possible (restore it and recover it).
</quote> 

global partitioned indexes

A reader, December 15, 2005 - 9:28 am UTC

tom,

thanks for posting the excerpt. unfortunately, i am not sure if i got you. you used a global non-partitioned index on a partitioned table. the performance gain came out of the table partitioning! if you have had a global partitioned index you would have had to prefix the index key leading to a fast full scan of the whole index!? where is the performance gain in that case?

please could you demonstrate your advice using a global partioned index on a non-partitioned table?

Tom Kyte
December 15, 2005 - 11:09 am UTC

whether the index is partitioned or not, it is a GLOBAL INDEX.  It shows the benefit of the global index.

the performance gain came from the fact that the indexes were global - and NOT partitioned the same way the table was.

....
 12  partition by range(loc)
 13  (
 14  partition p1 values less than('C') tablespace p1,
 15  partition p2 values less than('D') tablespace p2,
 16  partition p3 values less than('N') tablespace p3,
 17  partition p4 values less than('Z') tablespace p4
 18  )
 19  /
Table created.

ops$tkyte@ORA10G> alter table emp add constraint emp_pk
  2  primary key(empno)
  3  /
Table altered.

ops$tkyte@ORA10G> create index emp_job_idx on emp(job)
  2  GLOBAL
  3  /
Index created.
 
ops$tkyte@ORA10G> create index emp_dept_idx on emp(deptno)
  2  GLOBAL
  3  /
Index created.


Now, if emp_dept_idx was LOCAL - it would be partitioned by LOC and a query of the form:

select * from emp where deptno = 10;

would have to index range scan FOUR indexes to find all of the 10's.  Using a global index (partitioned or NOT) it has to index range scan ONE index to find all of the 10's.

 

global partitioned indexes

A reader, December 16, 2005 - 9:33 am UTC

tom,

thanks for your reply. i can also see the advantages of a global index over a local partitioned index now. but i still doesn't see the advantage of a global _partitioned_ index. can you expand your example to show us the advantages of a global partitioned index over a global non-partitioned index in detail? thanks.

Tom Kyte
December 16, 2005 - 12:40 pm UTC

You would use a global partitioned index for the same reason you would use a partitioned table.

Say you have a TABLE, range partitioned by "date_loaded" into 20 partitions.

Say you have an INDEX on that table, is it on "name"

You would global partition the INDEX so as to be able to hit just one index partition for something like "where name = :x".

But say the index is huge - and you would like it "smaller" so you can administer it more easily. You could range (or hash in 10g) partition the global index into 10 manageable bite sized pieces (10 partitions)

But say you query it frequently like "select distinct name from t where name between :x and :y" and it would like to do fast full scan on the global index, by range partitioning it, we can employ partition elimination to reduce the amount of index we fast full scan.

Take any reason you would have for partitioning a table - it would apply to a global index.

partition by function

A reader, February 09, 2006 - 2:02 pm UTC

Hi

Is it possible partition using a function? I would like to partition by even and odd numbers such as

partition by range(mod(ID, 2))
(partition x1 values less than (1),
partition x2 values less than (2))

I tried to run it in 9iR2 but it fails with this error

ERROR at line 10:
ORA-00907: missing right parenthesis

Thanx

Tom Kyte
February 10, 2006 - 11:31 am UTC

no, you cannot, you would have to store that column as a derived column.




multi-column range partition

GMA, February 23, 2006 - 3:43 pm UTC

This was most useful combined with a similar article on global indexes.

I have a strange situation, and maybe I'm just doing something wrong or oracle is doing some kind of date conversion. 

I have to partition a table based on Y or N values, and then the N values need to be further classified by date. The 'Y' partition with be completely exchanged every night, but the N partition needs to store 18 months of data, and the partitions will be dropped as time goes by.

I created a prototype scripts with baffling results, and am wondering why all the N data goes into the first partition even though it is further partitioned by date.

I know that another way of doing this would be to have a seperate column to_char(entry_date, 'yyyymm'), and then list partitoin by this .. but we want to avoid doing this.

Here is what I have:-

SQL> create table gma_test_part (entry_date date, acct_id varchar2(12), pending_trd_fl varchar2(1))
  2  PARTITION BY RANGE (pending_trd_fl, entry_date)
  3  (
  4   PARTITION PN_2000601 VALUES LESS THAN ('X', TO_DATE('01-JAN-2006','DD-MON-YYYY')),
  5   PARTITION PN_2000602 VALUES LESS THAN ('X', TO_DATE('01-FEB-2006','DD-MON-YYYY')),
  6   PARTITION PN_2000603 VALUES LESS THAN ('X', TO_DATE('01-MAR-2006','DD-MON-YYYY')),
  7   PARTITION PN_MAX VALUES LESS THAN        ('X', MAXVALUE),
  8   PARTITION PY_MAX VALUES LESS THAN        ('Z', MAXVALUE)
  9  );

Table created.

SQL> insert into gma_test_part values(TO_DATE('12-DEC-2005','DD-MON-YYYY'),'123', 'N');

1 row created.

SQL>
SQL> insert into gma_test_part values(TO_DATE('17-FEB-2006','DD-MON-YYYY'), '123', 'N');

1 row created.

SQL>
SQL> insert into gma_test_part values(TO_DATE('01-JAN-2007','DD-MON-YYYY'),'123', 'N');

1 row created.

SQL>
SQL> insert into gma_test_part values(TO_DATE('12-DEC-2005','DD-MON-YYYY'), '123', 'Y');

1 row created.

SQL>
SQL> insert into gma_test_part values(TO_DATE('17-FEB-2006','DD-MON-YYYY'), '123', 'Y');

1 row created.

SQL> COMMIT;

Commit complete.

SQL> select * from gma_test_part partition (PN_2000601) ;

ENTRY_DAT ACCT_ID      P
--------- ------------ -
12-DEC-05 123          N
17-FEB-06 123          N
01-JAN-07 123          N

WHY IS ALL THE DATA IN THIS PARTITION??

SQL> select *  from GMA_TEST_PART PARTITION (PY_MAX);

ENTRY_DAT ACCT_ID      P
--------- ------------ -
12-DEC-05 123          Y
17-FEB-06 123          Y
 

Tom Kyte
February 23, 2006 - 7:46 pm UTC

because it does vector comparisons and the ranges are always strictly less than.

'N' < 'X' - stop comparing, we found it.

http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:1200046826714

Maybe what you want is something like this:


ops$tkyte@ORA9IR2> create table gma_test_part
  2  (entry_date date,
  3   acct_id varchar2(12),
  4  pending_trd_fl varchar2(1) check (pending_trd_fl in ('Y','N')) not null
  5  )
  6  PARTITION BY RANGE (pending_trd_fl, entry_date)
  7  (
  8   PARTITION PN_200601 VALUES LESS THAN ('N', TO_DATE('01-JAN-2006','DD-MON-YYYY')),
  9   PARTITION PN_200602 VALUES LESS THAN ('N', TO_DATE('01-FEB-2006','DD-MON-YYYY')),
 10   PARTITION PN_200603 VALUES LESS THAN ('N', TO_DATE('01-MAR-2006','DD-MON-YYYY')),
 11   PARTITION PN_EXTRA  VALUES LESS THAN ('N', maxvalue),
 12   PARTITION PY_MAX VALUES LESS THAN     ('Y', MAXVALUE)
 13  );

Table created.

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> insert into gma_test_part
  2  select to_date('01-jan-2006','dd-mon-yyyy')+mod(rownum,100)-30,
  3         object_id,
  4             decode( mod(rownum,2), 0, 'Y', 'N' )
  5    from all_objects;

30919 rows created.

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select 'PN_200601', count(*), pending_trd_fl, min(entry_date), max(entry_date)
  2  from gma_test_part partition(pn_200601) group by pending_trd_fl union all
  3  select 'PN_200602', count(*), pending_trd_fl, min(entry_date), max(entry_date)
  4  from gma_test_part partition(pn_200602) group by pending_trd_fl union all
  5  select 'PN_200603', count(*), pending_trd_fl, min(entry_date), max(entry_date)
  6  from gma_test_part partition(pn_200603) group by pending_trd_fl union all
  7  select 'PN_EXTRA', count(*), pending_trd_fl, min(entry_date), max(entry_date)
  8  from gma_test_part partition(pn_extra) group by pending_trd_fl union all
  9  select 'PY_MAX', count(*), pending_trd_fl, min(entry_date), max(entry_date)
 10  from gma_test_part partition(py_max) group by pending_trd_fl ;

'PN_20060   COUNT(*) P MIN(ENTRY MAX(ENTRY
--------- ---------- - --------- ---------
PN_200601       4645 N 03-DEC-05 31-DEC-05
PN_200602       4635 N 02-JAN-06 30-JAN-06
PN_200603       4326 N 01-FEB-06 27-FEB-06
PN_EXTRA        1854 N 01-MAR-06 11-MAR-06
PY_MAX         15459 Y 02-DEC-05 10-MAR-06
 

Serge Shmygelsky, March 02, 2006 - 5:33 am UTC

Hello Tom,

I have a table storing calls partitioned by range of dates (separate partition for each day) and subpartitioned by type of the call. I want to enforce uniqueness with the following rule: any phone number can make only one call of specific type at any given point of time. But the question is that for some calls phone number is missing as it's a kind of supplementary call performed in the background and it shouldn't contain real phone number. E.g.

partition 1 for 01-MAR-2006
subpartition 1 - contains all 'real' calls of type 1
phone_num call_type call_date
111 1 01-MAR-06 01:00
112 1 01-MAR-06 01:00

partition 1 for 01-MAR-2006
subpartition 2 - contains all 'supplementary' calls
phone_num call_type call_date
2 01-MAR-06 01:00
2 01-MAR-06 01:00


How can I create a unique index as these supplementary calls prevent me from doing this? I've manage to create global FBI:

create unique index calls_idx on calls
(case when call_type = 1 then phone_num else null end,
case when call_type = 1 then call_date else null end,
case when call_type = 1 then call_type else null end)

but I really don't like it because it is FBI and it is global.
Is there a way to create local index using my conditions?

Thanks in advance



Tom Kyte
March 02, 2006 - 12:22 pm UTC

uniqueness needs a global index with partitioned tables - unless the partition key is part of the unique key (think about concurrency issues otherwise)....

So you will HAVE to use a global index.

And since you want to only enforce this uniqueness for call_type = 1, the function based index is the only way to do it (given your existing model and data).

What is wrong with the function based index? Once you create it, you cannot tell the "difference".

And the global index is a given in this case.

Unique index - ctd

Serge Shmygelsky, March 03, 2006 - 2:52 am UTC

Hello Tom,

Thanks for your answer. But it is not quite clear.

You say: 'uniqueness needs a global index with partitioned tables - unless the partition key is part of the unique key'

Here is my table:
CREATE TABLE calls
(
call_type_id NUMBER(3) NOT NULL,
record_type_id NUMBER(1) NOT NULL,
customer_type_id NUMBER(1) NOT NULL,
call_date DATE NOT NULL,
duration NUMBER NOT NULL,
cid VARCHAR2(4) NOT NULL,
msc_no VARCHAR2(8) NOT NULL,
is_deleted VARCHAR2(1) NOT NULL,
imei VARCHAR2(16),
imsi VARCHAR2(15),
dn_num VARCHAR2(24),
b_number VARCHAR2(24),
trunk_in VARCHAR2(8),
trunk_out VARCHAR2(8)
)
PARTITION BY RANGE ( call_date )
SUBPARTITION BY LIST ( call_type_id )

So the fields I've mentioned are partition keys: CALL_DATE, CALL_TYPE_ID. Thus I'd like to have a unique local index on (CALL_TYPE_ID, CALL_DATE, DN_NUM).

I've tried to create different indexes:

1 create unique index calls_idx1 on calls (
2 case when call_type_id = 1 then call_date else null end,
3 case when call_type_id = 1 then call_type_id else null end,
4 case when call_type_id = 1 then dn_num else null end
5 )
6* local
GUARD@REX> /
create unique index calls_idx1 on calls (
*
ERROR at line 1:
ORA-14039: partitioning columns must form a subset of key columns of a UNIQUE index


GUARD@REX> ed
Wrote file afiedt.buf

1 create unique index calls_idx1 on calls (
2 call_date,
3 call_type_id,
4 dn_num
5 )
6* local
GUARD@REX> /
create unique index calls_idx1 on calls (
*
ERROR at line 1:
ORA-01452: cannot CREATE UNIQUE INDEX; duplicate keys found

Duplicate keys are found in the partition which I really don't care about with 'supplementary' calls. But what I do care about is the partition containing 'real' calls which must be unique. Is there a way which allows a kind of 'skipping a partition in index'?

The reason why I don't like global index is that the table is going to be very big (~6G per day * at least 3 years). So the index itself is going to be quite big

Thanks in advance.

P.S. Thanks for your new book. It helped me a lot with this task. But not with local partitioned indexes yet :). Hope to get help directly from the author :)

Tom Kyte
March 03, 2006 - 8:11 am UTC


1 create unique index calls_idx1 on calls (
2 case when call_type_id = 1 then call_date else null end,
3 case when call_type_id = 1 then call_type_id else null end,
4 case when call_type_id = 1 then dn_num else null end
5 )
6* local
GUARD@REX> /
create unique index calls_idx1 on calls (
*
ERROR at line 1:
ORA-14039: partitioning columns must form a subset of key columns of a UNIQUE
index



your partition keys are call_type_id, call_date.

Your index is NOT ON THEM, your index is on something entirely different.

Therefore, your index must be global.

Partitioned indexes - ctd

Serge Shmygelsky, March 03, 2006 - 10:51 am UTC

Yes, in the first case it is true. But in the second case I've tried to use exactly these columns + one more column. But now after some reflection I can see that my goal is infeasible and I need to modify the last column in the index in the way it is not null because otherwise duplicate values are inevitable in index partition.

Finally I got it:

create index calls_idx on calls( call_date, call_type_id, decode (dn_num, null, decode (imsi, null, imei, imsi), dn_num)) local

Thanks.

Truth is born in discussions :)

Will it be faster?

Eddy Mak, March 06, 2006 - 3:42 am UTC

Hi Tom,

I have a very big historical data table. I am thinking if I convert the table into partition table. Because I need to make use of the date to locate records, I plan to partition the data by date range and create an index for that key locally.

I wonder if a same query runs faster on the partition table than the original table. Please advise.

Many thanks for help.

Tom Kyte
March 06, 2006 - 8:39 am UTC

Answer is

o yes
o no
o maybe

meaning "it totally depends". If you would like a more in depth discussion on this with examples and such - I have it in my last book. Basically, you need to understand the work the database will do - that is "you will need to understand the physics of the data here and the questions you ask"



Will it run faster?

Eddy Mak, March 07, 2006 - 2:47 am UTC

I know there are some parallelism settings for the tablespaces to speed up the query. However, if I have no such setup and only convert the big table into partition table where the partitions resides on the same disk drive. I assume same indexes created in both tables. Under such assumptions, will it run faster?

I tried to simulate the cases with ~10,000 dump records in both tables. I checked their explain plans and they looked same. So does it mean there is no performance gain in partition table?

Thank you.

Tom Kyte
March 08, 2006 - 4:25 pm UTC

there are no parallelism settings for tablespaces?

and a query might

a) run faster
b) run (a lot) slower
c) not be affected at all

by parallel query.


Will it run faster - yes, no, maybe - that is always the answer.


You really need to understand the physics behind partitioning, it is NOT fast=true, in fact - it can make your queries go many times slower if applied incorrectly. If you are interested in my write up of this - I did put it all down in writing in my latest book Expert Oracle Database Architecture.

Will it run faster - ctd

Serge Shmygelsky, March 07, 2006 - 3:49 am UTC

To Eddy

I dared answering your question instead of Tom because I've been investigating on the same task for the last couple of weeks. I hope Tom won't be offended :)

Assuming your task is to select data based on partition key,
I have created 2 tables of the same structure and containing the same set of values. But one table is partitioned. Look:

SHMYG@REX> create table calls (call_date date not null, phone_number varchar2(9), constraint pk_calls primary key (call_date, phone_number
));

SHMYG@REX> insert into calls (select sysdate, level from dual connect by level < 10001);

SHMYG@REX> select count(*) from calls;

COUNT(*)
----------
10000

SHMYG@REX> exec dbms_stats.gather_table_stats( 'SHMYG', 'CALLS');

SHMYG@REX> explain plan for select * from calls where call_date = trunc( sysdate );

SHMYG@REX> @p

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
Plan hash value: 90142470

-----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 12 | 2 (0)| 00:00:01 |
|* 1 | INDEX RANGE SCAN| PK_CALLS | 1 | 12 | 2 (0)| 00:00:01 |
-----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - access("CALL_DATE"=TRUNC(SYSDATE@!))

SHMYG@REX> create table calls2 (call_date date not null, phone_number varchar2(9))
partition by range (call_date)
(
partition part_1 values less than ( to_date ('08.03.2006', 'DD.MM.YYYY')),
partition part_2 values less than (maxvalue)
);

SHMYG@REX> insert into calls2 (select sysdate, level from dual connect by level < 10001);

SHMYG@REX> create index calls2_idx on calls2( call_date, phone_number) local;

SHMYG@REX> alter table calls2 add constraint pk_calls2 primary key (call_date, phone_number) using index;

SHMYG@REX> exec dbms_stats.gather_table_stats( 'SHMYG', 'CALLS2');

SHMYG@REX> explain plan for select * from calls2 where call_date = trunc( sysdate );
SHMYG@REX> @p


PLAN_TABLE_OUTPUT
-----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 12 | 2 (0)| 00:00:01 | | |
| 1 | PARTITION RANGE SINGLE| | 1 | 12 | 2 (0)| 00:00:01 | KEY | KEY |
|* 2 | INDEX RANGE SCAN | CALLS2_IDX | 1 | 12 | 2 (0)| 00:00:01 | KEY | KEY |
-----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("CALL_DATE"=TRUNC(SYSDATE@!))
SHMYG@REX>

It is quite simple testcase and it doesn't show how much you can gain using partitioning approach. But obviously plans are different - in the second case Oracle takes the only one partition which can contain the data you've asked for. If you have really big table like I do (6G per day), performance will increase dramatically.

Of course, don't forget to build partitioned index.

HIH.


partition advise -- 10gR2

Baqir Hussain, March 08, 2006 - 12:15 pm UTC

I am new to this concept and going through your book to get more understanding of it.
There is ONLY one table "POSITION" and it's structure will be as follows:
REV NUMBER(6) NOT NULL,
VEHICLE_TAG VARCHAR2(20 BYTE) NOT NULL,
REPORT_TIME TIMESTAMP(6) NOT NULL,
LATITUDE NUMBER(11,7) NOT NULL,
LONGITUDE NUMBER(11,7) NOT NULL,
SPEED NUMBER(10,3) NOT NULL,
HEADING NUMBER(10,2) NOT NULL,
TRAIN_ASSIGNMENT VARCHAR2(20 BYTE),
PREDICTABLE NUMBER(1) NOT NULL,
LAST_TIMEPOINT VARCHAR2(20 BYTE)

My primary concern with the Positions table is query speed. Eventually we expect to have approximately 1200 vehicles feeding data - resulting in approximately 1 million records per day.

I would like your opinion on the best method of structuring the Positions table to optimize query times. The majority of the queries will be by date or vehicle ID.

Thanks in advance.

Tom Kyte
March 09, 2006 - 12:33 pm UTC

umm, would sort of really depend on.....


what the queries are.

partition -- 10R2

Baqir Hussain, March 13, 2006 - 4:33 pm UTC

The position table will have 100 milliion records to start with and 1 million records will be added to "position" table every day.
The following procedure will be used to get a report from the position table.

CREATE OR REPLACE FUNCTION get_mileage_positions
str_veh_tag IN varchar2) RETURN CLOB IS
(str_start_time IN varchar2, str_end_time IN varchar2, str_veh_tag IN varchar2) RETURN NUMBER IS
strCur_route_line rail_lines8307.Route_key%TYPE;
strNext_route_line rail_lines8307.Route_key%TYPE;

numCur_measure Number;
numNext_measure Number;

numFromCurToIntersection Number;
numFromIntersectionToNext Number;

numTotal_dist Number := 0;

bool_first_iteration BOOLEAN := TRUE;

TYPE recVehGPS Is RECORD (vehicle_tag Varchar2(20),
report_time TimeStamp,
train_assignment Varchar2(20),
location MDSYS.SDO_GEOMETRY,
latitude NUMBER,
longitude NUMBER);

sdoIntersection_pt MDSYS.SDO_GEOMETRY;
sdoCur_proj_pt MDSYS.SDO_GEOMETRY;
sdoNext_proj_pt MDSYS.SDO_GEOMETRY;

returnString CLOB;
boolDEBUG Boolean := FALSE; --TRUE;--
numCounter NUMBER := 0;

--User defined object type created under system schema
stackTrainAssignments stack;
strCurTrainAssignment Varchar2(50);

CURSOR cursVehGPS is
SELECT Vehicle_Tag, Report_Time, Train_Assignment, mdsys.sdo_geometry(2001,8307,mdsys.sdo_point_type
(Longitude, Latitude,NULL),NULL,NULL)As Geom, Latitude, Longitude
FROM positions
WHERE Report_Time Between to_date(str_start_time, 'MM/DD/YYYY HH12:MI PM') AND to_date(str_end_time, 'MM/DD/YYYY HH12:MI PM')
AND Vehicle_Tag IN (str_veh_tag)
Order By report_time;
BEGIN

DBMS_OUTPUT.PUT_LINE('strNext_route_line: ');

FOR recVehGPS IN cursVehGPS LOOP

IF(bool_first_iteration = TRUE) THEN
--OPEN cursVehGPS;
--FETCH cursVehGPS INTO recVehGPS;

SELECT rl.Route_Key INTO strCur_route_line
FROM rail_lines8307 rl
WHERE SDO_NN(rl.geom,mdsys.sdo_geometry(2001,8307,mdsys.sdo_point_type
(recVehGPS.longitude, recVehGPS.latitude,NULL),NULL,NULL), 'sdo_num_res=1') = 'TRUE';


SELECT SDO_LRS.PROJECT_PT(rl.geom,recVehGPS.geom)
INTO sdoCur_proj_pt
FROM Rail_Lines8307 rl
WHERE rl.route_key = strCur_route_line;

Select SDO_LRS.get_measure(sdoCur_proj_pt)
INTO numCur_measure
FROM Rail_Lines8307 rl
WHERE rl.route_key = strCur_route_line;

strCurTrainAssignment := recVehGPS.Train_Assignment;

bool_first_iteration := False;
ELSE


SELECT rl.Route_Key INTO strNext_route_line
FROM rail_lines8307 rl
WHERE SDO_NN(rl.geom,mdsys.sdo_geometry(2001,8307,mdsys.sdo_point_type
(recVehGPS.longitude, recVehGPS.latitude,NULL),NULL,NULL), 'sdo_num_res=1') = 'TRUE';


SELECT SDO_LRS.PROJECT_PT(rl.geom,recVehGPS.geom )
INTO sdoNext_proj_pt
FROM Rail_Lines8307 rl
WHERE rl.route_key = strNext_route_line;

SELECT SDO_LRS.get_measure(sdoNext_proj_pt)
INTO numNext_measure
FROM Rail_Lines8307 rl
WHERE rl.route_key = strNext_route_line;




IF(strCur_route_line = strNext_route_line) THEN

numTotal_dist := numTotal_dist + abs(numNext_measure - numCur_measure);

If(boolDEBUG) Then
returnString := returnString || ' (|' || to_char(numTotal_dist) || '| next-' || to_char(numNext_measure) || ' cur-' || to_char(numCur_measure) || ') ';
End If;

numCur_measure := numNext_measure;
ELSE
If(boolDEBUG) Then

DBMS_OUTPUT.PUT_LINE('strCur_route_line: '||strCur_route_line);
DBMS_OUTPUT.PUT_LINE('strNext_route_line: '||strNext_route_line);
End If;




SELECT sdo_lrs.get_measure((SELECT SDO_LRS.PROJECT_PT(rl.geom,(SELECT SDO_GEOM.SDO_INTERSECTION(cur.geom, next_rail.geom, 0.5) FROM Rail_Lines8307 cur, Rail_Lines8307 next_rail WHERE cur.route_key = strCur_route_line AND next_rail.route_key = strNext_route_line)) As Prj FROM Rail_Lines8307 rl WHERE rl.route_key = strCur_route_line))
INTO numFromCurToIntersection
FROM Rail_lines8307 rl
WHERE rl.route_key = strCur_route_line;

SELECT sdo_lrs.get_measure((SELECT SDO_LRS.PROJECT_PT(rl.geom,(SELECT SDO_GEOM.SDO_INTERSECTION(cur.geom, next_rail.geom, 0.5) FROM Rail_Lines8307 cur, Rail_Lines8307 next_rail WHERE cur.route_key = strCur_route_line AND next_rail.route_key = strNext_route_line)) As Prj FROM Rail_Lines8307 rl WHERE rl.route_key = strNext_route_line))
INTO numFromIntersectionToNext
FROM Rail_lines8307 rl
WHERE rl.route_key = strNext_route_line;
--NOTE: Double Check this section
numTotal_dist := numTotal_dist + abs(numFromCurToIntersection - numCur_measure) + abs(numFromIntersectionToNext - numNext_measure);

If(boolDEBUG) Then
-- return strCur_route_line || ' <-> ' || strNext_route_line;
returnString := returnString || ' (|LineChange| ' || ' |' || to_char(numTotal_dist) || '| next-' || to_char(numNext_measure) || ' cur-' || to_char(numCur_measure) || ' Cur_line-'||strCur_route_line || ' Next_line-'||strNext_route_line || ') ';
returnString := returnString || ' (|LineChange| ' || ' |numFromCurToIntersection-|' || to_char(numFromCurToIntersection) || '| numCur_measure-|' || to_char(numCur_measure) || '| numFromIntersectionToNext-|' || to_char(numFromIntersectionToNext) || '| numNext_measure-|' || to_char(numNext_measure) || ')';
--returnString := returnString || ' (|LineChange| ' || ' |intersection-|' || sdoIntersection_pt. || ')';
End If;

strCur_route_line := strNext_route_line;
sdoCur_proj_pt := sdoNext_proj_pt;
numCur_measure := numNext_measure;


END IF;
End IF;
numCounter := numCounter + 1;
END LOOP;

--calculateExpectedMileage(stackTrainAssignments stack);

If(boolDEBUG) Then
--return (to_char(numCounter) || '|' || returnString);
return 0;
Else
Return round((numTotal_dist/1609.34),3); --'T';--
End If;
END get_mileage_positions;

/



Please advise. Thanks



Tom Kyte
March 14, 2006 - 10:02 am UTC

you miss my point.

In "text" you would say what you are doing. You do not give people pages of code and expect them to reverse engineer it.


Do you understand how partitioning works?

If so, look at your queries and ask yourself "will I be able to get the data efficiently using physical organization 'X' of the data?"

If not, you really need to get that understanding first (if interested - I think the chapter I have on this in my latest book is pretty good - but the data warehousing guide, free on otn.oracle.com, is pretty good too).


My point was - as with all things - you have to look at the questions you are going to ask of the data in order to see if your physical structures are optimal for doing so.

hash or range or list,

sns, March 15, 2006 - 4:23 pm UTC

How do you know whether the table is HASH partitioned, RANGE partitioned OR LIST partioned table? If it is a composite partition (RANGE and HASH),I can get that information from COMPOSITE column in DBA_TAB_PARTITIONS.

One more question: Can a composite partition be LIST and HASH?

Thanks,

Tom Kyte
March 15, 2006 - 5:40 pm UTC

select table_name, partitioning_type from user_part_tables;


composite is RANGE plus something else.

Partitioning a table with a XMLType column

Espen Rydningen, March 16, 2006 - 6:06 am UTC

Hi Tom,

thanks for a greate site. You have helped me out of a lot of troublesome situations, and I hope you can answer me on this. 

I have a table with a XMLType column, and I want to partition this table. I also want to make assure that the lob is stored in the same tablespace. But when I use the ordinary create statement, I get "ORA-00904: "BAR": invalid identifier".

I've made an example for you:

-------

SQL> conn sys@b2b as sysdba
Enter password:
Connected.
SQL> create tablespace fubar2006 datafile '/oradata/oracle/b2bdata/b2b/fubar2006.dbf' size 50M autoextend on next 50M ex
tent management local segment space management auto;

Tablespace created.

SQL> conn b2b_utv@b2b
Enter password:
Connected.

SQL> CREATE TABLE fubar
  2  (
  3    fu date,
  4    bar SYS.XMLType
  5  )
  6  partition by range( fu )
  7  ( partition fubar2006
  8    values less than ( To_Date( '01.01.2007', 'DD.MM.YYYY' ) ) tablespace fubar2006
  9    lob( bar ) store as SEG_BAR_2006 ( tablespace fubar2006 )
 10  )
 11  ;
  lob( bar ) store as SEG_BAR_2006 ( tablespace fubar2006 )
       *
ERROR at line 9:
ORA-00904: "BAR": invalid identifier

------

If I change the datatype to BLOB it is successful:

------

SQL> CREATE TABLE fubar
  2  (
  3    fu date,
  4    bar BLOB
  5  )
  6  partition by range( fu )
  7  ( partition fubar2006
  8    values less than ( To_Date( '01.01.2007', 'DD.MM.YYYY' ) ) tablespace fubar2006
  9    lob( bar ) store as SEG_BAR_2006 ( tablespace fubar2006 )
 10  )
 11  ;

Table created.

------

Even if I use the datatype to CLOB it is successful:

------
SQL> CREATE TABLE fubar
  2  (
  3    fu date,
  4    bar CLOB
  5  )
  6  partition by range( fu )
  7  ( partition fubar2006
  8    values less than ( To_Date( '01.01.2007', 'DD.MM.YYYY' ) ) tablespace fubar2006
  9    lob( bar ) store as SEG_BAR_2006 ( tablespace fubar2006 )
 10  )
 11  ;

Table created.

-------

Are you are able to help me out here ?

Thank you.

-Espen 

Tom Kyte
March 16, 2006 - 2:15 pm UTC

the blob is not really "visible" here, bar is NOT a blob, it is an xmltype with a hidden magic attribute.


... I also
want to make assure that the lob is stored in the same tablespace. ...

in this case, you get your wish, they will be without the LOB() clause at all.

Partitioning a table with a XMLType column, part II

Espen Rydningen, March 17, 2006 - 4:46 am UTC

Hi Tom,

thank you for your answer. I got a bit bewildered by: "(...) bar is NOT a blob, it is an xmltype with 
a hidden magic attribute.(...)". 

Anyway, I did some more research based on your answer and got som confusing results :

------
create tablespace tbs1 datafile '/u02/oracle/oradata/d02/tbs1.dbf' size 20M;
create tablespace tbs2 datafile '/u02/oracle/oradata/d02/tbs2.dbf' size 20M;

create table FUBAR
(
  FU  DATE
 ,BAR SYS.XMLType
 )
partition by range( FU )
( partition part_one    
 values less than ( To_Date( '01.01.2004', 'DD.MM.YYYY' ) ) tablespace TBS1
, partition part_two
 values less than ( To_Date( '01.01.2005', 'DD.MM.YYYY' ) ) tablespace TBS2
)

SQL> select *
  2  from USER_LOBS;

TABLE_NAME COLUMN_NAME   SEGMENT_NAME              TABLESPACE_NAME
---------- ------------- ------------------------- ---------------
FUBAR      SYS_NC00003$  SYS_LOB0000053580C00003$$ USERS                         

SQL>
  1  select *
  2  from USER_SEGMENTS
  3  where SEGMENT_NAME = 'FUBAR'
  4* or SEGMENT_NAME = 'SYS_LOB0000053580C00003$$'
SQL> /

SEGMENT_NAME              PARTITION_NAME SEGMENT_TYPE     TABLESPACE_NAME
------------------------- -------------- ---------------  ---------------
FUBAR                     PART_ONE       TABLE PARTITION  TBS1
FUBAR                     PART_TWO       TABLE PARTITION  TBS2
SYS_LOB0000053580C00003$$ SYS_LOB_P33    LOB PARTITION    TBS1
SYS_LOB0000053580C00003$$ SYS_LOB_P34    LOB PARTITION    TBS2                          

SQL> select TABLE_NAME COLUMN_NAME LOB_NAME PARTITION_NAME PART_NAME, LOB_PARTITION_NAME LOB_PAR_NAME
  2  from USER_LOB_PARTITIONS;

TABLE_NAME COLUMN_NAME  LOB_NAME                  PART_NAME LOB_PART_NAME
---------- ------------ ------------------------- --------- -------------
FUBAR      SYS_NC00003$ SYS_LOB0000053580C00003$$ PART_ONE SYS_LOB_P33
FUBAR      SYS_NC00003$ SYS_LOB0000053580C00003$$ PART_TWO SYS_LOB_P34       

------

The USER_LOBS view states that the table FUBAR has its segment in the USERS tablespace, but the USER_SEGMENTS view states that segments are in tablespace TBS1 and TBS2. Can you explain this for me?

- Espen 

Tom Kyte
March 17, 2006 - 5:27 pm UTC

user_lobs is not "partition aware"

use user_lob_partitions - ignore user_lobs for partitioned lobs - it doesn't have visibility into the partitions.

partitioning versus non partitioned with index

Menon, May 18, 2006 - 12:58 pm UTC

Hi Tom
We have a scnenario where a table is huge an in OLTP system. We dont really have any non performance reason for paritioning the table(that is we dont need to partition for the reason of administrative ease/maintenance/availability etc.) We have two options:
1. Partition by range for a date column
2. Index the column with the table being non partitioned

Assuming that we are interested in tuning a query that uses this partition, should we use an index or should we partition? In other words, assuming we only are considering query performance, is partition pruning faster or is using an index faster? What are the issues one would consider here.

Thanx!

Tom Kyte
May 19, 2006 - 10:05 am UTC

why are you partitioning then.

You've said what you are NOT partitioning for.

What is the goal with partitioning (and in oltp, improved "performance" is likely not a goal to be achieved with partitioning, you have to be careful not to NEGATIVELY impact performance in oltp with partitioning in most cases)


if you have expert oracle - database architecture, I cover the in's and out's of using partitioning in various scenarios.

thanx tom!

Menon, May 19, 2006 - 1:07 pm UTC

Yes - I do have the book though not right now with me :)
The scenario we have is:

table t, relevant columns a, b, c.

if you just select rows by column a, you get lot of rows. You need to use column b and c to narrow down to the low number of rows (actually one row).

Our query in question, uses all the columns.
The query looks as follows:

begin
SELECT x, y, ROWID, ....
INTO ...
FROM t
WHERE b = :b
AND c IN (20, 30)
ANd a = :a;

Now there are two options:

Option 1: List Partition by "a" and create local index on b, c.

Option 2: Create one index on a, b, c on a non partitioned table t.

How would you choose which option to go to. From what I read in your book, it seems that option 2 is the right one. We are running experiments as we speak so I will let you know what the results are. Again, our motivation is not availability/maintenance etc. - only performance.

Tom Kyte
May 20, 2006 - 4:18 pm UTC

wholly insufficient data.

Why do you want to partition.

You've said what reasons you DON'T have for partitioning.

Until I have a reason for wanting to partition, I'm not going to partition.

just to report our results

Menon, May 19, 2006 - 9:05 pm UTC

We created two tables with data copied from production.

t_no_part - no partitions, a regular index on a,b,c

t_part - partition on a, local index on a,b,c.

The query on t_part took 3 seconds, the query on t_no_part took 36 seconds - there is quiet a bit of difference in I/O as well - though mostly the physical reads are the one that are much higher in the slower query.

Regardless, the question is. What is the reason that in one case a partition pruning on column "a" and an index range scan access on a local index on columns a,b, and c is faster than a simple index range scan on columns a, b and c on an unpartitioned table. The question is how partition pruning helped such an index access.

The exact query structure - if it matters -is slightly different from what I posted earlier:

select ..
from <table>
where a= ?
b = ?
order by c;

In particular the third column "c" is not in the where clause but still the index column prevents a sort from happenning in both cases (partitioned/unpartitioned)

Your thoughts would be very much appreciated!

Thanx for your help as always!

Tom Kyte
May 20, 2006 - 4:43 pm UTC



Now, the partitioning (list partitoining) in this case will have the side effect that data is clustered by values of A. If you say though that b and c make this almost unique - I'd be interested in seeing the tkprof

Thank you!

Menon, May 22, 2006 - 10:10 am UTC

I guess if partitioning clusters, that may be an explanation. There were two queries we were working on - the one that we tested on Friday does not return just one row - it returns around 80k rows. That may explain why at least in this case, the clustering would make the index access faster. We will need to test the other similar query from a different table (where we only get one row as the result of the query.) I suspect tkprof for this query is no longer that interesting to you? Btw, does clustering of data happen only for list partition or for other types too? Thanx!

Tom Kyte
May 22, 2006 - 3:54 pm UTC

partitioning *forces physical location of data*

anything that does that cluster.


range partition by DATE - day1 here, day2 there, day3 over here, .... then all of day1 data will be together - regardless of how it arrives over time.

hash partition - anything that hashes together will be together (not really useful for predicable clustering therefore)

range and list, will always clump together data by the partition key in a predicable fashion. All data in the "range" or in the "list" will be together.

Thanx Tom!

Menon, May 24, 2006 - 5:54 pm UTC

That explains the results we saw.

So can we conclude the following (assume performance is the sole consideration - administrative ease / maintenance etc are not being considered and we are considering case I mentioned earlier in my question)?

If you are doing index range scan that returns lots of rows (what is "lots" is subjective, of course), then even for OLTP systems, you may get performance benefit from partitioning due to natural clustering of data in the partitioned column.

On the other hand, if we have a similar case (see the question above) but we return very few rows then partitioning may not help since the index range scan retrieves only few rows and hence does not benefit from clustering. In such cases, partitioning solely for performance reason may not make sense and we may as well have a non partitioned table with a normal index.

PS: we have not tested the second case (where we return only a few rows yet - I will post results once we do.)


Tom Kyte
May 25, 2006 - 1:29 pm UTC

<quote>
If you are doing index range scan that returns lots of rows (what is "lots" is
subjective, of course), then even for OLTP systems,
</quote>

large range scans are not characteristic of OLTP :)

You are retrieving what sounds like 10's of thousands of records (3 seconds, you get lots of records in 3 seconds)....

You need to

a) look at what you are trying to accomplish
b) understand the physical structures available
c) apply them

as always...


True

Menon, May 25, 2006 - 4:59 pm UTC

"large range scans are not characteristic of OLTP :) "

Our system is a mixed one. This particular query is used in a a process that needs to retrieve around 80 k records and process them in the middle tier.

Going back to the questions and ignoring the word "OLTP" for now:) can we make the following conclusions:

If you are doing index range scan that returns lots of rows (what is "lots" is subjective, of course), then you may get performance benefit from partitioning due to natural clustering of data in the partitioned column.

On the other hand, if we have a similar case (see the question above) but we return very few rows then partitioning won't help since the index range scan
retrieves only few rows and does not benefit from clustering. In such cases, partitioning solely for performance reason may not make sense and we may
as well have a non partitioned table with a normal index.

I just want to know if my understanding of partitioning viz. a viz index range scan is accurate.


Tom Kyte
May 25, 2006 - 6:03 pm UTC

80k records is DEFINITELY not an OLTP thing.

clustering of data that is queried together will benefit the retrieval of that data - defintely. And there are many ways to cluster that data - b*tree clusters, hash clusters, sorted hash clusters, index organized tables, ......

forget partitioning for a moment. physically colocating data that is queried together....

partition key

mal, May 29, 2006 - 4:49 pm UTC

Tom, I have following table and I am planning to partition it.I dont have any experience in partitioning.Can you please help me to find partition key?

Name Null? Type
----------------------------------------- -------- ----------------------------
VEHICLE_ID NOT NULL NUMBER
VIN NOT NULL VARCHAR2(17)
SELLER_VEHICLE_CODE VARCHAR2(30)
YEAR NUMBER(4)
MAKE_ID NUMBER
MODEL_ID NUMBER
SERIES_ID NUMBER
BODY_STYLE_ID NUMBER
STYLE_ID NUMBER
EXTERIOR_MAP_COLOR_ID NUMBER
INTERIOR_MAP_COLOR_ID NUMBER
MAKE_NAME VARCHAR2(32)
MODEL_NAME VARCHAR2(64)
SERIES_NAME VARCHAR2(45)
BODY_STYLE_NAME VARCHAR2(60)
MILEAGE NUMBER
DOORS NUMBER(1)
DRIVETRAIN VARCHAR2(32)
TRANSMISSION VARCHAR2(50)
SPEEDS NUMBER(1)
ENGINE_NAME VARCHAR2(100)
CYLINDERS NUMBER(2)
DISPLACEMENT NUMBER(6,1)
TURBO NUMBER(1)
FUEL_TYPE VARCHAR2(16)
EXTERIOR_COLOR_DESCRIPTION VARCHAR2(64)
INTERIOR_COLOR_DESCRIPTION VARCHAR2(64)
LICENSE VARCHAR2(16)
REGISTRATION_STATE_ID NUMBER
REGISTRATION_ZIPCODE_ARC NUMBER
REGISTRATION_EXPIRE_DATE DATE
GROUNDED NUMBER(1)
EXPECTED_GROUNDING_DATE DATE
BUYER_ORGANIZATION_ID NUMBER
SELLER_ORGANIZATION_ID NUMBER
LOCATION_ID NUMBER
SYSTEM_ID NOT NULL NUMBER
VEHICLE_STATUS_ID NOT NULL NUMBER
ACTIVE NOT NULL NUMBER(1)
CREATE_DATE NOT NULL DATE
CREATE_PERSON_ID NUMBER
MODIFY_PERSON_ID NUMBER
CONSIGNOR_ID NUMBER
VEHICLE_TYPE_ID NUMBER
TRUCK NUMBER(1)
CONDITION_TYPE_ID NUMBER
RELEASE_TO_AUCTION NUMBER(1)
STOCK_NUMBER NUMBER
PICTURE_REFERENCE VARCHAR2(64)
LAST_UPDATE_DATE NOT NULL DATE
CERTIFICATION_ID NUMBER
VIN_TYPE_ID NUMBER
LAST_UPDATE_STATUS_DATE NOT NULL DATE
CAR_GROUP_CONFIG_ID NUMBER
REGISTRATION_ZIPCODE VARCHAR2(10)
COUNTRY_ID NOT NULL NUMBER
REMARKETING_TYPE VARCHAR2(3)
SELLER_EXTERNAL_ARBITRATED NOT NULL NUMBER(1)
SELLER_MODEL_CODE VARCHAR2(50)
ACCP_MARKETING_PROGRAM NUMBER(1)
AUCTION_TRANSPORT_PROBLEM NOT NULL NUMBER(1)
VIEWED NUMBER(1)
FEATURED NOT NULL NUMBER(1)

Tom Kyte
May 30, 2006 - 9:24 am UTC

hahaha

thanks for the smile this morning, this is like "where's waldo".


ouch.


Do you have access to any of my books - I describe how to think about partitioning, when and where you might use it.

You sort of need a 'goal' first.

Then, we need to understand the usage of this data.

Then we can start looking for the hidden partition key.


<quote src=Expert Oracle Database Architecture>

Partitioning Overview

Partitioning facilitates the management of very large tables and indexes using "divide and conquer" logic. Partitioning introduces the concept of a partition key that is used to segregate data based on a certain range value, a list of specific values, or the value of a hash function. If I were to put the benefits of partitioning in some sort of order, it would be

1. Increases availability of data: This attribute is applicable to all system types, be they OLTP or warehouse systems by nature.

2. Eases administration of large segments by removing them from the database: Performing administrative operations on a 100GB table, such as a reorganization to remove migrated rows or to reclaim "whitespace" left in the table after a purge of old information, would be much more onerous than performing the same operation ten times on individual 10GB table partitions. Additionally, using partitions, we might be able to conduct a purge routine without leaving whitespace behind at all, removing the need for a reorganization entirely!

3. Improves the performance of certain queries: This is mainly beneficial in a large warehouse environment where we can use partitioning to eliminate large ranges of data from consideration, avoiding accessing this data at all. This will not be as applicable in a transactional system, since we are accessing small volumes of data in that system already.

4. May reduce contention on high-volume OLTP systems by spreading out modifications across many separate partitions: If you have a segment experiencing high contention, turning it into many segments could have the side effect of reducing that contention proportionally.

Let's take a look at each of these potential benefits of using partitioning.
</quote>

Mohamed, May 30, 2006 - 10:58 am UTC

In one project I have collaborated in implementing it, when we started range partitioning we have never and never ask our self what will be the main where clauses in the main end user requests. We have partitioned in a way that we can archive our application very easily.

Today after more than 4 years, our application has not yet been archived. In addition we have in our application no "partition pruning" at all. We have a serious problem of performance. And we are denormalising in order to build performant requests.

This is due to the fact that we have used a technical date as a partitioning key and this technical date has no functional meaning so that it doesn't appear in the different where clauses.



Tom Kyte
May 30, 2006 - 11:01 am UTC

Sounds like you needed to have used a global index or two...

yet did not.


In a transactional system, care must be taken to NOT NEGATIVELY IMPACT performance with the addition of partitioning, it'll be extremely rare for partitioning to enhance performance in a transactional system.

And it almost always requires the use of global indexes in order to not NEGATIVELY impact transactional performance.

Ginormous Table Partitioned or Not....

Robert, June 01, 2006 - 9:35 am UTC

9iR2
If, on development instance, I query all_tables (WHERE PARTITIONED = 'YES') and see no results.
Does that necessarily mean on Production instance there is no partitioned tables as well ?

SQL>select * from
(select to_char(num_rows/1000000,'99G999D99MI') million_rows, partitioned, last_analyzed from all_tables
WHERE num_rows IS NOT NULL order by num_rows desc)
where rownum < 11;

MILLION_ROWS PARTITIONED LAST_ANALYZED
------------ ----------- -------------
   271.71    NO          5/27/2006 6:0
    53.70    NO          5/27/2006 6:3
    45.63    NO          5/12/2006 6:0
    43.52    NO          5/15/2006 11:
    41.49    NO          5/27/2006 7:3
    40.58    NO          5/15/2006 3:3
    31.46    NO          5/27/2006 9:4
     6.96    NO          5/27/2006 5:0
     6.38    NO          5/27/2006 9:1
     6.27    NO          5/27/2006 7:5
 

Tom Kyte
June 01, 2006 - 11:04 am UTC

...
9iR2
If, on development instance, I query all_tables (WHERE PARTITIONED = 'YES') and
see no results.
Does that necessarily mean on Production instance there is no partitioned tables
as well ?
.......

well, in a word:

No.

I don't know your policies and procedures, hence I cannot say that your development and production instances are precise mirrors of eachother.

that and there is the fact that the ALL_* views are not "all" tables in the entire database, just ALL of the stuff YOU are allowed to see.

Script to dynamically determine partitioned INDEX usage

Robert, June 09, 2006 - 1:24 pm UTC

Tom,

I saw your script near the top of this thread to display the counts for a given table partition....

Do you have a script handy to dynamically report on the counts for an INDEX partition (e.g. using dba_ind_partitions.high_value) ?

Thanks,

Robert.

Tom Kyte
June 09, 2006 - 1:42 pm UTC

well, if AT LEAST one of the indexed columns is NOT NULL - then the count is exactly the same as for the table itself.

It would only be if ALL of the columns are NULLABLE that there would be a difference in cardinality between the index and the table.

Why do you need this? In general it won't different greatly from the table. And since you MUST use the cbo, maybe the statistics in the dictionary would be a better than good enough "estimate" ?


Of course... the index statistics

Robert, June 09, 2006 - 2:10 pm UTC

Tom,

Why do I need this?....

We are splitting/rebuilding some table/index partitions on a very large table. I am preparing extensive scripts and documentation to investigate, report, and execute this and I am wanting to get table/index info for partition usage before/after the partition splits.

So "why rebuild the wheel" huh :)
Great idea, Tom... I think I can get all info I need from index stats.

Thanks!

Robert

how many levels of partitions?

A reader, June 16, 2006 - 1:50 pm UTC

Tom,

I have a table which is partitioned by year/month and sub-partitioned by region. Now the application has a need to add a sub-sub-partition (for the lack of a better term) in which region data is catagorized as book1 data and book2 data.

Can there be a way to partition further than a sub-partition?

Thanks


Tom Kyte
June 16, 2006 - 7:18 pm UTC

nope

partition a big table

Alay, June 23, 2006 - 5:05 am UTC

Hi Tom,
I have one big table of size 30GB which contains some around 6 Crore rows. Now I want to create partition on this big table. So please suggest me a best method so I can convert this big table to partition table with minimum downtime. Please explain me with example.

Thanks.

Tom Kyte
June 23, 2006 - 10:18 am UTC

search this site for dbms_redefinition

Local Index for partition

A reader, July 21, 2006 - 2:48 pm UTC

For creating a local index, is it necessary to include the partition key as part of the
index , if , in the query , I always use the partition key as a predicate?

This is for a non-unique index.

Say I have a table SALES, partitioned by region and I always use the parition key
(region_key) predicate to access the table. Now my query always looks up data for
the region_asset_key (multiple rows for a given asset in a region) :

select * from SALES
where region_key = :1 -----> partition_key
and region_asset_key = :2

Since I ALWAYS use the partition key to access the SALES table, isn't it sufficient to
create the LOCAL index only on region_asset_key.

CREATE INDEX i_sales_region_asset_key ON SALES (region_asset_key) LOCAL ;

Is there any reason to add the partition key which region_key to the index ???
Is there any difference between the two accesses ?

Please advise


Tom Kyte
July 23, 2006 - 7:48 am UTC

that is known as a "non-prefixed local index" and it is permitted. Partition elimination in this case will in fact happen - yes.

<quote src=Expert Oracle Database Architecture>

Local Indexes

Oracle makes a distinction between the following two types of local indexes:

* Local prefixed indexes: These are indexes whereby the partition keys are on the leading edge of the index definition. For example, if a table is range partitioned on a column named LOAD_DATE, a local prefixed index on that table would have LOAD_DATE as the first column in its column list.

* Local nonprefixed indexes: These indexes do not have the partition key on the leading edge of their column list. The index may or may not contain the partition key columns.

Both types of indexes are able take advantage of partition elimination, both can support uniqueness (as long as the non-prefixed index includes the partition key), and so on. The fact is that a query that uses a local prefixed index will always allow for index partition elimination, whereas a query that uses a local non-prefixed index might not. This is why local non-prefixed indexes are said to be “slower” by some people—they do not enforce partition elimination (but they do support it).

There is nothing inherently better about a local prefixed index as opposed to a local nonprefixed index when that index is used as the initial path to the table in a query. What I mean by that is that if the query can start with “scan an index” as the first step, there isn’t much difference between a prefixed and a nonprefixed index.
</quote>

Very useful

Srinivasa Rao Bachina, July 24, 2006 - 7:29 am UTC

Hi Tom,

I have a table table_a_old(sub_id varchar2(30),bal_info varchar2(4000))
the data in this table will of the format(10,'[1~10~20][2~0~0]...[10~100~100]').The column bal_info stores the information about
bal_id,bal_amount and change_amount for 10 balances in the format[id~bal~change]....

Now we decided to migrate this application in to the next version,so as the data also.In the new version the table_a_new will have the format
(sub_id varchar2(30),
bal_amount_1 number(38,6),change_amount_1 number(18,6),
....................
bal_amount_10 number(38,6),change_amount_10 number(18,6))


The tables are partitioned,for migration we are using the alter table exchange partition option....we are doing in this way

create temp_table as
select
subid,
to_number(substr(balances_info,instr(balances_info,'~',1,1)+1,instr(balances_info,'~',1,2)-instr(balances_info,'~',1,1)-1)) bal_amount_1,
substr(balances_info,instr(balances_info,'~',1,2)+1,instr(balances_info,']',1,1)-instr(balances_info,'~',1,2)-1) change_amount_1,
.................
from team_a_old partition(partition_name)

after the above step we are exchanging the temp_table with the table_a_new.
the columns in the temp_table bal_amount_1 will be having data type of number ,where as the column bal_amount_1 in the table_a_new will be
number(38,6) ,while exchanging the table with one of the partitions of table_a_new , we are getting ora-14097 error.

How to get rid of this error
OR
Please let me know the efficient way of migrating the data.
We have more than 10 miliion rows in the old table.

Tom Kyte
July 24, 2006 - 10:27 am UTC

ouch - the proverbial "out of the frying pan and straight into that pesky fire" example. Neat. We'll go from a bunch of strings to the classic MS Access schema.

why not just one big old create table as select? you can create partitioned tables that way too.

or just insert /*+ APPEND */ into the partitioned table you created.

why bother with this extra step at all - go from "old" to "new" - but better yet, take a long lunch and really think about "using _N on a column name". Is it really your best approach.

[tkyte@localhost ~]$ oerr ora 14097
14097, 00000, "column type or size mismatch in ALTER TABLE EXCHANGE PARTITION"
// *Cause: The corresponding columns in the tables specified in the
// ALTER TABLE EXCHANGE PARTITION are of different type or size
// *Action: Ensure that the two tables have the same number of columns
// with the same type and size.


I would have described the two tables to see what types are "wrong" and use CAST on the create table as select to fix it.

or better yet, stop using this step all together.

Reader

Bonnie, August 02, 2006 - 7:05 pm UTC

Hi Tom,

I have a couple of problems relating to table partitions and hope you can give me some pointers:

1)I have a few tables created with a range partition using invalid values. Can I change these values without rebuilding the tables via an alter table command or something simular?

ie: Table created with wrong values

create table t(mnthdate, name varchar2(12))
PARTITION BY RANGE (dt)
(
PARTITION P_janVALUES LESS THAN ('1')
LOGGING
TABLESPACE SEVT,
PARTITION P_feb VALUES LESS THAN ('2')
LOGGING
TABLESPACE SEVT
PARTITION P_mar VALUES LESS THAN ('3')
LOGGING
TABLESPACE SEVT)

The values I wanted needs a 0 prefix like:

create table t(mnth date, name varchar2(12))
PARTITION BY RANGE (mnth)
(
PARTITION P_janVALUES LESS THAN ('01')
LOGGING
TABLESPACE SEVT,
PARTITION P_feb VALUES LESS THAN ('02')
LOGGING
TABLESPACE SEVT
PARTITION P_mar VALUES LESS THAN ('03')
LOGGING
TABLESPACE SEVT)


2) We are in the process of migrating to 9i from 8i. I would like to utilize the range-list composite index once we're in 9i. Can I add a list partition to an existing range partitioned table using an alter table command to add the new partition or subpartition?

Your help is greatly appreciated.

Bonnie




Tom Kyte
August 03, 2006 - 9:15 am UTC

you would have to figure out the splits and merges necessary there. You cannot just "change" the values. You have to take the existing partitions and split/merge/add to them.

you have to rebuild that table if you want to add that second layer of partitioning - every bit of data you have will have to MOVE.

Bonnie, August 03, 2006 - 7:18 pm UTC

Thank you Tom. That's very helpful!


Perromrance in OLTP databases

A reader, August 14, 2006 - 2:36 pm UTC

Hi Tom,
Follwing is from
</code> http://download-west.oracle.com/docs/cd/B14117_01/server.101/b10743/partconc.htm <code>
Here are a few guidelines for OLTP applications:

Global indexes and unique, local indexes provide better performance than nonunique local indexes because they minimize the number of index partition probes.

My question is: Should't the document mention
"Local prefixed" instead "unique, local indexes ".

Local prefixed anyway limit to one index partition. Why Index need to unique to proble only one partition.
Thanks for your help.




Tom Kyte
August 14, 2006 - 3:07 pm UTC

that is "not a good way to say it" actually. I've always had problems with the wording there.

All indexes, when partitioned properly, allow for the minimization of index partition probes.

All indexes, when partitioned inappropriately, will hit more partitions than necessary.

global, local, prefixed, non-prefixed.


They all permit the same degree of partition elimination
They all permit the inappropriate use.

I would disagree with their statement.

Index on partitioned key

Dilipkumar Patel, September 12, 2006 - 3:02 am UTC

Hi Tom,

Generally we are not keeping index on the partitioned key column.

I have one very big table, range partitioned on day_key (YYYYMMDD). Daily 6 Million records are getting added and this table stores data of 180 days. The queries on the table involved one condition

select day_key, a, b, c
from big_table
where day_key = (select max(day_key) from big_table)

Only issue with select max(day_key) query. If we pass day_key value, it gives result immediately.

If we create local bitmap index on day_key.

select max(day_key) from big_table gives result in seconds.

Can we have other alternatives, as maintanance of this index is also time consuming.

Thanks

Dilipkumar Patel

Tom Kyte
September 12, 2006 - 8:30 am UTC

and what happens if you don't have the index.

plans, creates (simple ONES to illustrate with), all would be good for example.

Index on the partitioned key column.

Dilipkumar Patel, September 12, 2006 - 10:24 am UTC

Hi Tom,

This is explain plan and other details.

With no indexes


----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost | Pstart| Pstop |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 6 | 414K| | |
| 1 | SORT AGGREGATE | | 1 | 6 | | | |
| 2 | PARTITION RANGE ALL| | | | | 1 | 162 |
| 3 | PARTITION LIST ALL| | | | | 1 | 18 |
| 4 | TABLE ACCESS FULL| DAILY_ACCT_BAL | 508M| 2908M| 414K| 1 | 2916 |
----------------------------------------------------------------------------------------

With index on the table

------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Pstart| Pstop |
------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 6 | 466 (0)| | |
| 1 | SORT AGGREGATE | | 1 | 6 | | | |
| 2 | PARTITION RANGE ALL | | | | | 1 | 162 |
| 3 | PARTITION LIST ALL | | | | | 1 | 18 |
| 4 | BITMAP INDEX SINGLE VALUE| DAB_DAYKEY_INDX | | | | 1 | 2916 |
------------------------------------------------------------------------------------------------------

As for with index, query have not to visit whole table, as DAY_KEY present itself on the index.

On executing query without index, wait events are showing scattered read (FULL Table scan) on the table.



Tom Kyte
September 12, 2006 - 11:01 am UTC

where is the example? I see no tables, I don't know the partitioning scheme really and I don't see a single query.

Sourabh, September 21, 2006 - 9:37 am UTC

Hi Tom,

</code> http://www.comp.dit.ie/btierney/Oracle10gDoc/server.101/b10743/partconc.htm <code>

The above document states that even though if we apply To_DATE funciton on the partition key , partition pruning will take place.
I tried it on Oracle 10g but it didn't worked.Could you please clarify the same.



Tom Kyte
September 22, 2006 - 2:03 am UTC

I don't know what they meant by "with the exception of the to_date function".

If you partitioned a table by a DATE column - it would not make sense to apply to_date to it.

If you partitioned a table by a STRING column - using to_date would make it not be a string anymore and partition elimination would not work.

So, how do you anticipate using the to_date function in a sensible fashion in this case?

Partition Management - Performance using Month as Range for full date data

Terry Pratt, September 25, 2006 - 1:02 pm UTC

The details in the previous posts are most helpful in confirming the value of partitions in our case. We have a large table where each month ~5,000,000 rows are added and the data older than 6 months (based on the transaction month, not full transaction date) is deleted.

We are plaaning to partition the table so the a truncate command can be used to purge the data (currently a 10 hour process to perform the logical deletes).

My question is around creating and maintaining the partitions. We can create new partitions for the new data each month or perhaps once each year, with the appropriate range for the data, but this requires setting the ranges and partitions well into the future or some monthly maintenance. I did see references to setting the ranges to a month, but I'm not clear on the technique to accomplish this or the performance implications either loading or querying the data.

Perhaps the answer is a simple NO, but before I have a process created to manage creating new partitions and deleting (or swapping) old ones I want to be sure of my options.

#1 Is there a way to define the ranges based on a date column regardless of the year?

Any insight would be appreciated.

Regards,

Terry Pratt



Tom Kyte
September 26, 2006 - 1:58 am UTC

I'm not sure what you mean by "define the ranges based on a date column regardless of the year?"

Date ranges are strictly less than - so you would always just use the first day of the next month (and the only way to specify a specific month would include having a year there as well)

partition

a reader, September 29, 2006 - 7:18 pm UTC

Hi Tom,

I've a partitioned table (range partition by date)which stores data for each day in a different partition. so, far the data in the partition key column of the table corresponds to dates without the time component.

Does one need to do any changes if the new data has time component also in the dates.


Regards



Tom Kyte
September 30, 2006 - 8:07 am UTC

you do not need to change the range bit, it was "strictly less than to_date(....)" and that had a time of 00:00:00 by default always.

Partitioning child tables

Vinod Joshi, October 24, 2006 - 11:42 am UTC

Hi Tom
I have a master table ( e.x TableA). This is 2 child tables (TableB and TableC).
One of the child (TableB) has a child on its own (TableD)
TableA
Table B Table C
Table D
Requirement is to have last 2 years data of Table A in one partition and the older records in different partition. I would take the partition offline and archive it. The older data WILL NOT be used anywhere else.
The child tables follow the same rule.
Table A has a date column on which I need to partition the table. I could use range partition for this table.
Table B,C and D doesn't have this date column. All tables are linked using IDs.
How can I partition data in B, C and D tables based on a value in A.
This is required on a 9i DB.

Tom Kyte
October 24, 2006 - 2:08 pm UTC

you would have to have the data pushed down into the tables currently (10gr2 and before), you cannot partition based on attributes that are NOT in the table.

Mohamed, October 25, 2006 - 11:01 am UTC

What I have understood from TOM's books and validated by my own experience is that for your case you have a master table A with, say, a primary key = Ide and
you want to partition this table on, say, a dat_column.

You have a child table B linked to your master one throught this ide. This means that the dat_column (which is the partition key of table A) is not a part of your master table A primary key.

Then, first of all, your table A should have a global partitioned index.

Then, you want to archive table A based on your dat_column. Even if your child table B is not partioned or is partionned with an other partition key, which of course must be a part of your child table, In my honest opinion, you can not archive table A(ides of A) without archiving table B(corresponding ides). In fact you must first archive child table before archiving master table whatever your partition key is

Tom, correct me please if I am wrong.



Tom Kyte
October 25, 2006 - 1:50 pm UTC

they were asking how to partition a child table by some attribute not in the child table. That is currently not possible.

Nothing about indexing or anything needs be mentioned- only the fact that they cannot partition currently on an attribute that does not exist in the table

still confused about indexes.

Elaine, February 12, 2007 - 10:55 am UTC

I've read the above information and also the information from "Expert Oracle". I also checked out the information in "Effective Oracle by Design". I even checked Metalink, but the most current Note I found was for 9.0.1.

I have a very large table, partitioned by range 9 ways. This table will never have partition pruning. The partitioning was created to help with data loads and to give the ability to parallelize the load process.

This table has 9 indexes. In the 9i version of the database, these indexes -- globally partitioned -- were each spread across 9 tablespaces as well, that is the 9 different index partitions for partition 1 were in 1 tablespace, all index partitions for range 2 were in another tablespace, etc.

In our move to Oracle 10, we plan to have each individual index in its own tablespace -- we need to have a better way to track growth (they all grow at different rates) and would like to be able to watch disk activity. I read that it is possible to use non-partitioned indexes on a partitioned table. since we are no longer spreading an index across multiple tablespaces, is there still value in partitioning the index or should non-partitioned indexes be considered? In your book, "effective oracle by design", you make the statement that indexes on partitioned tables are by default global indexes in a single partition (by default not partitioned indexes at all).

So, should I bother with trying to partition the indexes with its tablespace (locally to match the range partition on the table) or just go with a non-partitioned index?

I can't find anything related to performance one way or the other. I found reference to using the locally partitioned indexes in OLTP, but that is such a small part of what this database does.

If we do go the locally partitioned route, do you see the potential for major performance hits with an index being stored in a single tablespace? Our current set up is very slow and it is likely caused by a load process hitting all the index partitions in a single tablespace at the same time.

Recommendations? I am leaning towards going with local even though it would house all 9 partitions in a single tablespace, but I can't rationalize the decision based on my research -- it's just a gut feel at this point.

Any assistance (or if you could point me to additional documentation that I may have overlooked) is greatly appreciated.

Thanks.

Tom Kyte
February 12, 2007 - 11:44 am UTC

tablespaces have nothing really to do with IO tuning. All nine of your tablespaces could be on the same disk for all we know!

Use tablespaces to increase the joy in your life. Use them when they make your life better, as an organization tool, as an administrative tool.


I/O Tuning

elaine, February 12, 2007 - 5:15 pm UTC

As we have set up this new system, we do know precisely where every tablespace will be. There is a file system for each tablespace and the file system name names the raid rank and the cluster in the name. We took great pains to understand exactly how IBM divides their Shark and also how Veritas Volume Manager works in this environment. I now know more about the internals of RAID arrays across loops than I ever wanted to know.

I guess if we partition the index, we have the ability to move it to another disk (and created another tablespace to put it in). Any benefits to going non-partitioned or should we stick with the local partitioning route?
Tom Kyte
February 13, 2007 - 9:30 am UTC

it is not really possible to answer the "how to partition" - not without knowing the goal.

Partitioning is a tool that can

a) make administration easier (doesn't seem to be the case for you?)
b) make things more available (via partition elimination - if some data is offline, but we eliminate it from consideration)

c) rarely: as a performance design time tool (eg: you design to use partitioning to increase performance)

You would need to state what you want to accomplish (realizing that getting all three simultaneously is so very very rare :)

indexes continued

Elaine H, February 13, 2007 - 6:18 pm UTC

on aix with 9.2, we have a large table partitioned 9 ways. each partition has its own tablespace. we have mass data loads to this table 2-4x daily. the data is subdivided by partition (range) and load jobs are started concurrently.

this table has 9 indexes. on the aix architecture, there are 9 index tablespaces. in index_ts1 is the first partition of each of the 9 indexes. index_ts2 has all the second partitions of all 9 and so on.

we are moving to solaris 10 with 10gR2. it was decided that each index would have its own tablespace. given that there is only the one tablespace for each index, i am trying to figure out if it makes sense to partition each index or since the entire index resides within a single tablespace, whether there would be any performance gain. my feeling is that although there are multiple loops(4 channels)available in each raid rank (which defines a filesystem, which defines a tablespace) there is no benefit either way from a write standpoint. is this a correct assumption? or, since the table is partitioned, is the best practice to keep the indexes partitioned as well?

finally is there significant overhead associated with maintaining partitioned indexes?
Tom Kyte
February 14, 2007 - 8:19 am UTC

tablespaces are not about performance

they are about making your life better

is your life better with a tablespace per index partition or not?


you would make the decision to partition or not based on your needs.

there are administrative reasons to partition (rolling windows of data for example)

there are availability reasons to partition (if the data I need is online, I get it even if some of the data relevant to the table I'm querying isn't)

there are performance reasons (partition elimination)


so - why did you partition - what was your goal and would not partitioning the indexes remove the achievement of that goal

reason to partition

Elaine, February 14, 2007 - 9:28 am UTC

the main reason to partition the main table was so that we could break up the data loads into manageable chunks and run them concurrently. We load about 8 million rows to the table daily -- the table is over 5 billion rows now. the range is based on a substring of a generated key. it can help us find a row, but will never be used in pruning.

the indexes will have to live in a single tablespaces each for now. we don't have the disk space to create 81 tablespaces so that each partition of each index will have its own tablespace. the indexes don't have much to do with the way the data table is partitioned. it was originally done so that we would have all the data loads into the data partitions handled as discrete transactions. given that, i guess keeping the partitions within each index, despite the index being in a single tablespace, makes the most sense.

thanks for your input.
Tom Kyte
February 14, 2007 - 2:22 pm UTC

you didn't need to partition to load concurrently - or to break anything into manageable chunks.

you have enough disk space to create
a) one tablespace with all indexes
b) eighty one tablespaces each with one index apiece

it takes the same amount of disk!

A reader, February 14, 2007 - 5:13 pm UTC

Tom,
We are planning to implement a packaged software for warehouse management (OLTP with 4 node RAC).
Most of the data in each warehouse is independent of data in other warehouses. We are planning users of 3 warehouses on each node (3 wh * 4 nodes = 12 ).

Do you think List partitiong (NODE 1:wh 1,2,3 so list partion wih WH_ID =1,2,3 etc..) will help reduce certain waits like GC Cr request , GC buffer busy etc..
Thank you,
V
Tom Kyte
February 15, 2007 - 9:49 am UTC

if you physically partition the data like that so that all or most of the requests for a given partition are made from a single instance (node), yes, that would have material benefit.

Insert into partition - performance

Ravi Beevanapalli, February 21, 2007 - 6:18 pm UTC

Hi Tom,

I have a table

create table test_part
(col1 date,
col2 varchar2(1))
partition by list(col2) (
PARTITION daily_part VALUES ('d'),
PARTITION mon_part VALUES ('m')
);

Q1) is there any performance benifit by writing

Insert into test_part partition(daily_part) values(sysdate,'d');

insetead of writing

insert into test_part values(sysdate,'d');

And also..

Q2) Is there any performance benift querying partition, even if the partition key is specified in the where clause?

select * from test_part partition(daily_part)
where col2='d';

thanks,
Ravi
Tom Kyte
February 22, 2007 - 8:30 am UTC

q1) you can easily benchmark that however, it has a slight edge - not sure that I'd do it in general though (as the partition scheme could change over time).

ops$tkyte%ORA10GR2> drop table test_part1;

Table dropped.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create table test_part1
  2  (col1 date,
  3    col2 varchar2(1))
  4    partition by list(col2) (
  5    PARTITION daily_part VALUES ('d'),
  6    PARTITION mon_part VALUES ('m')
  7    );

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> drop table test_part2;

Table dropped.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create table test_part2
  2  (col1 date,
  3    col2 varchar2(1))
  4    partition by list(col2) (
  5    PARTITION daily_part VALUES ('d'),
  6    PARTITION mon_part VALUES ('m')
  7    );

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> exec runStats_pkg.rs_start;

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> begin
  2          for i in 1 .. 100000
  3          loop
  4                  insert into test_part1 (col1, col2) values ( sysdate,'d' );
  5          end loop;
  6  end;
  7  /

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> exec runStats_pkg.rs_middle;

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> begin
  2          for i in 1 .. 100000
  3          loop
  4                  insert into test_part2 partition(daily_part) (col1, col2) values ( sysdate,'d' );
  5          end loop;
  6  end;
  7  /

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> exec runStats_pkg.rs_stop(25000);
Run1 ran in 579 hsecs
Run2 ran in 447 hsecs
run 1 ran in 129.53% of the time

Name                                  Run1        Run2        Diff
STAT...calls to get snapshot s     100,209         223     -99,986
STAT...consistent gets             100,557         569     -99,988
STAT...consistent gets from ca     100,557         569     -99,988
STAT...session pga memory                0     196,608     196,608
STAT...db block gets               303,619     103,833    -199,786
STAT...db block gets from cach     303,619     103,833    -199,786
STAT...session logical reads       404,176     104,402    -299,774
LATCH.cache buffers chains       1,111,461     514,623    -596,838

Run1 latches total versus runs -- difference and pct
Run1        Run2        Diff       Pct
1,132,551     539,825    -592,726    209.80%

PL/SQL procedure successfully completed.




q2) no, they both know "one partition" and both know exactly what partition.

Thanks an lot!

Ravi Beevanapalli, February 22, 2007 - 1:19 pm UTC

Thank you Tom for your response. As usual crisp, clear and concise.

-Ravi

partition index compression and lifecycle data management

J, February 26, 2007 - 7:56 pm UTC

Hi Tom,

this is in DW environment with NOARCHIVELOG on.

the biggest schema has all table partitioned and data is compressed (about 1:3 ratio). However, index is not compressed, so we have same size of index as compressed data. The biggest table is about 50GB compressed data.

First Question: Is there any performance degradation if we compress index as well? Daily ETL job is append/insert.

Since this schema is about 800GB and still growing, it is hard to do backup due to all the constraint (no space for cold backup, etc.). it is currently backed up via transportable tablespace. user doesn't want to purge data even though historical data is used infrequently. In order to save DASD savings, we would like to keep most recent 2 years data in current DASD and move rest of data to cheaper DASD.

I planed to roll off history data into other tablespace on cheaper DASD and turn the tablespace to read only.

Second question for you is:
What might be the best practice for this type of data management for future maintenance?

I plan to create history table for each and store the data in history tablespace for read only, and grant access to those who truely needs the data. Is it make sense to create another schema for history data? Should we fix one tablespace for current year data and move out at end of year?

I appreciate if you could provide any suggestion to ease later maintenance.
Tom Kyte
February 27, 2007 - 10:33 am UTC

first answer: "it depends".

Might index maintenance take more work? yes

Might index retrieval take more work? perhaps - but unlikely, more likely retrieval is positively influenced. Especially for large range scans - less physical IO, less logical IO, better buffer cache efficiency (as the cache can cache more without being increased in size)


second answer: partitioning - i would not involve schema after schema, you have rolling window partitions. partition by date. Move and compress partitions onto this cheaper storage and mark read only.

A reader, March 18, 2007 - 2:32 am UTC

Tom,

I have a fact table, say F, which is:
* Partitioned (range) by Month (DATE), and
* Sub-partitioned (list) by Product (VARCHAR)

The loading strategy for F is thus:
* load a temporary table (say T) - which is a non-partitioned table
* index and analyze T
* partition-exchange T with F - using including indexes clause

Now consider this:
* After having loaded F I realize that data for one of the products is completely messed up. I re-run my entire process again, only for that product, and load data in table T. Now, is there a way by which I can selectively partition-exchange T and F for the subpartition corresponding to this product? To rephrase it: can I do partition-exchange at subpartition level? (have I just made an awful lot of money by suggesting a novel idea to the Oracle development team :) )

* Second question: I had asked you this earlier, but, apparently, it's not working. I index and analyze table T and partition-exchange (including indexes) it with table F - you had said that the statistics gathered for T will go along to F when we do partition-exchange, but this doesn't seem to be the case. In TOAD, the stats. tab for F looks like, to use my limited knowledge of cool Latin phrases, tabula rasa. Your thoughts on this?


Tom Kyte
March 18, 2007 - 7:45 pm UTC

I doubt you are doing what you say...

ops$tkyte%ORA10GR2> alter table t exchange partition part1 with table t2 including indexes;
alter table t exchange partition part1 with table t2 including indexes
*
ERROR at line 1:
ORA-14291: cannot EXCHANGE a composite partition with a non-partitioned table


so, give us a small test case (2 partitions with 2 subpartitions - NOT A SINGLE TABLESPACE/STORAGE CLAUSE) that shows us what you mean.

Partitioning Table & Indexes

akg, March 19, 2007 - 10:29 am UTC

Hi Tom,

I am regular visitor of your web site since last 4 years and it is really very informative.
I have questions regarding portioning:

1. Is it necessary to partition all indexes on a table if the table is partitioned?
2. A table is partitioned on a date column but table have a primary key which is a normal b-tree index. Is it correct to have a normal b-tree index(primary key) when table is portioned?
3. Is there any guide line what to do with other indexes, primary key, unique key when a table is partitioned on a column which is not a primary key?
4. I have table with 110 millions of rows with 16 indexes and primary key. I need to partition this table(on a date column) into 3 partition. Since data is huge, what would be the best approach to load data from this table into new partitioned table. Partition key is not a primary key and we have to retain primary key and all indexes on new partitioned table.

Your expert suggestions/comments/guidelines would be highly appreciated.

Thanks a lot.
Tom Kyte
March 19, 2007 - 12:09 pm UTC

1) no
2) i presume you mean "but the table has a primary key which is NOT the date field", not that the "priamry key which is a normal b-tree index". In order to enforce uniqueness, the column to be unique must either

a) have a global partitioned index (with the option to be in a single partition - eg: a normal index)
b) be part of the partition key, in which case the uniqueness can be enforce via a local index

3) see #2, those are your choices

4) create table as select is probably the easiest way (fastest too).

A reader, March 20, 2007 - 4:51 am UTC

thanks a lot Tom.

Split a List Partitioin

Su Baba, March 20, 2007 - 4:53 pm UTC

CREATE TABLE x (
   x_id   NUMBER PRIMARY KEY,
   x_type VARCHAR2(6) NOT NULL
);

INSERT INTO x VALUES (1, 'TYPE A');
INSERT INTO x VALUES (2, 'TYPE A');
INSERT INTO x VALUES (3, 'TYPE B');
INSERT INTO x VALUES (4, 'TYPE B');
INSERT INTO x VALUES (5, 'TYPE C');
INSERT INTO x VALUES (6, 'TYPE C');
INSERT INTO x VALUES (7, 'TYPE C');

COMMIT;


CREATE TABLE x2 (
   x_id,
   x_type
)
PARTITION BY LIST (x_type)
(PARTITION p_typeA VALUES ('TYPE A')
)
ENABLE ROW MOVEMENT
AS
SELECT * 
FROM   x
WHERE  1 = 2;

ALTER TABLE x2
   EXCHANGE PARTITION p_typeA
   WITH TABLE x
   WITHOUT VALIDATION;

SELECT * FROM X2 PARTITION (p_TypeA);

      X_ID X_TYPE
---------- ------
         1 TYPE A
         2 TYPE A
         3 TYPE B
         4 TYPE B
         5 TYPE C
         6 TYPE C
         7 TYPE C

ALTER TABLE X2
   SPLIT PARTITION p_TypeA
   VALUES ('TYPE B', 'TYPE C')
   INTO (PARTITION p_TypeB, PARTITION p_TypeC);

ALTER TABLE X2
            *
ERROR at line 1:
ORA-14313: Value 'TYPE B' does not exist in partition P_TYPE



The objective is to put
'TYPE A' records into Partition p_TypeA
'TYPE B' records into Partition p_TypeB
'TYPE C' records into Partition p_TypeC

What's the best way to achieve this?


Can we partition a table by "month" regardless which year it is?

Michael Leung, March 22, 2007 - 2:42 am UTC

Hi Tom,

I have a table with a date column and want to partition the table by that column.
Can I partition the table into 12 partitions like:
P1: Jan
P2: Feb
....
P12: Dec

I don't care which year the data belongs to because no data will exist longer than half a year.

I only know that I could add a new partition for each month but I have to cater the partition maintenance then. Would it be a good idea that I need fixed 12 partitions only in my case?

Thanks a lot!!!

Warmest Regards,
Michael
Tom Kyte
March 22, 2007 - 7:43 am UTC

in 10gr2 and before - you need a column with that number 1..12 in it...

that is, you can only partition by actual values in actual columns - not on a function of a column...

OK

Siva, March 28, 2007 - 5:40 am UTC

Hi Tom,
I have a product table range partitioned by country with country code
as the partitioning key.i.e say UK,US.
I wanted to update the partitioned table by updating the country code from 'UK' to 'US'.
It throwed an error ORA-14402 and I used "ALTER TABLE <tab_name> enable row movement" and then did an update as
"update product set country_code = 'US' where country_code = 'UK' " by getting each table in a loop
It again throwed an error as Unique constraint violated.
How best to proceed with this sort of requirement?
Bye!
Thanks

Tom Kyte
March 28, 2007 - 11:54 am UTC

don't violate your unique keys I guess??

apparently, you have a unique key, part of that key is the country code and you are creating duplicate data.

do not do that.

Rajesh, April 03, 2007 - 8:55 am UTC

Hi Tom,
This procedure drops partitions from a table that has been
range partitioned by country.
The problem is when the first partition does not exist,
it comes out of the loop.
I just want to continue with the dropping of existing remaining partitions just by skipping non existing partitions.

How to modify this procedure to do that?
Is a <goto> statement valid here?
I need your help here.


create or replace procedure drop_part(country in varchar2,schema_name in varchar2)
as
part_not_exist exception;
pragma exception_init(part_not_exist,-2149);
sql_str_drop varchar2(2000);
cursor cur_tab_part is select table_name from dba_tables where owner = schema_name and
partitioned = 'YES';
begin
for rec_cur_tab_part in cur_tab_part loop
sql_str_drop := 'alter table '|| rec_cur_tab_part.table_name ||' drop partition '
||rec_cur_tab_part.table_name||'_'||country;
execute immediate sql_str_drop;
dbms_output.put_line(rec_cur_tab_part.table_name||'_'||country||' partition dropped.');
end loop;
commit;
exception
when part_not_exist then
null;
dbms_output.put_line('Specified partition does not exist');
end;

Tom Kyte
April 04, 2007 - 9:48 am UTC

you have misplaced the exception block


ops$tkyte%ORA10GR2> create or replace procedure drop_part(country in varchar2,schema_name in varchar2)
  2  as
  3      part_not_exist exception;
  4      pragma exception_init(part_not_exist,-2149);
  5      sql_str_drop varchar2(2000);
  6      cursor cur_tab_part is
  7              select table_name
  8                from dba_tables where owner = schema_name
  9                 and partitioned = 'YES';
 10  begin
 11      for rec_cur_tab_part in cur_tab_part loop
 12          sql_str_drop := 'alter table '|| rec_cur_tab_part.table_name ||
 13                          ' drop partition ' ||rec_cur_tab_part.table_name||
 14                          '_'||country;
 15          begin
 16              execute immediate sql_str_drop;
 17          exception
 18              when part_not_exist then
 19                  dbms_output.put_line( sql_str_drop );
 20                  dbms_output.put_line('Specified partition does not exist');
 21          end;
 22          dbms_output.put_line(rec_cur_tab_part.table_name||'_'||country||' partition dropped.');
 23      end loop;
 24  end;
 25  /

Procedure created.

adding partitions

reader, June 22, 2007 - 10:43 am UTC

we have implemented range partitioning by week with date as partition key. we have 4 partitions per month. we want to implement a scheduled dbms job that would run on the last week of the month to add 4 more partitions for the following month. In this way we don't need to precreate partitions for another year or so and also to ensure new partions are automatically added before the end of the month. Could you provide some guidance how to implement it with date..Thank you.
Tom Kyte
June 22, 2007 - 5:08 pm UTC

last_day( add_months(sysdate,1) ) - 7

would have it run 7 days before the end of the next month...

adding partitions

reader, June 22, 2007 - 5:46 pm UTC

we have 4 range partitions per month each per week.
partition 1 for Day 1 -7
partition 2 is for Day 8-14
partition 3 is for Day 15 - 21
partition 4 is for remaining days in a month.

can you provide us the code to add new partitions for the following month by scheduling dbms_job. Using your suggestion above, last_day( add_months(sysdate,1) ) - 7, is it possible to implement for every month. Thanks.

Tom Kyte
June 23, 2007 - 8:57 am UTC

... can you provide us the code to add new partitions ...

hmm, interesting way to put it. anyway, you would just be adding partitions using

add_months(trunc(sysdate,'mm'),1) + 7 or 14 or 21
and
add_months(trunc(sysdate,'mm'),2)


the first three would give you the 8th, 15th and 22nd of the next month as the LESS THAN value and adding 2 months would give you the first day of the month after as the less than value.


so last_day( add_months(sysdate,1) ) - 7 would be your interval (when executed any time in JUNE for example, that'll give:

ops$tkyte%ORA9IR2> select last_day( add_months(sysdate,1) ) - 7 from dual;

LAST_DAY(
---------
24-JUL-07


a date in the last week of july - and when you use the 4 sysdate functions in july, they'll give the days in august you want.

stats

David, June 26, 2007 - 11:02 am UTC

currently we gather stats using gather_schema_stats of dbms_stats package. all of our tables are now non-partitioned. we are planning to partition the tables. Is there any change we should do to gather stats for partitioned tables. Does gather_schema_stats collect stats for each partition and also for the table in global level. Thanks.
Tom Kyte
July 02, 2007 - 9:45 am UTC

it depends on the parameters passed to it.

http://docs.oracle.com/docs/cd/B19306_01/appdev.102/b14258/d_stats.htm#sthref8114

read about granularity

list partition

A reader, July 24, 2007 - 3:28 am UTC

Hello,Mr. Tom.
Could you tell me why oracle can not create a global index on a list partitioned table?
Regards¿
Alan
Tom Kyte
July 24, 2007 - 9:47 am UTC

I cannot tell you that which is not true

ops$tkyte%ORA10GR2> CREATE TABLE t
  2  (
  3    dt  date,
  4    x   int,
  5    y   varchar2(30)
  6  )
  7  PARTITION BY list (x)
  8  (
  9    PARTITION part1 VALUES (1,2),
 10    PARTITION part2 VALUES (3,4)
 11  )
 12  /

Table created.

ops$tkyte%ORA10GR2> create index t_idx on t(dt) global;

Index created.


Please help

Kumar, July 25, 2007 - 3:02 am UTC

Hi Tom,
we have a partitioned table A with country code as partitioning key.
During each data load for table A, country wise partitions are truncated and loaded with data.
We have a plan to include another partitioned table B which can have the
history data of table A.
Our requirement is
"Before truncation of each partition of table A existing partition data must go
to table partition B".
We thought of using the command "Alter table <table_name> exchange partition"
but found that to be not useful.
Could you please give an idea of how to achieve this?

Tom Kyte
July 26, 2007 - 9:08 am UTC

why didn't you find it useful?

if you use a range/list partitioned table - partition by DATE, subpartition by country code, it would be very useful don't you think?

as long as you have a DATE column in there - but you give insufficient information to really comment...

To Kumar

martina, July 25, 2007 - 8:45 am UTC


Does A have a column when_loaded?

Then i would partition B by (country, when_loaded);

Then i would say:

create table X as select * from A where 1=2;
alter table A exchange partition country_part with table X;
alter table B exchange partition country_date_part with table X.

I am doing the like in a stored Procedure. You must name your partitions properly.

hope that helps,

martina

adding partitions...

Reader, July 26, 2007 - 3:24 pm UTC

Apologize for pasting the entire create table code here. Currently we have created partitions until the end of 2007.
However, the goal is, if possible, to automate the process of adding partitions by scheduling a dbms_job that would run, say on 22nd of each month to add partitions for the following month. We would like to implement this process starting from Dec 22, 2007.
Is it really feasible to automate this?
we would appreciate your guidance on how to accomplish this. Does oracle have any built-in date related function that could help in building the logic.

Currently the plan is to add partitions for tables for the following month by creating a sql script for each table,
for example to add partitions for table P_TEST for Jan 2008:

ALTER TABLE P_TEST ADD PARTITION Y2008_WEEK_1 values less than (to_date('2008-01-08','YYYY-MM-DD')) TABLESPACE DATA ;
ALTER TABLE P_TEST ADD PARTITION Y2008_WEEK_1 values less than (to_date('2008-01-15','YYYY-MM-DD')) TABLESPACE DATA ;
ALTER TABLE P_TEST ADD PARTITION Y2008_WEEK_1 values less than (to_date('2008-01-22','YYYY-MM-DD')) TABLESPACE DATA ;
ALTER TABLE P_TEST ADD PARTITION Y2008_WEEK_1 values less than (to_date('2008-02-01','YYYY-MM-DD')) TABLESPACE DATA ;

and so on for other tables..

Thanks. Appreciate your time in reviewing this request.


CREATE TABLE P_TEST
(
PK_TEST_ID VARCHAR2(50 BYTE) NOT NULL,
DEPOSIT_TYPE_ID VARCHAR2(50 BYTE),
FK_ASSOCIATED_TEST_ID VARCHAR2(50 BYTE),
RECEIVED_BY VARCHAR2(50 BYTE) NOT NULL,
FK_MANIFEST_ID VARCHAR2(50 BYTE) NOT NULL,
FK_CONTRACT_CUSTOMER_ID NUMBER,
FK_SERVICE_UNIT_ID NUMBER,
TEST_NUMBER VARCHAR2(50 BYTE) NOT NULL,
TEST_TYPE VARCHAR2(25 BYTE),
SERIAL_NUMBER VARCHAR2(50 BYTE),
TOTAL_SAID_TO_CONTAIN NUMBER,
TOTAL_NUM_PIECES NUMBER,
STATUS VARCHAR2(25 BYTE) NOT NULL,
STATUS_REASON VARCHAR2(4000 BYTE),
STATED_NUM_OF_ENVELOPES NUMBER,
FK_TEST_BRANCH_ID NUMBER NOT NULL,
LOGIN_ID VARCHAR2(25 BYTE) NOT NULL,
DATETIME_STAMP DATE NOT NULL
)
TABLESPACE DATA
PARTITION BY RANGE (DATETIME_STAMP)
SUBPARTITION BY LIST (FK_TEST_BRANCH_ID)
SUBPARTITION TEMPLATE
(SUBPARTITION BRANCH_1 VALUES (20, 27),
SUBPARTITION BRANCH_2 VALUES (DEFAULT)
)
(PARTITION WEEK_BEFORE_2007 values less than (to_date('2006-12-31','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_1 values less than (to_date('2007-01-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_2 values less than (to_date('2007-01-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_3 values less than (to_date('2007-01-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_4 values less than (to_date('2007-02-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_5 values less than (to_date('2007-02-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_6 values less than (to_date('2007-02-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_7 values less than (to_date('2007-02-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_8 values less than (to_date('2007-03-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_9 values less than (to_date('2007-03-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_10 values less than (to_date('2007-03-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_11 values less than (to_date('2007-03-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_12 values less than (to_date('2007-04-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_13 values less than (to_date('2007-04-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_14 values less than (to_date('2007-04-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_15 values less than (to_date('2007-04-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_16 values less than (to_date('2007-05-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_17 values less than (to_date('2007-05-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_18 values less than (to_date('2007-05-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_19 values less than (to_date('2007-05-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_20 values less than (to_date('2007-06-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_21 values less than (to_date('2007-06-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_22 values less than (to_date('2007-06-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_23 values less than (to_date('2007-06-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_24 values less than (to_date('2007-07-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_25 values less than (to_date('2007-07-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_26 values less than (to_date('2007-07-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_27 values less than (to_date('2007-07-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_28 values less than (to_date('2007-08-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_29 values less than (to_date('2007-08-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_30 values less than (to_date('2007-08-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_31 values less than (to_date('2007-08-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_32 values less than (to_date('2007-09-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_33 values less than (to_date('2007-09-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_34 values less than (to_date('2007-09-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_35 values less than (to_date('2007-09-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_36 values less than (to_date('2007-10-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_37 values less than (to_date('2007-10-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_38 values less than (to_date('2007-10-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_39 values less than (to_date('2007-10-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_40 values less than (to_date('2007-11-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_41 values less than (to_date('2007-11-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_42 values less than (to_date('2007-11-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_43 values less than (to_date('2007-11-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_44 values less than (to_date('2007-12-01','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_45 values less than (to_date('2007-12-08','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_46 values less than (to_date('2007-12-15','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_47 values less than (to_date('2007-12-22','YYYY-MM-DD'))
TABLESPACE DATA,
PARTITION Y2007_WEEK_48 values less than (to_date('2008-01-01','YYYY-MM-DD'))
TABLESPACE DATA
)
/

Tom Kyte
July 27, 2007 - 9:13 am UTC

... Is it really feasible to automate this? ...

yes.

write down your requirements
design the code
implement it.


it is rather straight forward stuff, you'll want to adopt a naming convention that sorts probably:

Y2007_WEEK_1

should be Y2007_WEEK_01


but this is rather straight forward stuff. query dictionary, find highest partition name/value. figure out what next partition name/value will be, add it.

(and 11g automates it at the database level if you are interested :)

Partitioning by week number

Francisco Martínez Oviedo, July 27, 2007 - 1:39 pm UTC

Hi Tom,

I am trying to partition a table according to week number, but I am unable to figure it how to accomplish it.


CREATE TABLE part_table 
(X NUMBER,
 y DATE,
 z      NUMBER)
PARTITION BY LIST (to_char(y,'IW'))
( PARTITION week_1 VALUES ('1')
  PARTITION week_2 VALUES ('2')
  ....
  <the rest of weeks>);

But I am getting next error message:

SQL> CREATE TABLE part_table 
  2  (X NUMBER,
  3   y DATE,
  4   z      NUMBER)
  5  PARTITION BY LIST (to_char(y,'IW'))
  6  ( PARTITION week_1 VALUES ('1')
  7    PARTITION week_2 VALUES ('2'));
PARTITION BY LIST (to_char(y,'IW'))
                          *
ERROR at line 5:
ORA-00907: missing right parenthesis

How can I partition according to week number in a date field?

Thanks in advance Tom for your valuable help and advice.

Tom Kyte
July 27, 2007 - 3:30 pm UTC

you cannot (prior to 11g) partition by a function

you would need an actual column in there that contained the result of to_char(y,'IW'), then you could partition by that.

I would suggest a range partition based on actual DATES, not the IW week

select a ditinct key from list partitioned table

A reader, August 03, 2007 - 9:03 pm UTC

Hello,Tom.
Wish you fine.
I am very curious about a sql statment on a list partitined table:
Here is a table T was LIST partitioned on TYPE column.
I issued a statment below:
<code>select distinct type from t;

I guess :If the TYPE column have 2 key: 'Y' and 'N'
Does oracle know this and do not query the table?
But when I test it,I foud oracle does a full scan on the table ,why?
</code>
Tom Kyte
August 05, 2007 - 2:14 pm UTC

because - there need not be a single row in that partition and the answer could be "nothing"

you have to look and see what is in there.

select a ditinct key from list partitioned table

Alan, August 06, 2007 - 7:47 am UTC

Hi,Tom
Yes,it may return no rows from a partition.
But I think If oracle know this at least one row in that partition ,it just return a partition key rather than make a full scan on that partition?Maybe Oracle is not smart enough to do so?:)
Regards!
Alan

question on INSERT

Michael, August 11, 2007 - 9:42 am UTC

My senior DBA says that "conventional" insert (that is, inserting a row at a time typically in a oltp application) into a partitioning table is faster than into a non-partitioned table. Is this true? If true then why all of the tables are not partitioned?
Thanks
Tom Kyte
August 14, 2007 - 3:35 pm UTC

in single user mode, your senior DBA would likely be "wrong"

It takes extra CPU cycles to figure out where the row goes - it takes more work to insert into a partitioned table...

However, you typically have inserts going into all partitions (say you hash partitioned) and you have many partitions of indexes (many root blocks for a single index - not just one)....


So in a high concurrent user situation, you spread contention out over many segments - you have many root index blocks (not one), you have many "hot right hand sides of an index" (not one), and so on.

So you might see some overall decrease in contention when inserting at high rates with partitioning.


so, as with everything, IT DEPENDS.

insert performance

Reader, August 14, 2007 - 4:55 pm UTC

Regarding your response above:

In a Range partitioned table, all of the new rows go into current week partition. In which case, there should not be any improvement in INSERT with regard to response time whether the table is partitioned or not. correct? Thanks.
Tom Kyte
August 20, 2007 - 12:47 pm UTC

that is not always true. Range partitioned tables can have values go into ANY PARTITION.

it might be your CONVENTION that you are doing a rolling window partition and all newly inserted rows go into the "last" or "most current" partition.

But it doesn't HAVE to work that way.


In your example, all inserts going into a single partition, you will not see any sort of runtime decrease in contention, you might see a runtime increase in CPU as we do the extra code to figure out what partition to insert into.

OK

Kumar, August 23, 2007 - 7:30 am UTC

Hi Tom,
I have some index partitions in a tablespace but the tablespace has become totally occupied(no space in it)
When I do a 
SQL> alter index <index_name> rebuild partition   <partition_name> 
I am getting an error as "Unable to allocate initial extent"
How to rebuild these index partitions?
Please help.

Tom Kyte
August 23, 2007 - 12:15 pm UTC

ummm

a) add more space to the tablespace's datafiles?
b) rebuild the index into a tablespace with sufficient freespace?


OK

Raj, August 27, 2007 - 5:39 am UTC

Hi Tom,
what happens to local and global indexes
when we do a table wise split partition operation?
Tom Kyte
September 04, 2007 - 11:37 am UTC

when you split a partition, it depends on what options you use...

by default, the local index on that split partition will result in two unusable local index partitions that need to be rebuilt and all global indexes will have all partitions marked unusable.

you can use update global indexes to have just the local index partitions go invalid.

or you can use update indexes to have nothing go invalid, the indexes will be maintained in real time

ops$tkyte%ORA10GR2> CREATE TABLE t
  2  (
  3    dt  date,
  4    x   int,
  5    y   varchar2(30)
  6  )
  7  PARTITION BY RANGE (dt)
  8  (
  9    PARTITION part1 VALUES LESS THAN (to_date('13-mar-2003','dd-mon-yyyy')) ,
 10    PARTITION part2 VALUES LESS THAN (to_date('14-mar-2003','dd-mon-yyyy')) ,
 11    PARTITION junk VALUES LESS THAN (MAXVALUE)
 12  )
 13  /
Table created.

ops$tkyte%ORA10GR2> create index t_local on t(x) local;
Index created.

ops$tkyte%ORA10GR2> create index t_global on t(y) global
  2  partition by range(y)
  3  ( partition i1 values less than ('M'),
  4    partition i2 values less than (MAXVALUE)
  5  );
Index created.

ops$tkyte%ORA10GR2> insert into t select to_date( '12-mar-2003','dd-mon-yyyy')+mod(rownum,4), user_id, username from all_users;
37 rows created.

ops$tkyte%ORA10GR2> select index_name, partition_name, status from user_ind_partitions where index_name in ( 'T_LOCAL', 'T_GLOBAL' ) order by 1, 2;

INDEX_NAME                     PARTITION_NAME                 STATUS
------------------------------ ------------------------------ --------
T_GLOBAL                       I1                             USABLE
T_GLOBAL                       I2                             USABLE
T_LOCAL                        JUNK                           USABLE
T_LOCAL                        PART1                          USABLE
T_LOCAL                        PART2                          USABLE

ops$tkyte%ORA10GR2> select 'p1', count(*) from t partition(part1) union all
  2  select 'p2', count(*) from t partition(part2) union all
  3  select 'ju', count(*) from t partition(junk);

'P   COUNT(*)
-- ----------
p1          9
p2         10
ju         18

<b>this is the 'default' outcome...</b>

ops$tkyte%ORA10GR2> alter table t split partition junk
  2  at (to_date('15-mar-2003','dd-mon-yyyy'))
  3  into (partition part3, partition junk)
  4  /

Table altered.

ops$tkyte%ORA10GR2> select 'p1', count(*) from t partition(part1) union all
  2  select 'p2', count(*) from t partition(part2) union all
  3  select 'p3', count(*) from t partition(part3) union all
  4  select 'ju', count(*) from t partition(junk);

'P   COUNT(*)
-- ----------
p1          9
p2         10
p3          9
ju          9

ops$tkyte%ORA10GR2> select index_name, partition_name, status from user_ind_partitions where index_name in ( 'T_LOCAL', 'T_GLOBAL' ) order by 1, 2;

INDEX_NAME                     PARTITION_NAME                 STATUS
------------------------------ ------------------------------ --------
T_GLOBAL                       I1                             UNUSABLE
T_GLOBAL                       I2                             UNUSABLE
T_LOCAL                        JUNK                           UNUSABLE
T_LOCAL                        PART1                          USABLE
T_LOCAL                        PART2                          USABLE
T_LOCAL                        PART3                          UNUSABLE

6 rows selected.



<b>but if we had done this instead:</b>

ops$tkyte%ORA10GR2> alter table t split partition junk
  2  at (to_date('15-mar-2003','dd-mon-yyyy'))
  3  into (partition part3, partition junk)
  4  update global indexes
  5  /
Table altered.

ops$tkyte%ORA10GR2> select index_name, partition_name, status from user_ind_partitions where index_name in ( 'T_LOCAL', 'T_GLOBAL' ) order by 1, 2;

INDEX_NAME                     PARTITION_NAME                 STATUS
------------------------------ ------------------------------ --------
T_GLOBAL                       I1                             USABLE
T_GLOBAL                       I2                             USABLE
T_LOCAL                        JUNK                           UNUSABLE
T_LOCAL                        PART1                          USABLE
T_LOCAL                        PART2                          USABLE
T_LOCAL                        PART3                          UNUSABLE

6 rows selected.

<b>only the local index partitions are in need of a rebuild.. further:</b>



ops$tkyte%ORA10GR2> alter table t split partition junk
  2  at (to_date('15-mar-2003','dd-mon-yyyy'))
  3  into (partition part3, partition junk)
  4  update indexes
  5  /
Table altered.

ops$tkyte%ORA10GR2> select index_name, partition_name, status from user_ind_partitions where index_name in ( 'T_LOCAL', 'T_GLOBAL' ) order by 1, 2;

INDEX_NAME                     PARTITION_NAME                 STATUS
------------------------------ ------------------------------ --------
T_GLOBAL                       I1                             USABLE
T_GLOBAL                       I2                             USABLE
T_LOCAL                        JUNK                           USABLE
T_LOCAL                        PART1                          USABLE
T_LOCAL                        PART2                          USABLE
T_LOCAL                        PART3                          USABLE

6 rows selected.

<b>nothing goes invalid...</b>


A reader, September 05, 2007 - 1:40 am UTC

Nice Explanation.

OK

A reader, September 14, 2007 - 7:57 am UTC

Hi Tom,
I have a table partitioned by week which are maintained in
different databases in a network.
when I do a insert from one database into the same table in a different database, the partitions are not retained. I am able to see the rows as that of source table in the target table but partitions are not preserved or copied into the
remote database.
How to move the partitions also into the remote database?

Tom Kyte
September 15, 2007 - 9:40 pm UTC

eh? this makes no sense, distribute and partitions are orthogonal concepts.

Concept Needed Dynamic Partition Pruning

AMIR RIAZ, September 16, 2007 - 2:42 am UTC

Hi Tom.

thanks for sharing your knowledge with us.

Oracle has two type of partition pruning. static and dynamic. I understand static pruning. Its recently when viewing oracle documentation i found out that Dynamic partition pruning also exists. But oracle documentation just give a glampse of it. My question is:

Dynamic partition pruning with bind variables. The partition is Selected at RUN TIME. Is RUN TIME means hard parsing if so against one sql text we will have multiple execution plans which seems confusing because in bind variable we have one sql text and one execution plan.

another concept can be a General execution plan for all partitions. i.e if we have list partition p1,p2,p3 on values 'A','B','C' respectively then we will have one execution plan. At execution time we peek into the query predicates to find the exact partition. But a general execution plan for all partitions is rather another confusing thing.

which one is right?.

regards
Amir Riaz



Tom Kyte
September 16, 2007 - 11:45 am UTC

runtime means the query plan says "I know we will eliminate partitions, we just won't know till we execute the query for a given user which ones will be eliminated"

There is no additional hard parse.


As far as optimization

a) if the optimizer can determine at hard parse time precisely which partition will be accessed AND THAT ONLY ONE partition will be accessed - the optimizer will use local partition statistics (if present) to optimize that query.

b) if the optimizer cannot determine at hard parse time precisely which partition will be accessed, or the optimizer cannot reduce it to a single partition, or if there are no local statistics on the partition - global statistics will be used.

c) in the event of bind peeking - if the optimizer can bind peek at hard parse time - A) will be true if only a single partition is accessed...



for C, consider the following (confusing perhaps) example

ops$tkyte%ORA10GR2> CREATE TABLE t
  2  (
  3    part_key  number,
  4    x   int,
  5    y   varchar2(30)
  6  )
  7  PARTITION BY RANGE (part_key)
  8  (
  9    PARTITION part1 VALUES LESS THAN (10),
 10    PARTITION part2 VALUES LESS THAN (20),
 11    PARTITION junk VALUES LESS THAN (MAXVALUE)
 12  )
 13  /

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> insert into t select mod(rownum,10), rownum, rownum from all_objects;

50172 rows created.

ops$tkyte%ORA10GR2> insert into t select mod(rownum,10)+10, 0, rownum from all_objects;

50172 rows created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> exec dbms_stats.gather_table_stats( user, 'T' );

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> create index t_idx on t(x) local;

Index created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set serveroutput off
ops$tkyte%ORA10GR2> variable part_key number
ops$tkyte%ORA10GR2> exec :part_key := 15

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> @trace
ops$tkyte%ORA10GR2> alter session set events '10046 trace name context forever, level 12';

Session altered.

ops$tkyte%ORA10GR2> set autotrace traceonly
ops$tkyte%ORA10GR2> select * from t where part_key = :part_key and x = 0;

5017 rows selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 293519354

------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name  | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |       |     1 |    12 |     2   (0)| 00:00:01 |       |       |
|   1 |  PARTITION RANGE SINGLE            |       |     1 |    12 |     2   (0)| 00:00:01 |   KEY |   KEY |
|*  2 |   TABLE ACCESS BY LOCAL INDEX ROWID| T     |     1 |    12 |     2   (0)| 00:00:01 |   KEY |   KEY |
|*  3 |    INDEX RANGE SCAN                | T_IDX |    29 |       |     1   (0)| 00:00:01 |   KEY |   KEY |
------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("PART_KEY"=TO_NUMBER(:PART_KEY))
   3 - access("X"=0)


Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
        449  consistent gets
          0  physical reads
          0  redo size
      97035  bytes sent via SQL*Net to client
       4059  bytes received via SQL*Net from client
        336  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
       5017  rows processed



the optimizer KNOWS a single partition will be accessed (part_key = :part_key)

the optimizer DOESN'T KNOW until runtime which will be accessed however.

Explain plan does not bind peek
http://asktom.oracle.com/Misc/when-explanation-doesn-sound-quite.html
and says "we shall do an index range scan, because there are lots of values for X"

however, the optimizer does bind peek and the optimizer really optimized:

select *
from
 t where part_key = :part_key and x = 0


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        2      0.00       0.00          0          0          0           0
Execute      2      0.00       0.00          0          0          0           0
Fetch      672      0.04       0.04          0        898          0       10033
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      676      0.04       0.04          0        898          0       10033

Misses in library cache during parse: 2
Optimizer mode: ALL_ROWS
Parsing user id: 215

Rows     Row Source Operation
-------  ---------------------------------------------------
   5016  PARTITION RANGE SINGLE PARTITION: KEY KEY (cr=449 pr=0 pw=0 time=20236 us)
   5016   TABLE ACCESS FULL T PARTITION: KEY KEY (cr=449 pr=0 pw=0 time=15183 us)


to a full scan because local statistics told it "0 is in every single row"



If we did the example again with :part_key set to 5 instead (note i ran the entire thing again, drop table and create table included - to get a HARD PARSE, else the plan would NOT change!!!!!):

select *
from
 t where part_key = :part_key and x = 0


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        1      0.00       0.00          1          2          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        3      0.00       0.00          1          2          0           0

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 215

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  PARTITION RANGE SINGLE PARTITION: KEY KEY (cr=2 pr=1 pw=0 time=234 us)
      0   TABLE ACCESS BY LOCAL INDEX ROWID T PARTITION: KEY KEY (cr=2 pr=1 pw=0 time=217 us)
      0    INDEX RANGE SCAN T_IDX PARTITION: KEY KEY (cr=2 pr=1 pw=0 time=209 us)(object id 143514)




your example is wonderful

AMIR RIAZ, September 16, 2007 - 3:15 pm UTC

Wonderful, beautiful, excellent

you have even answered the question which i would have asked in future. thanks Tom.

Dynamic pruning on Joins in 11g

AMIR RIAZ, September 18, 2007 - 1:47 pm UTC

Hi Tom

In 11g documentation oracle allow partition pruning on joins.

Statements that are most efficiently executed using a nested loop join use dynamic pruning. For example:

select t.time_id, sum(s.amount_sold)
from sales s, times t
where s.time_id = t.time_id and t.fiscal_year = 2000 and t.fiscal_week_number = 3
group by t.time_id;

In my understanding partition pruning on Joins is not possible especially dynamically. Because statically at parsing time oracle can look into the statistics and eliminate partition but again at run time suppose we have select the data of three partition and at join time we need only only partition of each table but again How partition will be eliminated because at run time we only have data. how at execution time oracle knows that this join can be made efficient by partition pruning.

It says partition pruning on joins is only possible on nested loop join. Is partition pruning on joins is allowed on hash join and sort merge joins.
Regards
Amir Riaz
Tom Kyte
September 18, 2007 - 4:53 pm UTC

you'll want to point us to the documentation you are talking about - I'm not sure of the context here.

your example doesn't say WHAT is partitioned or what bits you expect pruned, it is hard to comment on anything.


Dynamic Pruning with Nested Loop Joins

AMIR RIAZ, September 19, 2007 - 2:05 am UTC

Hi tom.

thanks for the reply. here is the link to the oracle 11g documents.

http://download.oracle.com/docs/cd/B28359_01/server.111/b32024/part_avail.htm#BJEIEDIA

See the heading "Dynamic Pruning with Nested Loop Joins"

1. How can partition be eliminated while joining tables. How oracle knows that join can be made efficient by eliminate partition especially Dynamically at run time. also because for join pruning oracle will have to look into the data after it has been filter from the predicates and then perform partition elimination which seems pretty heavy calculation keeping in mind that a join can have hundred or thousands of records.

2. Is Dynamic partition pruning on joins is possible with bind variables

3. is dynamic partition pruning on join possible when hash or sort merge join is been used in the execution plan. oracle documentation does not say anything about it.

4. Is cardinality (number of distinct rows) have to do anything with dynamic partition pruning on joins.

regards
Amir Riaz


Tom Kyte
September 19, 2007 - 12:34 pm UTC

but that is nothing new.... Here, 9i:

ops$tkyte%ORA9IR2> CREATE TABLE t
  2  (
  3    dt  date,
  4    x   int,
  5    y   varchar2(30)
  6  )
  7  PARTITION BY RANGE (dt)
  8  (
  9    PARTITION part1 VALUES LESS THAN (to_date('13-mar-2003','dd-mon-yyyy')) ,
 10    PARTITION part2 VALUES LESS THAN (to_date('14-mar-2003','dd-mon-yyyy')) ,
 11    PARTITION junk VALUES LESS THAN (MAXVALUE)
 12  )
 13  /

Table created.

ops$tkyte%ORA9IR2> create index t_idx on t(dt) local;

Index created.

ops$tkyte%ORA9IR2> create table t2 ( x int primary key, y date );

Table created.

ops$tkyte%ORA9IR2>
ops$tkyte%ORA9IR2> exec dbms_stats.set_table_stats( user, 'T', numrows=> 1000000, numblks=> 100000 );

PL/SQL procedure successfully completed.

ops$tkyte%ORA9IR2> exec dbms_stats.set_table_stats( user, 'T2', numrows=> 1000000, numblks => 10000 );

PL/SQL procedure successfully completed.

ops$tkyte%ORA9IR2>
ops$tkyte%ORA9IR2> @plan 'select * from t, t2 where t2.x = 5 and t.dt = t2.y'
ops$tkyte%ORA9IR2> delete from plan_table;

7 rows deleted.

ops$tkyte%ORA9IR2> explain plan for &1;
old   1: explain plan for &1
new   1: explain plan for select * from t, t2 where t2.x = 5 and t.dt = t2.y

Explained.

ops$tkyte%ORA9IR2> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------------
| Id  | Operation                           |  Name        | Rows  | Bytes | Cost  | Pstart| Pstop |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |              |     1 |    61 |     4 |       |       |
|   1 |  NESTED LOOPS                       |              |     1 |    61 |     4 |       |       |
|   2 |   TABLE ACCESS BY INDEX ROWID       | T2           |     1 |    22 |     2 |       |       |
|*  3 |    INDEX UNIQUE SCAN                | SYS_C003063  |     1 |       |     1 |       |       |
|   4 |   PARTITION RANGE ITERATOR          |              |       |       |       |   KEY |   KEY |
|   5 |    TABLE ACCESS BY LOCAL INDEX ROWID| T            |     1 |    39 |     2 |   KEY |   KEY |
|*  6 |     INDEX RANGE SCAN                | T_IDX        |     1 |       |     1 |   KEY |   KEY |
----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("T2"."X"=5)
   6 - access("T"."DT"="T2"."Y")

Note: cpu costing is off

20 rows selected.




1) we get a row from the driving table (t2 in my example). This gives us a partition key value for the other table. We know now the precise INDEX partition to probe for that value. Very straightforward, we can prune for each row returned from T2


2) yes.

3) yes.

ops$tkyte%ORA9IR2> explain plan for &1;
old   1: explain plan for &1
new   1: explain plan for select /*+ use_hash(t t2) */ * from t, t2 where t2.x = 5 and t.dt = t2.y

Explained.

ops$tkyte%ORA9IR2> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

---------------------------------------------------------------------------------------------
| Id  | Operation                    |  Name        | Rows  | Bytes | Cost  | Pstart| Pstop |
---------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |              |     1 |    61 |  9642 |       |       |
|*  1 |  HASH JOIN                   |              |     1 |    61 |  9642 |       |       |
|   2 |   TABLE ACCESS BY INDEX ROWID| T2           |     1 |    22 |     2 |       |       |
|*  3 |    INDEX UNIQUE SCAN         | SYS_C003064  |     1 |       |     1 |       |       |
|   4 |   PARTITION RANGE ITERATOR   |              |       |       |       |   KEY |   KEY |
|   5 |    TABLE ACCESS FULL         | T            |  1000K|    37M|  9619 |   KEY |   KEY |
---------------------------------------------------------------------------------------------


4) cardinality estimates are what the optimizer uses to pick a plan, they do not preclude a plan - but if the cost is "high", they have the appearance of precluding a plan (because that plan is not chosen)

You learn New things in oracle world Daily.

AMIR RIAZ, September 21, 2007 - 2:58 pm UTC

Hi Tom.

thanks for this example. But i did not manage to understand what you said at number 4

cardinality estimates are what the optimizer uses to pick a plan, they do not preclude a plan - but if the cost is "high", they have the appearance of precluding a plan (because that plan is not chosen)

would you explain a bit. if a plan depends upon cardinality and is not preclude how does high costs apprear to make it preclude. thanks again for your kind help

regards
Amir Riaz
Tom Kyte
September 26, 2007 - 1:15 pm UTC

it just means - yes, sort of.

you wrote:



4. Is cardinality (number of distinct rows) have to do anything with dynamic partition pruning on joins.


cardinality estimates affect the plan chosen.
so, yes, they can have an effect on whether or not pruning will happen.

if the optimizer decided on full scans and hash joins over nested loops... for example.

they do not 'preclude'


can we compress the lob in a compress partition.

Vin, October 01, 2007 - 12:06 pm UTC

Oracle 10.2.0.3 on Solaris 5.10

TABLE_NAME COLUMN_NAME LOB_NAME TABLE PARTITION_NAME LOB_PARTITION_NAME LOB_INDPART_NAME PARTITION_POSITION
----------- ----------- -------- -------------------- ------------------ ---------------- ------------------
TAB_BLOB COL_BLOB LB_TB_CB TB_2003Q3 LB_TB_CB_2003Q3 SYS_IL_P75 1


Table Name Partition Name #Extents Rows Size(Mb)
---------- ------------- ------- ----- -------
TS_BLOB TS_2003Q3 1 4784 1


TS Name Segment Type Segment Name LOB Partition Name #Extents Size(Mb)
------- ------------- ------------ ------------------ -------- --------
TS_LOB LOB PARTITION LB_TB_CB LB_TB_CB_2003Q3 88 1,408

alter table TAB_BLOB move partition TB_2003Q3 compress update indexes parallel 2;
alter table TAB_BLOB move partition TB_2003Q3 nocompress update indexes parallel 2;

Table Name Partition Name #Extents COMPRESS Rows Size(Mb)
---------- -------------- -------- ---------- ---- --------
SOB TB_2003Q3 1 ENABLED 5327 1
SOB TB_2003Q4 1 DISABLED 106 1

Question:
if a table with lob is range partitioned, we can compress a partition (TB_2003Q3) of partitioned table (TAB_BLOB).

can we also compress the lob partition (LB_TB_CB_2003Q3) of the table partition (TB_2003Q3)
that we compressed. if yes, then could you please advice on the sql.

this sql did not work for me for compressing the lob in Oracle 10.2.0.3
alter table TAB_BLOB move partition LB_TB_CB_2003Q3 compress update indexes parallel 2;

Appreciate your time and sharing knowledge.

compress the lob in a compress partition.

Vin, October 02, 2007 - 9:36 pm UTC

providing the sql's that i used for testing to compress the lob in a compress partition.

create table T( X number, Y date, Z blob) tablespace TST_DATA
lob(Z) store as LB_T_Z
(tablespace TST_LOB disable storage in row nocache nologging chunk 8k pctversion 10)
partition by range(Y)
(
partition T_2005Q1 values less than (to_date('01-apr-2005', 'dd-mon-yyyy'))
tablespace TST_DATA lob(Z) store as LB_T_Z_2005Q1
(tablespace TST_LOB disable storage in row nocache nologging chunk 8k pctversion 10),
partition T_2005Q2 values less than (to_date('01-jul-2005', 'dd-mon-yyyy'))
tablespace TST_DATA lob(Z) store as LB_T_Z_2005Q2
(tablespace TST_LOB disable storage in row nocache nologging chunk 8k pctversion 10)
)parallel (degree 2) nomonitoring nocache nologging enable row movement;


SQL > alter table T move partition T_2005Q1 compress update indexes parallel 2;

Table altered.

Table Table No of No of Size
Name Partition Name Extents COMPRESS Rows in Mb
------------------ ------------------ ------- -------- ---------- ------------
T T_2005Q1 1 ENABLED 5327 1
T_2005Q2 1 DISABLED 0 1
****************** ****************** ------- ---------- ------------
sum 2 5327 2

Tablespace Segment Lob Lob No of Size
Name Type Name Partition Name Extents in Mb
------------ ------------------ -------------------- ------------------ ------- ------------
TST_LOB LOB PARTITION LB_T_Z LB_T_Z_2005Q1 161 2,576
LB_T_Z_2005Q2 1 16
************ ****************** ******************** ------- ------------
sum 162 2,592

the alter table compress only compressed a partition (T_2005Q1) on table T but not
the lob partition (LB_T_Z_2005Q1) whose size remained the same (2,576 Mb).

is there a way to compress the lob in a compressed partition?
Regards
Tom Kyte
October 05, 2007 - 11:08 am UTC

lobs are not compressable automagically.

securefiles in 11g (new feature) are.

utl_compress can be used programatically by you to compress a lob.

Partition key bounds

Emmanuel MAKONDAMBUTA, October 08, 2007 - 4:18 am UTC

I would like to implement partitioning with Oracle 10g on a big table. I would like the partition to be as follow:

if myKey like:
'MAB%' ---> partition 1
'HEF%' ---> partition 2
'KBE%' ---> partition 3
Otherwise ---> partition 4

where myKEY is my column used as partition key.

In another words: I want all rows where myKey is like 'MAB%' to be stored in one separated partition. Same logic with the other possible values of myKey.

As I can't use just "VALUES LESS THAN..." nor LIST partition, do you have any strategy implementing these kind of partitions?

Thanks,
Emmanuel.

Partition key bounds

Mike, October 08, 2007 - 7:42 am UTC

I can think of two options to approximate what you ask for:

1) Use range partitioning on the current column. Instead of 4 partitions, you will have 7:
< HEF : partition 1
= HEF : partition 2 (specify as < HEG)
> HEF and < KBE : partition 3 (specify as < KBE)
= KBE : partition 4 (specify as < KBF)
> KBE and < MAB : partition 5 (specify as < MAB)
= MAB : partition 6 (specify as < MAC)
> MAB : partition 7 (specify as < MAXVALUE)


2) Add (and maintain) a new column that is derived from the first 3 characters of your key, and use that for list partitioning. This can give you the 4 partitions. But SQL that uses the current key column will not benefit from partition pruning (if that is one of your objectives for partitioning).

about partitioning

Emmanuel MAKONDAMBUTA, October 08, 2007 - 11:25 am UTC

Mike,

Thank you for your input.
I was already doing something similar to what you suggested but the problem is that I have more than 10 keys and I don't want to create as (almost) many partitions as the distinct keys.

I think it should be possible to create partitions based on wildcard characters (key like 'BLABA%').
Your suggestions are welcome.
Emmanuel.

Partitioning by leading characters

Mike, October 09, 2007 - 8:02 am UTC

11g may also add more options here, with Reference Partitioning (ability to partition by a column in a parent table, not in the table you are partitioning), or virtual columns (which may maintain the partitioning column for you). Again, these 'indirect' strategies are likely to limit how well partition elimination can be exploited with your SQL.

About partitioning

Emmanuel MAKONDAMBUTA, October 12, 2007 - 9:43 am UTC

Mike,

I've read that Oracle 11g can define "virtual partitions", List-range partitions, ... and much more.
I'm planning to install it on the test machine and try "Partitioning new features".

Thanks again,
Emmanuel.

OK

A reader, October 16, 2007 - 3:43 am UTC

Hi Tom,
Is it possible to drop a local index
partition for a particular partition?

A reader, October 24, 2007 - 7:29 am UTC

If I have tables with a million of rows, should I have it partitioned or not?
I'm not sure which is the apropiate size to partitioned a table.

Thank you.
Tom Kyte
October 24, 2007 - 9:20 am UTC

size isn't as relevant as what you need to do to it.

do you need to age/archive old data over time? a table with 10,000 rows might need to be partitioned to support that.

do you need to implement partition elimination to avoid a big full scan (eg: the table is scanned a lot - but only half at a time - partition by the value that splits the table in half and scan half as much data)

list out what you do to this segment, what you need to do to this segment and then ask "would partitioning make any of this faster, easier..."

partition elimination

Aimee Lin, October 24, 2007 - 10:58 pm UTC

Hi Tom,

I have a question regarding a comment you made on this question:

"if you use any locally partitioned index, and your predicate includes the key used to partition 
that locally partitioned index, it doesn't matter if it is prefixed or not.  It can do the same 
partition elimination."

I have tried to test this partition elimination on a locally partitioned index which does not have the table partition key column as the first column in the indexed column list.  However, I don't see partition elimination from the execution plan.  

Here is the test case that I went through (tested on 9.2.0.7 database):

Table creation DDL:
create table test (test_id number(13), test_date date, test_desc varchar2(30))
TABLESPACE users
partition by range (test_date)
(partition P_200609 values less than (to_date('01 Oct 2006 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200610 values less than (to_date('01 Nov 2006 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200611 values less than (to_date('01 Dec 2006 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200612 values less than (to_date('01 Jan 2007 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200701 values less than (to_date('01 Feb 2007 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200702 values less than (to_date('01 Mar 2007 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200703 values less than (to_date('01 Apr 2007 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200704 values less than (to_date('01 May 2007 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200705 values less than (to_date('01 Jun 2007 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200706 values less than (to_date('01 Jul 2007 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200707 values less than (to_date('01 Aug 2007 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_200708 values less than (to_date('01 Sep 2007 00:00:00','dd mon yyyy hh24:mi:ss')),
 partition P_CURRENT values less than (maxvalue));

Local index DDL:
create index test_local on test (test_id,test_date) local;

Sample data:
insert into test values (1,sysdate,'test');
insert into test values (2,sysdate,'test');

analyze table:
analyze table test compute statistics;

data in the table:
15:41:00 cpu9208 SQL> select * from test;

         TEST_ID TEST_DATE            TEST_DESC
---------------- -------------------- ------------------------------
               2 17 jul 2007 15:04:27 test
               1 25 oct 2007 15:04:20 test


Table Stats:
PARTITION_NAME                    NUM_ROWS HIGH_VALUE                                                                       TABLESPACE_NAME
------------------------- ---------------- -------------------------------------------------------------------------------- ------------------------------
P_200609                                 0 TO_DATE(' 2006-10-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200610                                 0 TO_DATE(' 2006-11-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200611                                 0 TO_DATE(' 2006-12-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200612                                 0 TO_DATE(' 2007-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200701                                 0 TO_DATE(' 2007-02-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200702                                 0 TO_DATE(' 2007-03-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200703                                 0 TO_DATE(' 2007-04-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200704                                 0 TO_DATE(' 2007-05-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200705                                 0 TO_DATE(' 2007-06-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200706                                 0 TO_DATE(' 2007-07-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200707                                 1 TO_DATE(' 2007-08-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_200708                                 0 TO_DATE(' 2007-09-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIA SYSTEM
P_CURRENT                                1 MAXVALUE                                                                         SYSTEM


Index stats:
INDEX_NAME                PARTITION_NAME                    NUM_ROWS
------------------------- ------------------------- ----------------
TEST_LOCAL                P_200609                                 0
TEST_LOCAL                P_200610                                 0
TEST_LOCAL                P_200611                                 0
TEST_LOCAL                P_200612                                 0
TEST_LOCAL                P_200701                                 0
TEST_LOCAL                P_200702                                 0
TEST_LOCAL                P_200703                                 0
TEST_LOCAL                P_200704                                 0
TEST_LOCAL                P_200705                                 0
TEST_LOCAL                P_200706                                 0
TEST_LOCAL                P_200707                                 1
TEST_LOCAL                P_200708                                 0
TEST_LOCAL                P_CURRENT                                1

13 rows selected.


Set trace on to get plan:
cpu9208 SQL> set autotrace on

run sql to retrieve data via test_id:
cpu9208 SQL> select * from test where test_id=1;

         TEST_ID TEST_DATE            TEST_DESC
---------------- -------------------- ------------------------------
               1 25 oct 2007 15:04:20 test


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=1 Bytes=13)
   1    0   PARTITION RANGE (ALL)
   2    1     TABLE ACCESS (BY LOCAL INDEX ROWID) OF 'TEST' (Cost=2 Ca
          rd=1 Bytes=13)

   3    2       INDEX (RANGE SCAN) OF 'TEST_LOCAL' (NON-UNIQUE) (Cost=
          1 Card=1)


Here, the plan says it had to do partition range on all partitions -- so no partition elimination??!!!

And then did another query with predicate includes table partitioned key (test_date) and test_id:

15:45:46 cpu9208 SQL> select * from test where test_date=to_date('17 jul 2007 15:04:27','dd mon yyyy hh24:mi:ss') and test_id=2;

         TEST_ID TEST_DATE            TEST_DESC
---------------- -------------------- ------------------------------
               2 17 jul 2007 15:04:27 test

Elapsed: 00:00:00.35

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=1 Bytes=13)
   1    0   TABLE ACCESS (BY LOCAL INDEX ROWID) OF 'TEST' (Cost=2 Card
          =1 Bytes=13)

   2    1     INDEX (RANGE SCAN) OF 'TEST_LOCAL' (NON-UNIQUE) (Cost=1
          Card=1)

again, no partition elimination.

Question:  Why don't I see partition elimination in my tests?  This appears to contradict your comment quoted earlier.  Could you please help to clarify your comment?

Thank you,
Aimee

Tom Kyte
October 25, 2007 - 6:13 pm UTC

ops$tkyte%ORA10GR2> insert into test select rownum, to_date( '01-sep-2006')+mod(rownum,365), object_name
  2  from all_objects;

50196 rows created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create index test_local on test (test_id) local;

Index created.

ops$tkyte%ORA10GR2> exec dbms_stats.gather_table_stats( user, 'TEST', cascade=>true );

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> @plan "select * from test where test_id = 1 and test_date = to_date('17-jul-2007', 'dd-mon-yyyy') "
ops$tkyte%ORA10GR2> delete from plan_table;

4 rows deleted.

ops$tkyte%ORA10GR2> explain plan for &1;
old   1: explain plan for &1
new   1: explain plan for select * from test where test_id = 1 and test_date = to_date('17-jul-2007', 'dd-mon-yyyy')

Explained.

ops$tkyte%ORA10GR2> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 313074962

-----------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name       | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |            |     1 |    37 |     2   (0)| 00:00:01 |       |       |
|   1 |  PARTITION RANGE SINGLE            |            |     1 |    37 |     2   (0)| 00:00:01 |    11 |    11 |
|*  2 |   TABLE ACCESS BY LOCAL INDEX ROWID| TEST       |     1 |    37 |     2   (0)| 00:00:01 |    11 |    11 |
|*  3 |    INDEX RANGE SCAN                | TEST_LOCAL |     1 |       |     1   (0)| 00:00:01 |    11 |    11 |
-----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("TEST_DATE"=TO_DATE('2007-07-17 00:00:00', 'yyyy-mm-dd hh24:mi:ss'))
   3 - access("TEST_ID"=1)

16 rows selected.


a locally partition index
non-prefixed (in fact the partition key isn't there at all)

a query that

a) uses a predicate on the indexed column AND
b) includes the partition key

does partition elimination naturally.

Type of partitioning to use

Doug Floyd, October 26, 2007 - 9:30 am UTC

The original post was asking about range vs hash partitioning. If your goal is to provide partition elimination where you're querying by idcolumn = value, then at what point do you choose hash or range partitioning? For example, let's say the partition key is a jobid column. If you have only 1,000 jobs, it may be easy enough to range partition and create a partition for each jobid. But if you grow to 50,000, 100,000, or more jobs, how would you decide to partition this data? Would it be better to partition by ranges of jobids or just hash partition by jobid? Is there a practical limit on the number of partitions per table before it becomes too difficult to manage?

Thanks.
Tom Kyte
October 29, 2007 - 11:11 am UTC

if your only goal was

partition eliminate so that the full scan done by "where col = :x" hits X% of the data

then the answer would be "hash partition using powers of 2 (2,4,8,16,32,64,... partitions) so that approximately X% of the data is in each partition.

The more distinct values "col" has - the better (for distribution), but as the number of distinct values of "col" increases, the more likely you meant to "index", not partition to make retrieval times better (although partitioning would in effect enforce some degree of clustering.... all of the col = :x values would be "close to each other" in the same partition whereas they could be "far from each other" in a regular heap table.

is lic required

sat, November 01, 2007 - 1:49 pm UTC

is separate lic is required to create partition tables ? I dont know my DBA keep saying we dont have licenesing to creating partition tables ? is that my DBA is right
Tom Kyte
November 02, 2007 - 12:13 pm UTC

http://www.oracle.com/pls/db102/portal.portal_db?selected=1
see the licensing section there

Partitioning is a separately licensed option of the Enterprise Edition.

Limit on number of partitions?

Doug Floyd, November 27, 2007 - 12:42 pm UTC

I know the documentation states the maximum number of partitions allowed on a table, but are you aware of a practical limit on the number of partitions? I noticed in the Metalink document 76765.1 that it states "So, while 64k-1 is the theoretical limit, there may be physical limitations
well before that."

The article is referencing Oracle 8i, but I was still curious if you've seen real world examples of running into issues with a large number of partitions on a table (i.e 50k, 100k, or more).

Thanks.
Tom Kyte
November 27, 2007 - 4:09 pm UTC

well, it depends on the release (the more current, the more scalable the implementation is)

for example - current releases only load into the dictionary cache the partition information needed for the query at hand - in the past - it was *every partition*. So, having 10's of thousands could a) take a while to parse the first time and b) effectively flush the dictionary cache.

Also, some partition operations were less efficient in the past - dropping a partition would renumber them - and that could take a while, depending on which on you drop.

In general, using 10g and above, having thousands of partitions is not only doable, it is done.

A reader, November 27, 2007 - 5:04 pm UTC


Thanks!

Doug Floyd, November 28, 2007 - 9:57 am UTC

Thank you for the quick response!

BTW, I thoroughly enjoyed your sessions at OpenWorld, I can't wait to start working with 11g. I'm also trying to become more of a 2.0 style DBA.

new value for list Partitioning

Ranjan, December 05, 2007 - 11:56 pm UTC

Hi Tom,

The answers provided here are very much useful to everyone. I have a small doubt regarding the list partitioning you have mentioned.

I have a table with around 10 milion records with 5 distinct category_codes. Inorder to improve the performance, I am planning to use the list partition option for this table. However I am wondering how I should proceed with the new values in category_codes. If I need to create a new partition before the new category_code is to be inserted into this table?

Please advise.

Thanks.
Tom Kyte
December 10, 2007 - 9:56 am UTC

... Inorder to improve the performance, I am planning to use the list partition
option for this table. ...

why - why do you believe it will improve performance? You'll have to be careful to not negatively impact current performance, and it is unlikely to improve performance.

what are you doing in your application whereby you believe this will help? Unless you are FULL SCANNING the table with "select * from table where category_code = :x", it is not likely to improve performance.

Improve administration - sure
Improve availability - possible
Improve performance - not necessarily.

Subpartitioning

Ana, January 10, 2008 - 6:45 am UTC

Hi,
All the answers are very usefull, but I have another question. I have a table partitioned like this:
CREATE TABLE GI_PXP_DETAIL
(
ID_RECORD NUMBER(8) NOT NULL,
FH_SEND_DATE DATE NOT NULL,
FH_RECEPTION_DATE DATE NOT NULL,
NU_ID_FICHERO NUMBER(8) NOT NULL,
TX_MSISDN VARCHAR2(16 BYTE),
TX_DIRECTION VARCHAR2(3 BYTE),
TX_UID VARCHAR2(19 BYTE),
TX_TMP_UID VARCHAR2(19 BYTE),
NU_BYTES NUMBER(8),
TX_STATUS_CODE VARCHAR2(8 BYTE),
TX_ERROR_CLASS VARCHAR2(8 BYTE),
TX_SECURE_TYPE VARCHAR2(5 BYTE),
TX_MOBILE_IP_ADDRESS VARCHAR2(15 BYTE),
TX_ACCESS_PROTOCOL VARCHAR2(7 BYTE),
TX_URL VARCHAR2(2048 BYTE),
TX_URL_PREFIJO VARCHAR2(1024 BYTE),
TX_URL_SUFIJO VARCHAR2(2048 BYTE),
TX_ACCESS_GW VARCHAR2(20 BYTE),
TX_MIME_TYPE VARCHAR2(1024 BYTE),
TX_ML_TYPE VARCHAR2(15 BYTE),
TX_ACCESS_TYPE VARCHAR2(15 BYTE),
TX_ICAP_INFO VARCHAR2(7 BYTE),
FH_ULTIMA_MODIF DATE DEFAULT SYSDATE
)
TABLESPACE DATOS_DINAMICOS
PARTITION BY RANGE (FH_RECEPTION_DATE)
(
PARTITION P0811 VALUES LESS THAN (TO_DATE(' 2007-11-09 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))
PARTITION P99 VALUES LESS THAN (MAXVALUE)
)

Now I want to make subpartitions but I get an ORA-14253: table is not partitioned by Composite Range method
I work with Oracle 9.2.0.6.
How can I subpartition this table?

Thanks.
Tom Kyte
January 10, 2008 - 2:28 pm UTC

You will have to rebuild it - you cannot change from one level of partitioning to another via ALTER

every row pretty much has to move anyway - to be placed into the right subpartition

histograms for partitions

A reader, January 11, 2008 - 12:59 am UTC

Hi Tom

did we need histograms for partition pruning(especially dynamic)?. On partition tables we have globle statistics and local statistics. I think globle statistics are like histograms if not will you like to eloborate this concept.

Tom Kyte
January 11, 2008 - 7:26 am UTC

we never needed histograms for partition pruning.


global statistics are "not like histograms"

histograms are a detailed picture of a columns values. If the column has less than 255 distinct values, a histogram presents a "perfect picture" - telling us "where x = 5 will return 53 records, and where x = 42 will return 100,203 records". If the column has more than 255 distinct values, the picture gets a little blurry as more than one value will be in each bucket - in ranges - so we would know that values X through Y would return so many records whereas A through B would return so many.

histograms may be global (for the entire logical table) or histograms may be local (for each partition)

but histograms are not "like global statistics" or vice versa.

Centralization of Databases

Nishith Pandey, February 06, 2008 - 6:49 am UTC

We are a Print Media Industry publishing a Daily Newspaper in about 30 cities. We are aiming towards Centralization of our 30 databases presently located at each of our publishing office, as Each office has similar Inhouse developed applications running. (Obviously, the objective is to avoid replication of programs and Database Object structures and hence reduction of maintenance efforts.) Platform is Oracle Database 10g and Forms/Reports 6i.

Access control to applications are controlled through Programmatic Login Form where Login ID (Employee ID) and passwords are stored in tables.

In the new scenario, the users at each site should only be able to see/modify their Office's transactions ( a Division Field is present in almost all the tables to identify office wise transactions ).

Please suggest us the following:

1) Should we use VPD through DBMS_RLS to limit the number of records for users or any other better treatment is available ?

2) How should we plan the storage of data, i.e., How many number of Tablespaces/Datafiles, Placing of various Datafiles to different disks, etc. for optimum I/O performance.

3) We are running in NOARCHIVELOG mode. Now since we want to shift in ARCHIVELOG mode, what would be the best practices for RMAN backups while using ARCHIVELOG?

Please help us and give us some reference links for guidelines.

Thanks !


Tom Kyte
February 06, 2008 - 7:59 am UTC

1) that would be the way, yes. That is what VPD was invented for (virtual private database)

2) hah. you are only kidding right? Tablespaces are not about performance, they are about making your life as a DBA happier (they are a tool to organize things with).

Just stripe everything over as many small disks as you can get your hands on

3) The best practice would be to learn rman inside and out. Then to set down in writing what you expect from your new ability to recover (eg: how long you can be down, how far back in the past you need to go, everything). Then finally, design a backup and recovery set of procedures that using your new knowledge of rman, you satisfy everything you wrote down as far as expectations.


Parition name for date

Tony, February 13, 2008 - 2:54 pm UTC

I have a big table range partitioned by date. For a given date, I want to find the partition name. The table has 500 million rows. Is there a more efficient way to find the partition name for a given date?


Tom Kyte
February 13, 2008 - 10:52 pm UTC

"more efficient" you wrote.

"more efficient than what" I ask???


http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:652093600346909239

if you have a row from the table and want to know the partition it came from, that might apply.

selecting from multiple partition

DK, February 22, 2008 - 3:29 am UTC

Hi Tom

I want to select the data from the alrerady partitioned table t1.The table t1 is partitioned on month p1,p2,p3...I want to select the data for the latest three months in single SQL.

I know there I can do
select *
from t1 parition(p1)

But this will give only one month data.As mentioned I want 3 month data so I need to access 3 partitions at a time.

Can I do
select *from
t1 partition (p1,p2,p3) or something similar.

Thanks,
Dheeraj
Tom Kyte
February 22, 2008 - 7:14 am UTC

it sounds distinctly like you have partitioned on this date since you wrote:

I know there I can do
select *
from t1 parition(p1)

But this will give only one month data.


so, just

select * from t1 where partition_key >= add_months(sysdate,-3)

we'll figure out what partitions need accessing to answer that.

Partitioning required ?

Nishith Pandey, February 28, 2008 - 12:56 am UTC

Hi Tom,

In one of your followups in response to my question above, you suggested :

"Just stripe everything over as many small disks as you can get your hands on"

If we follow this configuration, then what other benefits we can avail with Table Partitioning?

Thanks!
Tom Kyte
February 28, 2008 - 3:38 pm UTC

partitioning = divide and conquer

if you have to do something to a table/index and it is 500gb in size, that is hard.

if you have 500 1gb partitions of the same, it is easy and can be done bit by bit.


partitioning = eliminate from consideration big bits of data

if your query can stop considering 499gb out of 500gb of data - it might be able to run faster...


partitioning = more available

if 1 partition out of 500 becomes unavailable due to a failure somehow, it is likely that most queries will complete without error - you'll be more available.



Partitioning is about easing administration of large things, making big queries go faster in some cases and increasing availability.

Thanks a lot :)

Nishith Pandey, February 29, 2008 - 7:47 am UTC

Thanks a lot Tom !!!! Now I know what really is PARTITIONING ;)

Does Updating a Partition Column cause fragmentation ?

sumedha fernandes, April 10, 2008 - 12:29 pm UTC

One of the previous reviews, talked about updating a table , to set the partitioned Column to another value.
[ Updating Country_code to 'UK' from 'US'..
The table was partitioned on country_code

Question :
=========
1) Would this cause Fragmentation on the table ?

2) Is it a good idea to update a column value that is partitioned [ instead of a delete / insert ] , especially if the table also has another column with BLOB datatype ?

Thanks,
sumedha
Tom Kyte
April 10, 2008 - 1:12 pm UTC

1) define to me your definition of "fragmentation" - what does it mean for a table to be "fragmented" to you?

It would not do anything beyond what a delete+insert would do.

2) If you need the data to move, yes, it is a brilliant idea. If you did not want the data to move, then it would be bad.

It is neither good nor bad, it is "a thing that may be done". If your needs and design dictate that it must happen - so be it.

In general, it should not happen "frequently" - mostly for data range partitioned by date and occasionally - infrequently - the date needs to be corrected.

OK

Saravanan, April 21, 2008 - 3:02 am UTC

Hi Tom,
Can I add some 20 or 30 extents to a table partition at once? I used the " alter table <table_name> modify partition
<part_name> allocate extent .." But this adds a single extent only. I need to have multiple extents added in a single statement.
Can this statement " Alter table <table_name> storage (...)
" be modified for a partitioned table?

Thanks for your time.
Tom Kyte
April 23, 2008 - 4:37 pm UTC

simple question for you:

why??

you can modify the storage, but that will affect subsequent extents only (and only if you are using the legacy dictionary managed tablespaces, which hopefully you are not)

so we are back to "why?"

11g - Partitioning by Reference

A reader, July 08, 2008 - 12:07 pm UTC


CREATE TABLE parent (
   pid     NUMBER PRIMARY KEY,
   Source  VARCHAR2(15) NOT NULL
)
PARTITION BY list (source)
(
   PARTITION p1 VALUES ('SOURCE1'),
   PARTITION p2 VALUES ('SOURCE2'),
   PARTITION p3 VALUES ('SOURCE3')
);

-- ------------------------------------------------------------------------------
-- Note that in order to define a partition by reference, the foreign key must
-- be defined as NOT NULL.
-- ------------------------------------------------------------------------------
CREATE TABLE child (
   cid     NUMBER PRIMARY KEY,
   pid     NUMBER NOT NULL,
      CONSTRAINT fk_child_1 FOREIGN KEY (pid) REFERENCES parent
)
PARTITION BY REFERENCE (fk_child_1);

-- ------------------------------------------------------------------------------
-- Grand child
-- ------------------------------------------------------------------------------
CREATE TABLE grandChild (
   gcid     NUMBER PRIMARY KEY,
   cid      NUMBER NOT NULL,
      CONSTRAINT fk_grandchild_1 FOREIGN KEY (cid) REFERENCES child
)
PARTITION BY REFERENCE (fk_grandchild_1);


INSERT INTO parent
SELECT rownum, DECODE(MOD(rownum, 3), 0, 'SOURCE1',
                                      1, 'SOURCE2',
                                      2, 'SOURCE3')
FROM   all_objects;

INSERT INTO child
SELECT rownum, pid
FROM   parent
UNION
SELECT rownum + 60000, pid
FROM   parent
UNION
SELECT rownum + 120000, pid
FROM   parent;

INSERT INTO grandChild
SELECT rownum, cid
FROM   child
UNION
SELECT rownum + 200000, cid
FROM   child
UNION
SELECT rownum + 400000, cid
FROM   child
;

COMMIT;

BEGIN
  DBMS_STATS.GATHER_TABLE_STATS(
    ownname          => user,
    tabname          => 'PARENT',
    estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE,
    method_opt       => 'FOR ALL COLUMNS SIZE SKEWONLY',
    cascade          => TRUE);
END;
/

BEGIN
  DBMS_STATS.GATHER_TABLE_STATS(
    ownname          => user,
    tabname          => 'CHILD',
    estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE,
    method_opt       => 'FOR ALL COLUMNS SIZE SKEWONLY',
    cascade          => TRUE);
END;
/

BEGIN
  DBMS_STATS.GATHER_TABLE_STATS(
    ownname          => user,
    tabname          => 'GRANDCHILD',
    estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE,
    method_opt       => 'FOR ALL COLUMNS SIZE SKEWONLY',
    cascade          => TRUE);
END;
/

set autotrace traceonly

SELECT p.pid, c.cid, gc.gcid
FROM   parent p, child c, grandchild gc
WHERE  p.pid = c.pid AND
       c.cid = gc.cid AND
       p.source = 'SOURCE1';


----------------------------------------------------------------------------------------------------
| Id  | Operation              | Name                       | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |                            |   158K|  4629K|   419   (3)| 00:00:06 |
|   1 |  RESULT CACHE          | g6rnjkgxqjg3tg3a1fm2g6fznq |       |       |            |          |
|   2 |   PARTITION LIST SINGLE|                            |   158K|  4629K|   419   (3)| 00:00:06 |
|*  3 |    HASH JOIN           |                            |   158K|  4629K|   419   (3)| 00:00:06 |
|*  4 |     HASH JOIN          |                            | 53443 |  1095K|   109   (3)| 00:00:02 |
|   5 |      TABLE ACCESS FULL | PARENT                     | 17929 |   210K|    15   (0)| 00:00:01 |
|   6 |      TABLE ACCESS FULL | CHILD                      |   161K|  1418K|    92   (2)| 00:00:02 |
|   7 |     TABLE ACCESS FULL  | GRANDCHILD                 |   484K|  4254K|   306   (2)| 00:00:04 |
----------------------------------------------------------------------------------------------------

The question is how do I read this execution plan? Is it doing a single partition scan on all three tables even though it says "TABLE ACCESS FULL?"

Tom Kyte
July 08, 2008 - 4:36 pm UTC

I didn't load up the data - isn't necessary - but I believe this is a formatting error more than anything - any change you are truncating the dbms_xplan output?

ops$tkyte%ORA11GR1> SELECT p.pid, c.cid, gc.gcid
  2  FROM   parent p, child c, grandchild gc
  3  WHERE  p.pid = c.pid AND
  4         c.cid = gc.cid AND
  5         p.source = 'SOURCE1';

no rows selected


Execution Plan
----------------------------------------------------------
Plan hash value: 360337564

----------------------------------------------------------------------------------------------------
| Id  | Operation             | Name       | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |            |     1 |    74 |     3   (0)| 00:00:01 |       |       |
|   1 |  PARTITION LIST SINGLE|            |     1 |    74 |     3   (0)| 00:00:01 |     1 |     1 |
|   2 |   NESTED LOOPS        |            |     1 |    74 |     3   (0)| 00:00:01 |       |       |
|   3 |    NESTED LOOPS       |            |     1 |    48 |     3   (0)| 00:00:01 |       |       |
|   4 |     TABLE ACCESS FULL | PARENT     |     1 |    22 |     2   (0)| 00:00:01 |     1 |     1 |
|*  5 |     TABLE ACCESS FULL | CHILD      |     1 |    26 |     1   (0)| 00:00:01 |     1 |     1 |
|*  6 |    TABLE ACCESS FULL  | GRANDCHILD |     1 |    26 |     1   (0)| 00:00:01 |     1 |     1 |
----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - filter("P"."PID"="C"."PID")
   6 - filter("C"."CID"="GC"."CID")


it should have pstart and pstop - your plan table and all is "current" right?


why is the result cache step in there? you don't have that "on for everything" do you?

11g - Partitioning by Reference - Execution Plan

A reader, July 09, 2008 - 5:25 pm UTC

I turned off result cache.

I didn't copy the entire execution plan. Here it is after I re-created the tables/partitions without putting in any data.

SELECT p.pid, c.cid, gc.gcid
FROM   parent p, child c, grandchild gc
WHERE  p.pid = c.pid AND
       c.cid = gc.cid AND
       p.source = 'SOURCE1';


----------------------------------------------------------------------------------------------------
| Id  | Operation             | Name       | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |            |     1 |    74 |     3   (0)| 00:00:01 |       |       |
|   1 |  PARTITION LIST SINGLE|            |     1 |    74 |     3   (0)| 00:00:01 |     1 |     1 |
|   2 |   NESTED LOOPS        |            |     1 |    74 |     3   (0)| 00:00:01 |       |       |
|   3 |    NESTED LOOPS       |            |     1 |    48 |     3   (0)| 00:00:01 |       |       |
|   4 |     TABLE ACCESS FULL | PARENT     |     1 |    22 |     2   (0)| 00:00:01 |     1 |     1 |
|*  5 |     TABLE ACCESS FULL | CHILD      |     1 |    26 |     1   (0)| 00:00:01 |     1 |     1 |
|*  6 |    TABLE ACCESS FULL  | GRANDCHILD |     1 |    26 |     1   (0)| 00:00:01 |     1 |     1 |
----------------------------------------------------------------------------------------------------


It appears that I got the same execution plan as you did. So Oracle is scanning the first partition of each table in the joins.

The next query includes the values for two partitions. Based on the execution plan, how do I know that only two partitions are scanned?


SELECT p.pid, c.
cid, gc.gcid
FROM   parent p, child c, grandchild gc
WHERE  p.pid = c.pid AND
       c.cid = gc.cid AND
       p.source IN ('SOURCE1', 'SOURCE2');

----------------------------------------------------------------------------------------------------
| Id  | Operation             | Name       | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |            |     1 |    74 |     3   (0)| 00:00:01 |       |       |
|   1 |  PARTITION LIST INLIST|            |     1 |    74 |     3   (0)| 00:00:01 |KEY(I) |KEY(I) |
|   2 |   NESTED LOOPS        |            |     1 |    74 |     3   (0)| 00:00:01 |       |       |
|   3 |    NESTED LOOPS       |            |     1 |    48 |     3   (0)| 00:00:01 |       |       |
|   4 |     TABLE ACCESS FULL | PARENT     |     1 |    22 |     2   (0)| 00:00:01 |KEY(I) |KEY(I) |
|*  5 |     TABLE ACCESS FULL | CHILD      |     1 |    26 |     1   (0)| 00:00:01 |KEY(I) |KEY(I) |
|*  6 |    TABLE ACCESS FULL  | GRANDCHILD |     1 |    26 |     1   (0)| 00:00:01 |KEY(I) |KEY(I) |
----------------------------------------------------------------------------------------------------


I got the above execution plans using autotrace

set autotrace traceonly

but, I got the following error

SP2-0619: Error while connecting
SP2-0611: Error enabling STATISTICS report

What do I need to do on 11g to fix this error (sorry this is not related to the original question)?

Tom Kyte
July 09, 2008 - 6:27 pm UTC

the plan won't show you that the way the plan was developed - it is just saying "we got some keys, we'll be iterator-ing over them". It'll only hit the necessary data.

you need the plustrace role for the v$ stuff for autotrace statistics.


A reader, August 11, 2008 - 1:02 pm UTC

Tom,
I have a daily partitioned table. There are some partitions which are loaded on Saturday and Sunday. I need to truncate those partitions. I have a dt_key column (number type). Partition is based on the dt_key column.
Partitions:
PARTITION P070701 VALUES LESS THAN (20070702)
PARTITION P070702 VALUES LESS THAN (20070703)
PARTITION P070703 VALUES LESS THAN (20070704)

Is there any way, I can find the partitions for saturday and sunday based on this information in USER_TAB_PARTITIONS?

Can you give some suggestions?

Tom Kyte
August 12, 2008 - 8:44 am UTC

to_char( to_date( '20' || substr( partition_name,2 ), 'yyyymmdd' ), 'DY' )


use that and where on it in ('SAT','SUN')

partition exchange using 'INCLUDING INDEXES' clause

Apurva, October 06, 2008 - 5:54 am UTC

Tom,

Hope you are doing great. Have a quick question regarding partition exchange using 'INCLUDING INDEXES' clause --

Are there some limitations to the 'INCLUDING INDEXES' clause in PARTITION EXCHANGE.

I am trying to exchange a list-partitioned table with a range-list-partitioned table using the including indexes clause, and Oracle does not like it -- it says ORA-14098 (index mismatch for tables in ALTER TABLE EXCHANGE PARTITION). However, if I do not use the 'INCLUDING INDEXES' clause then partition-exchange works fine; but I do want to carry forth the indexes during exchange.

Both the tables have same set/order of local bitmap indexes.

Please enlighten,
Thanks for your help
Tom Kyte
October 06, 2008 - 2:58 pm UTC

give an example of what you are doing here. Use just as small an example as you can put together, really tiny. If it is overly large (because you didn't take the 5 minutes to cut out unnecessary columns, partitions, indexes, etc) it will be ignored....

Thanks Tom

Apurva, October 06, 2008 - 8:55 am UTC

Hey Tom,

I was making some stupid mistake. I got this one.

Thanks!

The applicable number of partitions (range/list)

A reader, October 07, 2008 - 2:29 am UTC

Hi Tom,

I am going through your comments on using range/list partition. You mentioned

"
50 -- they could do it.
500,000 -- they would have a hard time at it (but hash partitioning would start to come into play).

values in between with ranges/hashes -- not practical at some point.
"

But 10gR2 said one object can have up to 1 million partitions. So what's the suggested maximum number of partitions we should consider as to range/list partitions ? Will it be better less than 100 or 1000 ?

Thanks,

JJ
Tom Kyte
October 08, 2008 - 7:49 pm UTC

the point was, if you have 50, you can easily as a human being - range partition.

if you have 500,000, as a human being, would be harder. Unless you wrote software to do it - to automatically managed the partitions for you.

Until you get to 11g, then interval partitioning might well work to automate it.


The answer is "it depends", what is reasonable for you in your design might be utterly and horribly unreasonable for someone else with theirs.

To find partitions to drop

David, October 07, 2008 - 12:00 pm UTC

We have range-partitioned tables with weekly partition. We are planning to drop partitions. Is there a way to query dba_tab_partitions to dynamically extract drop partition statement for a specific month or range of months? Partitions are named as below.
Y2007_WEEK_1
Y2007_WEEK_2
Y2007_WEEK_3
Y2007_WEEK_4
....
Y2007_WEEK_10
....

AS high_value column is LONG datatype in dba_tab_partitions, I am not able to use it in the where clause.

Thanks.
Tom Kyte
October 08, 2008 - 9:49 pm UTC

ops$tkyte%ORA11GR1> select x, to_number(substr( x, 2, 4 )) YEAR,
  2         to_number(substr( x, instr( x, '_', -1 )+1) ) week
  3    from t;

X                                    YEAR       WEEK
------------------------------ ---------- ----------
Y2007_WEEK_1                         2007          1
Y2007_WEEK_2                         2007          2
Y2007_WEEK_3                         2007          3
Y2007_WEEK_4                         2007          4




David, you could

Sokrates, October 09, 2008 - 5:07 am UTC

write a small function

function high_value(vPartitionName in varchar2) return date is
maxdate constant date := to_date('31.12.2099', 'dd.mm.yyyy');
l varchar2(1024);
p varchar2(64);
f varchar2(64);
begin
select high_value
into l
from user_tab_partitions
where partition_name = vPartitionName;

if l = 'MAXVALUE' then
return maxdate;
end if;

p := substr(l,
instr(l, '''', 1, 1),
instr(l, '''', 1, 2) - instr(l, '''', 1, 1) + 1);

f := substr(l,
instr(l, '''', 1, 3),
instr(l, '''', 1, 4) - instr(l, '''', 1, 3) + 1);

return to_date(p,f);

exception
when no_data_found then return null;
end high_value;


and then
select partition_name, high_value(partition_name) as high from user_tab_partitions

Manoj V, October 13, 2008 - 4:53 am UTC

Hi Tom,

First of all Thanks for giving us valuable suggessions and explanations for each and every query.

I am having 2 doubts on partition in Oracle9i.

01) When i create a list partition ( for e.g list partition based on city code) , what is the use of index on the column that is used for list partition. ( in this what is the use of a index on city code?)

02) When i use simple select statement based on the city code will it go and directly hit the partition or should i explicitly mention the partition, if yes then how dynamically is it possible?


Thanks
Manoj.V

Tom Kyte
October 14, 2008 - 4:48 pm UTC

1) probably not much. Unless it was a global index maybe. But - you give us no use case (no example).

And as usual, it depends. Say partition 1 has cities A and B. Supppose city A has 1,000 records, city B has 1,000,000. An index on city used to retrieve city A would be effective.

Probably - the answer is "an index on city code by itself would not be useful"

However, the real answer is "it depends, there could be more than one city per partition, the data could be skewed, the index could be a global index, the index might be local with other columns" - there are many cases.

2) only mention the partition name in super special cases. Let the optimizer partition prune for you.

select * from t where partition_key = :x

that is the right way.

Partition

A reader, October 15, 2008 - 12:34 am UTC

Thanks Tom for giving me guidence.

I created the following table.

CREATE TABLE "SALES_BY_REGION"
( "ITEM" NUMBER(38,0),
"STATE_CODE" VARCHAR2(2 BYTE)
)
PARTITION BY LIST ("STATE_CODE")
(PARTITION "REGION_EAST" VALUES ('1') NOCOMPRESS ,
PARTITION "REGION_WEST" VALUES ('2') NOCOMPRESS ,
PARTITION "REGION_SOUTH" VALUES ('3') NOCOMPRESS ,
PARTITION "REGION_CENTRAL" VALUES ('4') NOCOMPRESS ,
PARTITION "REGION_WILDWEST" VALUES ('6') NOCOMPRESS ,
PARTITION "REGION_WILDEAST" VALUES ('5') NOCOMPRESS ,
PARTITION "REGION_UNKNOWN" VALUES (DEFAULT) NOCOMPRESS ) ENABLE ROW MOVEMENT ;

CREATE INDEX "PARTITION_INDEX" ON "SALES_BY_REGION" ("STATE_CODE")
;

and when i gave the statement

select * from SALES_BY_REGION where state_code=2
it give me the explain plan

SELECT STATEMENT ALL_ROWS 9 1 16
PARTITION LIST(ALL) 9 1 16 1 7 1
TABLE ACCESS(FULL) SCOTT.SALES_BY_REGION 9 1 16 1 7 1 TO_NUMBER("STATE_CODE")=2


But when i gave the

SELECT * FROM SALES_BY_REGION PARTITION(REGION_WEST);

that gave me a different plan.


SELECT STATEMENT ALL_ROWS 3 1 16
PARTITION LIST(SINGLE) 3 1 16 KEY KEY 1
TABLE ACCESS(FULL) SCOTT.SALES_BY_REGION 3 1 16 2 2 2


Which one is performance wise better. I think it is the second one.because it directly hit the partition and cost also shows less.

I am using 11g.

Thanks
Manoj.V
Tom Kyte
October 15, 2008 - 5:27 pm UTC

there is only one correct way to do this in an application, the first way.

I've already stated that.

Your plans are unreadable (use code button next time please)

In your case, the index is a "not useful thing" - almost 100% certain of that. Why do you create it? of what use do you think it will be.


did you happen to see this???
TO_NUMBER("STATE_CODE")=2 


why did you compare a string (state_code) to a number?????

run your query properly, where state_code = '2', to compare a string to a string and you'll see something "completely different"



OR

if state_code is actually a NUMBER - define it as such!

Explicit mention of Partitions

A reader, October 16, 2008 - 2:51 am UTC

Sorry Tom,

When i change the statement like

select * from sales_by_region where state_code='2'

it gives me the same Explain plan as that of using partition explicitly.

If both gave me same why should we need to explicitly specify the partition name in select query? in which scenario we should explicitly mention partition name in select clause?

can u please explain me?

thanks
Manoj.V
Tom Kyte
October 17, 2008 - 8:40 pm UTC

... why should we need to explicitly specify the partition
name in select query ...

you shouldn't, that is what I've been saying......


It is useful for testing sometimes, to verify things. I use it to demonstrate concepts.

It is useful for direct path loading (a direct path load will lock a segment, if you insert /*+ APPEND */ into T, it'll lock T. If you can insert /*+ APPEND */ into t partition(part1) - it'll only do part1 of T, not the entire table)

That is about it.


"U" is not available, they died a while ago. Sorry about that.

A reader, October 17, 2008 - 8:56 am UTC

SELECT
sed.MBR_ID,
sed.WCARD_NUM,
sed.AMT_RQSTD,
sed.PROFILE_NUM,
sed.PREV_BALANCE,
sed.NEW_BALANCE,
sed.NET_BALANCE,
sed.FNAME,
sed.MNAME,
sed.LNAME,
sed.TITLE,
sed.SUFFIX,
sed.DOB,
sed.WORK_PHONE,
sed.HOME_PHONE,
sed.ADDR1,
sed.ADDR2,
sed.EMAIL,
sed.CITY,
sed.STATE,
sed.ZIP,
sed.NUM_OF_CARDS,
sed.ENROL_TYPE,
sed.amount AMOUNT,
sed.STAGING_ELIG_DTL_SEQ_ID,
sed.TERM_DTTM,
sed.PAID_DTTM,
sed.PAID_IND,
wcm.cardhldr_seq_id,
-- client_seq,
wcm.wcard_mapping_seq_id
FROM staging_elig_dtls sed,wcard_mapping_tmp wcm
WHERE sed.client_num=:client_num
AND sed.mbr_id=wcm.mbr_id(+)
AND wcm.client_seq_id(+)=:client_seq;


Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=CHOOSE 4 K 440
MERGE JOIN OUTER 4 K 1 M 440
SORT JOIN 4 K 1 M 435
PARTITION LIST SINGLE KEY KEY
TABLE ACCESS BY LOCAL INDEX ROWID WCARD_PERF.STAGING_ELIG_DTLS 4 K 1 M 6 KEY KEY
INDEX RANGE SCAN WCARD_PERF.IDX_STAGING_ELIG_DTL 1 K 2 KEY KEY
SORT JOIN 3 168 5
PARTITION LIST SINGLE KEY KEY
TABLE ACCESS FULL WCARD_PERF.WCARD_MAPPING_TMP 3 168 3 KEY KEY



SELECT
sed.MBR_ID,
sed.WCARD_NUM,
sed.AMT_RQSTD,
sed.PROFILE_NUM,
sed.PREV_BALANCE,
sed.NEW_BALANCE,
sed.NET_BALANCE,
sed.FNAME,
sed.MNAME,
sed.LNAME,
sed.TITLE,
sed.SUFFIX,
sed.DOB,
sed.WORK_PHONE,
sed.HOME_PHONE,
sed.ADDR1,
sed.ADDR2,
sed.EMAIL,
sed.CITY,
sed.STATE,
sed.ZIP,
sed.NUM_OF_CARDS,
sed.ENROL_TYPE,
sed.amount AMOUNT,
sed.STAGING_ELIG_DTL_SEQ_ID,
sed.TERM_DTTM,
sed.PAID_DTTM,
sed.PAID_IND,
wcm.cardhldr_seq_id,
-- client_seq,
wcm.wcard_mapping_seq_id
FROM staging_elig_dtls sed,wcard_mapping_tmp wcm
WHERE sed.client_num=:client_num
AND sed.mbr_id=wcm.mbr_id(+)
--AND wcm.client_seq_id(+)=:client_seq;
AND wcm.mbr_id(+)=:mbr_id


Query 2: Outer join on partition with no join on partition key

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=CHOOSE 1 4
NESTED LOOPS OUTER 1 334 4
PARTITION LIST SINGLE KEY KEY
TABLE ACCESS BY LOCAL INDEX ROWID WCARD_PERF.STAGING_ELIG_DTLS 1 291 1 KEY KEY
INDEX RANGE SCAN WCARD_PERF.IDX_STAGING_ELIG_DTL 1 2 KEY KEY
PARTITION LIST ALL 1 3
TABLE ACCESS FULL WCARD_PERF.WCARD_MAPPING_TMP 1 43 3 1 3



My DBA is saying that The query uses an outer join on WCARD_MAPPING table. So it will not qualify the particular partition and entire data will be scanned anyway..

So this query really does not justify the partitioning of the table.


Can u tell me why?

I assume that Query1 is using the partition.

Please tell me my assumption is right/wrong.

Thanks in advance,
Manoj.V

Tom Kyte
October 18, 2008 - 8:18 pm UTC

well

a) I cannot read the plan, since you didn't format it for 'code'

b) I do not have your create tables.... so I do not know your partitioning scheme or what is partitioned.




but...
FROM staging_elig_dtls sed,wcard_mapping_tmp wcm
  WHERE sed.client_num=:client_num
  AND sed.mbr_id=wcm.mbr_id(+)
  AND wcm.client_seq_id(+)=:client_seq; 



sed.client_num has a predicate, if data is partitioned by client_num - that'll definitely partition eliminate.

But I really don't know what question you are asking - remove like 99% of the columns (they just make it hard to read), use a fixed font for plans (so they can be read) and better explain what it is you are looking for.

both plans above show partition elimination taking place.

  FROM staging_elig_dtls sed,wcard_mapping_tmp wcm
  WHERE sed.client_num=:client_num
  AND sed.mbr_id=wcm.mbr_id(+)
  --AND wcm.client_seq_id(+)=:client_seq;
  AND wcm.mbr_id(+)=:mbr_id 


and I don't see how you can compare THAT predicate to the prior one???!?!

they are totally different, not close to the same, answer entirely different questions, return different answers.

A reader, October 21, 2008 - 5:32 am UTC

Hi Tom,

Just want to know that whether outerjoin in a query is having any impact on partition?

regards,
Manoj.V


Tom Kyte
October 21, 2008 - 3:49 pm UTC

yes, it can.

but I don't see the relevance to the above - you seem to be comparing two entirely different queries, that just doesn't make sense. You either need to use the first or you need to use the second or you need the results of both - just because one partition eliminates and the other doesn't (or whatever) would not tell you which query is 'better', they do different things.

LISt partition Explain Plan

A reader, October 22, 2008 - 2:29 am UTC

Sorry Tom,

I confused you . I gone through the documents, but not mentioned about the explain plan interpretation of LIST partitioning. Thats why asked this question.

I want to know how a list partition explain plan to be interpreted. Is it same that of range and hash or it is different?

For e.g

My table details.

CREATE TABLE "SALES_BY_REGION"
( "ITEM" NUMBER(38,0),
"STATE_CODE" VARCHAR2(2 BYTE)
)
PARTITION BY LIST ("STATE_CODE")
(PARTITION "REGION_EAST" VALUES ('AB') NOCOMPRESS ,
PARTITION "REGION_WEST" VALUES ('CD') NOCOMPRESS ,
PARTITION "REGION_SOUTH" VALUES ('EF') NOCOMPRESS ,
PARTITION "REGION_CENTRAL" VALUES ('GH') NOCOMPRESS ,
PARTITION "REGION_UNKNOWN" VALUES (DEFAULT) NOCOMPRESS ) ENABLE ROW MOVEMENT ;

SQL> insert into sales_by_region values(1,'AB');

1 row created.

SQL> insert into sales_by_region values (2,'AB');

1 row created.

SQL> insert into sales_by_region values(3,'AB');

1 row created.

SQL> insert into sales_by_region values(1,'CD');

1 row created.

SQL> insert into sales_by_region values(2,'CD');

1 row created.

SQL> insert into sales_by_region values(3,'CD');

1 row created.

SQL> insert into sales_by_region values(1,'EF');

1 row created.

SQL>
SQL> insert into sales_by_region values(2,'EF');

1 row created.

SQL>
SQL> insert into sales_by_region values(3,'EF');

1 row created.

SQL> insert into sales_by_region values(1,'GH');

1 row created.

SQL> insert into sales_by_region values(2,'GH');

1 row created.

SQL>
SQL> insert into sales_by_region values(3,'GH');

1 row created.

SQL> commit;

Commit complete.

SQL> set autotrace on explain
SQL> select * from sales_by_region where state_code in ('AB','CD');

ITEM ST
---------- --
1 AB
2 AB
3 AB
1 CD
2 CD
3 CD

6 rows selected.


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=4 Card=6 Bytes=96)
1 0 PARTITION LIST (INLIST) (Cost=4 Card=6 Bytes=96)
2 1 TABLE ACCESS (FULL) OF 'SALES_BY_REGION' (TABLE) (Cost=4
Card=6 Bytes=96)




SQL> select * from sales_by_region where state_code='AB';

ITEM ST
---------- --
1 AB
2 AB
3 AB


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=3 Card=3 Bytes=48)
1 0 PARTITION LIST (SINGLE) (Cost=3 Card=3 Bytes=48)
2 1 TABLE ACCESS (FULL) OF 'SALES_BY_REGION' (TABLE) (Cost=3
Card=3 Bytes=48)




SQL> select * from sales_by_region where state_code='AB' or state_code='HJ';

ITEM ST
---------- --
1 AB
2 AB
3 AB


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=3 Card=3 Bytes=48)
1 0 PARTITION LIST (INLIST) (Cost=3 Card=3 Bytes=48)
2 1 TABLE ACCESS (FULL) OF 'SALES_BY_REGION' (TABLE) (Cost=3
Card=3 Bytes=48)




SQL> select * from sales_by_region where state_code='AB' or state_code='CD';

ITEM ST
---------- --
1 AB
2 AB
3 AB
1 CD
2 CD
3 CD

6 rows selected.


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=4 Card=6 Bytes=96)
1 0 PARTITION LIST (INLIST) (Cost=4 Card=6 Bytes=96)
2 1 TABLE ACCESS (FULL) OF 'SALES_BY_REGION' (TABLE) (Cost=4
Card=6 Bytes=96)




SQL> select * from sales_by_region where state_code='AB' and state_code='CD'

no rows selected


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=0 Card=1 Bytes=16)
1 0 FILTER
2 1 PARTITION LIST (SINGLE) (Cost=3 Card=3 Bytes=48)
3 2 TABLE ACCESS (FULL) OF 'SALES_BY_REGION' (TABLE) (Cost
=3 Card=3 Bytes=48)




SQL> select * from sales_by_region where state_code='AB' and state_code='XX'

no rows selected


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=0 Card=1 Bytes=16)
1 0 FILTER
2 1 PARTITION LIST (SINGLE) (Cost=3 Card=3 Bytes=48)
3 2 TABLE ACCESS (FULL) OF 'SALES_BY_REGION' (TABLE) (Cost
=3 Card=3 Bytes=48)




SQL> select * from sales_by_region where state_code='XX';

no rows selected


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=2 Card=1 Bytes=16)
1 0 PARTITION LIST (SINGLE) (Cost=2 Card=1 Bytes=16)
2 1 TABLE ACCESS (FULL) OF 'SALES_BY_REGION' (TABLE) (Cost=2
Card=1 Bytes=16)




SQL>

Even if there is no row as 'XX' it is showing a partition hit. i am wondering why is it so?

even if i am having values 'AB' and 'CD' in the table it is displaying a SINGLE partition instead of LIST ITERATION.

can u please find some time to explain me about the scenarios.

regards,
Manoj.V


Tom Kyte
October 22, 2008 - 8:48 am UTC

use dbms_xplan, not just autotrace, in 9i

You'll get a more meaningful explain plan with partition specific information.

Yes, you read it like a hash or a range plan - it'll tell you if you have partition elimination or not.

Partitioning Question

A reader, October 22, 2008 - 4:32 am UTC

Sorry Tom,

Forgot to add this question.

When i read the Oracle documentation on partition, i saw the below statement.

" A nonpartitioned table can have partitioned or nonpartitioned indexes". How come it is?

How will a nonpartioned table can have partioned index?

regards,
Manoj.V

partition key column

David, February 10, 2009 - 8:00 pm UTC

Currently, our partition key colum is of DATE datatype. Can it be changed to TIMESTAMP datatype? RDBMS version is 9.2.0.7.0.
If it is possible, is this change seamless? and what will be the impact of all the rows that are already there in the current datatype DATE?

Thanks.
Tom Kyte
February 11, 2009 - 10:31 am UTC

well, a timestamp is bigger (wider) and has lots more options.

This will be a reorganization


ops$tkyte%ORA11GR1> create table t as select sysdate dt, localtimestamp ts from dual;

Table created.
ops$tkyte%ORA11GR1> desc t
 Name                                     Null?    Type
 ---------------------------------------- -------- ----------------------------
 DT                                                DATE
 TS                                                TIMESTAMP(6)

ops$tkyte%ORA11GR1> select vsize(dt), vsize(ts) from t; 
 VSIZE(DT)  VSIZE(TS)
---------- ----------
         7         11


as every row will grow and you'd need to redefine the partitioning scheme based on the new timestamp datatype.

ops$tkyte%ORA11GR1> alter table t modify dt timestamp;
alter table t modify dt timestamp
                     *
ERROR at line 1:
ORA-14060: data type or length of a table partitioning column may not be
changed



how to create a weekly interval in 11g

Steven, April 21, 2009 - 3:41 pm UTC

I have been trying to get a date range partition using interval for a weekly partition and have not been successfull. I can create for a , day ,month , year inteval partitions, but do not see how to make a weekly using the interval in 11g. I saw your above commnents in this post and still am not able to figure out a weekly automated partition clause. Like the above posts I thought about using to_char(datefield,'iw'), but of course this is wrong. I need to end up with an ending date for each week.
Tom Kyte
April 21, 2009 - 4:07 pm UTC

interval (numtodsinterval(7,'day'))



create table audit_trail
( ts    timestamp,
  data  varchar2(30)
)
partition by range(ts)
interval (numtodsinterval(7,'day'))
store in (users, example )
(partition p0 values less than
 (to_date('12-apr-2009','dd-mon-yyyy'))
)
/




partition wise and indexes

A reader, June 05, 2009 - 5:58 am UTC

Hi Tom,

I started a new job at a big company and have started by analyzing their ERD. As such, I have pointed out the following situation that I want to share with you and for wich I need your precious help

They have a table T1 range partitioned on dat_dep. This table has a primary key composed of
(t1_id, dat_dep).

The primary key of table T1 (which has a locally partitioned index associated to it) is a foreign key for several range partitioned tables T2, T3, T4, etc... on the same partition key (dat_dep). Of course all those tables posses a FK (t1_id, dat_dep).


My first remark is

1. All the indexes on child tables covering the FK (t1_id, dat_dep) are not locally partitioned. In fact they are simple b-tree-indexes while the main PK (t1_id, dat_dep) is represented by a locally partitioned index

My first question is

I would suggest transforming all those FK b-tree indexes to locally partitioned index. It seems for me logical but I can¿t explain it. Do you agree with my suggestion?


My second remark is

There exist a couple of tables which are not partitioned while having a FK (t1_id, dat_dep) referencing the master partitioned table T1.

My second question is

I would suggest range partitioning those tables, on dat_dep, in order to take advantage of partition wise join. Do you agree with me?

Thanks very much for your help

Tom Kyte
June 08, 2009 - 12:03 pm UTC

1) no, I do not agree at all.

whether to partition *anything* needs to be justified. What is it you would hope to gain by locally partitioning these indexes? What is your goal, what do you think you will accomplish? and are you darn sure you will not kill performance by locally partitioning them (many times, you globally partition indexes so as to NOT impede retrieval performance)


If the queries against the T2 table for example look like:

select * from t2 where T1_ID = ?;

and you locally partition them by dat_dep, you'll end up doing N index range scans (where N = number of local index partitions). Right now, you are doing 1 index range scan. It would be a disaster in that case to locally partition.


It all goes to

a) what you want to accomplish (why are you partitioning)
b) how the data is used

you need both bits before partitioning anything


for your second question, I refer you to my first answer - it would be identical.

do you actually DO queries that would benefit from a partition wise join - that would be the first question.

and if so, would partitioning by that dimension

a) help the other queries
b) neither help nor hurt the other queries
c) kill the performance of the other queries.

Partition boundary

A reader, June 09, 2009 - 8:50 am UTC

Thanks very much for your answser. It's a chance to have someone from which we can take correct information in this oracle world where there is so much wrong information.

I have another remark about this project I am involved in. I did not understand why they have range partitioned on dat_dep as follows

PARTITION BY RANGE (DAT_DEP)
(
PARTITION PART_1_20070101 VALUES LESS THAN (TO_DATE(' 2007-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))

etc...

Knowing that the dat_dep is always without a timestamp I wonder why they have created those partition using HH24:MI:SS

1) Wouldn't it better to use this instead

PARTITION BY RANGE (DAT_DEP)
(
PARTITION PART_1_20070101 VALUES LESS THAN (TO_DATE('01-01-2007', 'DD-MM-YYYY'))

2) In addition they have created a Function Based Index on TRUNC(DAT_DEP). If they have created their boundary partitions without timestamp, they then would not need to have this extra FBI on dat_dep.
Could you please let me know if I am correct or not.

Best Regards

Tom Kyte
June 09, 2009 - 10:35 am UTC

... Knowing that the dat_dep is always without a timestamp I wonder why they have
created those partition using HH24:MI:SS ....


that is the most explicit, unambiguous representation of that date - it is very very clear what it is. That is good.

It is highly likely however that they DID NOT use that when they created the table.

That looks a lot like the default representation we use in dbms_metadata and related utilities:

ops$tkyte%ORA10GR2> CREATE TABLE t
  2  (
  3    dt  date,
  4    x   int,
  5    y   varchar2(30)
  6  )
  7  PARTITION BY RANGE (dt)
  8  
  9  (
 10    PARTITION part1 VALUES LESS THAN (to_date('01-jan-2008','dd-mon-yyyy')) ,
 11    PARTITION part2 VALUES LESS THAN (to_date('01-jan-2009','dd-mon-yyyy'))
 12  )
 13  ;

Table created.

ops$tkyte%ORA10GR2> select dbms_metadata.get_ddl( 'TABLE', 'T' ) from dual;

DBMS_METADATA.GET_DDL('TABLE','T')
-------------------------------------------------------------------------------

  CREATE TABLE "OPS$TKYTE"."T"
   (    "DT" DATE,
        "X" NUMBER(*,0),
        "Y" VARCHAR2(30)
   ) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255
  STORAGE(
  BUFFER_POOL DEFAULT)
  TABLESPACE "USERS"
  PARTITION BY RANGE ("DT")
 (PARTITION "PART1"  VALUES LESS THAN <b>(TO_DATE(' 2008-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))</b>
  PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255
  STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
  PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
  TABLESPACE "USERS" NOCOMPRESS ,
 PARTITION "PART2"  VALUES LESS THAN <b>(TO_DATE(' 2009-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))</b>
  PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255
  STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
  PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
  TABLESPACE "USERS" NOCOMPRESS )





Tell me, explain why your way would be "better"? What is better about letting something default? You could get inconsistent schemas if the NLS settings where to change or whatever.

and remember - this isn't about the values in DAT_DEP, this is rather in being precise about specifying the ending value of a partition - it would not matter if DAT_DEP had (or doesn't have) a time component.




2) are you sure that dat_dep doesn't have time stuffed in it? If it doesn't, using TRUNC on it doesn't really make sense (it is already trunced)


but that said - if dat_dep DOES have time in it, the specification of the range boundary would HAVE NO IMPACT on this.

but that said - if dat_dept DOES NOT have time in it, the specification of the range bounary would HAVE NO IMPACT on this.


why do you think this date literal (that is all it is - in your current default settings

(TO_DATE(' 2007-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))

and

(TO_DATE('01-01-2007',
'DD-MM-YYYY'))


are IDENTICAL - as in THE SAME - as in "NOT DIFFERENT" - as in, they both mean 0hundred hours on the 1st of January in the year 2007.



partition pruning and index

A reader, June 13, 2009 - 11:03 pm UTC

Hi Tom,
We have partition on year key, the table contains data for 7 years(around 7 million rows - 1 million per year ). We are pulling data for last two years through ETL. As table has 7 distinct values for year key, do you think that bitmap index on year key can speed up the extraction?

Regards,

Tom Kyte
June 15, 2009 - 12:05 pm UTC

think about it

you have 2,000,000 rows in two partitions you are interested in. No other data exists in these partitions.

which would be faster

o full scan retrieving 2,000,000 rows using nice big multi-block reads - knowing we want every row on every block we hit

o go from index to some block to index to some block to index to some block 2,000,000 times - using single block IO - perhaps reading and re-reading the same block hundreds of times (but not sequentially).


A full scan is the only sensible plan for this - given what you have said which is:

o pulling two years
o have partitioned by year
o getting all rows (assumed by me)


indexes are horrible for retrieving a lot of data. think about it.

Bitmap Indexes and partitioning

A reader, July 16, 2009 - 11:37 am UTC

Hi Tom,
We have a table t1 that is partitioned by period.
We are moving old periods(partitions) to a compressed table space. This table also has local bitmap indexes.
what is the best way to move these partitions into the new compressed tablespace. can i just mark the bitmap indexes for that partition unusable and do the move or else do i have to mark unusable for the index to move this.

Tom Kyte
July 16, 2009 - 4:27 pm UTC

you would just move the partition and then rebuild the local index partition - it'll go unusable all by itself when you do the move.


If the table doesn't have a compressed option already - you'll need to set unusable and rebuild the bitmap index the first time, else if it had compression enabled, you are set to go

ops$tkyte%ORA11GR1> CREATE TABLE t
  2  (
  3    dt  date,
  4    x   int,
  5    y   varchar2(30)
  6  )
  7  compress
  8  PARTITION BY RANGE (dt)
  9  (
 10    PARTITION part1 VALUES LESS THAN (to_date('01-jan-2008','dd-mon-yyyy')) ,
 11    PARTITION part2 VALUES LESS THAN (to_date('01-jan-2009','dd-mon-yyyy'))
 12  )
 13  /

Table created.

ops$tkyte%ORA11GR1> insert into t select to_date( '01-dec-2007' ) + mod(rownum,60), mod(rownum,5), rownum from all_objects;

68625 rows created.

ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> create bitmap index bm_index on t(x) local;

Index created.

ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> select partition_name, status from user_ind_partitions where index_name = 'BM_INDEX';

PARTITION_NAME                 STATUS
------------------------------ --------
PART1                          USABLE
PART2                          USABLE

ops$tkyte%ORA11GR1> alter table t move partition part1 compress;

Table altered.

ops$tkyte%ORA11GR1> select partition_name, status from user_ind_partitions where index_name = 'BM_INDEX';

PARTITION_NAME                 STATUS
------------------------------ --------
PART1                          UNUSABLE
PART2                          USABLE

ops$tkyte%ORA11GR1> alter index bm_index rebuild partition part1;

Index altered.

ops$tkyte%ORA11GR1> select partition_name, status from user_ind_partitions where index_name = 'BM_INDEX';

PARTITION_NAME                 STATUS
------------------------------ --------
PART1                          USABLE
PART2                          USABLE


Bitmap Indexes and partitioning

Sandeep, July 17, 2009 - 11:18 am UTC

Hi Tom,
Thanks a lot for your quick response.In my case the table does not have compression enabled.i tried to set the bitmap index for that partition unusable and tried to move the partition and it give me the following error
ORA-14646: Specified alter table operation involving compression cannot be performed in the presence of usable bitmap indexes. Is there any other way to move this partition without marking the whole index(all partitions) unusable.


Tom Kyte
July 24, 2009 - 8:35 am UTC

as stated, if the table did not have 'compress' before, the first time you move, you need to rebuild the bitmap index - the bitmap index MUST be aware the data in the underlying table is to be compressed at some point, it radically affects the data in the bitmap structure.

You have to do this the first time.

How is the hash value decided

DK, September 08, 2009 - 6:35 am UTC

Hi Tom,

I want to know how what is the method Oracle uses to generate the Hash value,that is if a new record is inserted how does oracle decides in which partition this row should belong to(basically what is the Hash algorithm )

Hash Partitioned Table CREATE TABLE hash_part (
prof_history_id NUMBER(10),
person_id NUMBER(10) NOT NULL,
organization_id NUMBER(10) NOT NULL,
record_date DATE NOT NULL,
prof_hist_comments VARCHAR2(2000))
PARTITION BY HASH (prof_history_id)
PARTITIONS 3
STORE IN (part1, part2, part3);

Thanks,
Dheeraj

Tom Kyte
September 08, 2009 - 7:13 am UTC

it is an algorithm that needs us to use powers of 2 - 2, 4, 8, 16, 32, 64, ... number of partitions - never 3.

Beyond that, it is just a hash algorithm to map an infinite set of inputs into a finite (power of 2) set.

the algorithm beyond that is internal.

A reader, March 05, 2010 - 11:17 am UTC

Tom, 

<quote> The fact is that a query 
that uses a local prefixed index will always allow for index partition elimination, whereas a query 
that uses a local non-prefixed index might not. </quote>

when a local non_prefixed index 'might' perform partition elimination?

take the example above:
SQL> create table test (test_id number(13), test_date date, test_desc varchar2(30))
  2  partition by range (test_date)
  3  (partition P_200612 values less than (to_date('01 Jan 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  4   partition P_200701 values less than (to_date('01 Feb 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  5   partition P_200702 values less than (to_date('01 Mar 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  6   partition P_200703 values less than (to_date('01 Apr 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  7   partition P_200704 values less than (to_date('01 May 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  8   partition P_200705 values less than (to_date('01 Jun 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  9   partition P_200706 values less than (to_date('01 Jul 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 10   partition P_200707 values less than (to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 11   partition P_200708 values less than (to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 12   partition P_200709 values less than (to_date('01 Oct 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 13   partition P_200710 values less than (to_date('01 Nov 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 14   partition P_200711 values less than (to_date('01 Dec 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 15   partition P_200712 values less than (to_date('01 Jan 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 16   partition P_200713 values less than (to_date('01 Feb 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 17   partition P_CURRENT values less than (maxvalue));

Table created.

SQL> insert into test select rownum, to_date( '01-dec-2008')+mod(rownum,365),
  2  object_name
  3  from all_objects;

32344 rows created.

SQL> create index test_local on test (test_id) local;

Index created.

SQL> exec dbms_stats.gather_table_stats( user, 'TEST', cascade=>true );

PL/SQL procedure successfully completed.

SQL> @p

0 rows deleted.

Enter value for l: select * from test where test_id = 11333

Explained.


PLAN_TABLE_OUTPUT
-----------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2683220617

-----------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name       | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |            |     1 |    29 |    17   (0)| 00:00:01 |    |  |
|   1 |  PARTITION RANGE ALL               |            |     1 |    29 |    17   (0)| 00:00:01 |     1 |    15 |
|   2 |   TABLE ACCESS BY LOCAL INDEX ROWID| TEST       |     1 |    29 |    17   (0)| 00:00:01 |     1 |    15 |
|*  3 |    INDEX RANGE SCAN                | TEST_LOCAL |     1 |       |    16   (0)| 00:00:01 |     1 |    15 |
-----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("TEST_ID"=11333)

15 rows selected.

SQL> select * from v$version where banner like 'Oracle%';

BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.1.0.7.0 - 64bit Production

SQL>


Question:

Is there any way to let Oracle to perform partition elimination here? we want the data about test_id = 11333, we don't know which partition, should Oracle know about it? what condition a local non_prefixed index 'might' perform partition elimination?

Thanks

Tom Kyte
March 09, 2010 - 11:39 am UTC

take your example and query

where test_id = 11333 and test_date = to_date( '01-jan-2009', 'dd-mon-yyyy' );


We will partition eliminate using test_date = to_date(), we will index range scan on the remaining index partition.





If your predicate is "where test_id = 11333" - and your index is on test_id and your index is locally partitioned not only do you not know what partition it is in - Oracle does not".

It could be in 0, 1 or ALL of the partitions, or every other partition, or the 3rd and 5th partitions, whatever.

In order for the local non prefixed index to use partition elimination, you must involve the partition key in the query somehow - it doesn't need to be in the index - but it would need to be referenced in the query itself.

A reader, March 05, 2010 - 1:53 pm UTC

Thanks Tom,

Will global partitioned index help to perform elimination if the WHERE CLAUSE has no partition key involved? 

Here I created a new table as an example (2 date type columns):

SQL> create table new_test (test_id number(13), test_date date, created_date date)
  2    partition by range (test_date)
  3    (partition P_200612 values less than (to_date('01 Jan 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  4     partition P_200701 values less than (to_date('01 Feb 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  5     partition P_200702 values less than (to_date('01 Mar 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  6     partition P_200703 values less than (to_date('01 Apr 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  7     partition P_200704 values less than (to_date('01 May 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  8     partition P_200705 values less than (to_date('01 Jun 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  9     partition P_200706 values less than (to_date('01 Jul 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 10     partition P_200707 values less than (to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 11     partition P_200708 values less than (to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 12     partition P_200709 values less than (to_date('01 Oct 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 13     partition P_200710 values less than (to_date('01 Nov 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 14     partition P_200711 values less than (to_date('01 Dec 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 15     partition P_200712 values less than (to_date('01 Jan 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 16     partition P_200713 values less than (to_date('01 Feb 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 17     partition P_CURRENT values less than (maxvalue));

Table created.

SQL> insert into new_test select rownum, to_date( '01-dec-2008')+mod(rownum,365),  to_date( '01-dec-2008')+mod(rownum,365) + 1
  2  from all_objects;

32436 rows created.

SQL> commit;

Commit complete.

SQL> create index ix_global1 on new_test (created_date)
  2  GLOBAL PARTITION BY RANGE (created_date)
  3    (partition P_200612 values less than (to_date('01 Jan 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  4     partition P_200701 values less than (to_date('01 Feb 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  5     partition P_200702 values less than (to_date('01 Mar 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  6     partition P_200703 values less than (to_date('01 Apr 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  7     partition P_200704 values less than (to_date('01 May 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  8     partition P_200705 values less than (to_date('01 Jun 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  9     partition P_200706 values less than (to_date('01 Jul 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 10     partition P_200707 values less than (to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 11     partition P_200708 values less than (to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 12     partition P_200709 values less than (to_date('01 Oct 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 13     partition P_200710 values less than (to_date('01 Nov 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 14     partition P_200711 values less than (to_date('01 Dec 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 15     partition P_200712 values less than (to_date('01 Jan 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 16     partition P_200713 values less than (to_date('01 Feb 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 17     partition P_CURRENT values less than (maxvalue));

Index created.

SQL> create index ix_global2 on new_test (test_date, created_date)
  2  GLOBAL PARTITION BY RANGE (created_date)
  3    (partition P_200612 values less than (to_date('01 Jan 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  4     partition P_200701 values less than (to_date('01 Feb 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  5     partition P_200702 values less than (to_date('01 Mar 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  6     partition P_200703 values less than (to_date('01 Apr 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  7     partition P_200704 values less than (to_date('01 May 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  8     partition P_200705 values less than (to_date('01 Jun 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  9     partition P_200706 values less than (to_date('01 Jul 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 10     partition P_200707 values less than (to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 11     partition P_200708 values less than (to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 12     partition P_200709 values less than (to_date('01 Oct 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 13     partition P_200710 values less than (to_date('01 Nov 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 14     partition P_200711 values less than (to_date('01 Dec 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 15     partition P_200712 values less than (to_date('01 Jan 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 16     partition P_200713 values less than (to_date('01 Feb 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 17     partition P_CURRENT values less than (maxvalue));
GLOBAL PARTITION BY RANGE (created_date)
                                       *
ERROR at line 2:
ORA-14038: GLOBAL partitioned index must be prefixed


SQL>
SQL> create index ix_global2 on new_test (test_date, created_date)
  2  GLOBAL PARTITION BY RANGE (test_date)
  3    (partition P_200612 values less than (to_date('01 Jan 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  4     partition P_200701 values less than (to_date('01 Feb 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  5     partition P_200702 values less than (to_date('01 Mar 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  6     partition P_200703 values less than (to_date('01 Apr 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  7     partition P_200704 values less than (to_date('01 May 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  8     partition P_200705 values less than (to_date('01 Jun 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  9     partition P_200706 values less than (to_date('01 Jul 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 10     partition P_200707 values less than (to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 11     partition P_200708 values less than (to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 12     partition P_200709 values less than (to_date('01 Oct 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 13     partition P_200710 values less than (to_date('01 Nov 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 14     partition P_200711 values less than (to_date('01 Dec 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 15     partition P_200712 values less than (to_date('01 Jan 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 16     partition P_200713 values less than (to_date('01 Feb 2010 00:00:00','dd mon yyyy hh24:mi:ss')),
 17     partition P_CURRENT values less than (maxvalue));

Index created.


SQL> exec dbms_stats.gather_table_stats( user, 'NEW_TEST', cascade=>true );

PL/SQL procedure successfully completed.

SQL> @CHKPART
Enter value for tbl: new_test
old   2: table_name=upper('&tbl')
new   2: table_name=upper('new_test')

PARTITION_NAME                 TO_CHAR(LAST_ANALYZED,'YYYY-MON-DDHH24:MI:SS')                             NUM_ROWS
------------------------------ --------------------------------------------------------------------------- ----------
P_200612                       2010-MAR-05 14:33:38                                                      2758
P_200701                       2010-MAR-05 14:33:38                                                      2759
P_200702                       2010-MAR-05 14:33:39                                                      2492
P_200703                       2010-MAR-05 14:33:39                                                      2759
P_200704                       2010-MAR-05 14:33:40                                                      2670
P_200705                       2010-MAR-05 14:33:40                                                      2759
P_200706                       2010-MAR-05 14:33:40                                                      2670
P_200707                       2010-MAR-05 14:33:41                                                      2759
P_200708                       2010-MAR-05 14:33:41                                                      2759
P_200709                       2010-MAR-05 14:33:42                                                      2670
P_200710                       2010-MAR-05 14:33:42                                                      2741
P_200711                       2010-MAR-05 14:33:42                                                      2640
P_200712                       2010-MAR-05 14:33:42                                                         0
P_200713                       2010-MAR-05 14:33:42                                                         0
P_CURRENT                      2010-MAR-05 14:33:42                                                         0

15 rows selected.

SQL> @P

3 rows deleted.

Enter value for l: select * from new_test where created_date between to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss') and to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')
old   1: explain plan for &l
new   1: explain plan for select * from new_test where created_date between to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss') and to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')

Explained.


PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 425827078

------------------------------------------------------------------------------------------------
| Id  | Operation           | Name     | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT    |          |  2940 | 58800 |    26   (8)| 00:00:01 |       |       |
|   1 |  PARTITION RANGE ALL|          |  2940 | 58800 |    26   (8)| 00:00:01 |     1 |    15 |
|*  2 |   TABLE ACCESS FULL | NEW_TEST |  2940 | 58800 |    26   (8)| 00:00:01 |     1 |    15 |
------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("CREATED_DATE">=TO_DATE(' 2009-08-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')
              AND "CREATED_DATE"<=TO_DATE(' 2009-09-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))

15 rows selected.

SQL>


As you can see, it still does a full scan on all partitions if only non-partition key in the WHERE CLAUSE, did I create a wrong global partition index? what index should I create to do the elimination in the above example?


Thanks a lot.

Tom Kyte
March 05, 2010 - 2:45 pm UTC

... Will global partitioned index help to perform elimination if the WHERE CLAUSE
has no partition key involved? ...

close your eyes, envision the data - how it is laid out on disk, imagine what the process would be if you globally partitioned the index.


the answer is "of course, if you partition the index t(test_id) by values of TEST_ID, then where test_id = ? would be able to partition eliminate"


rather than you posting failed attempts, why don't you explain

a) how you would like the table partitioned
b) what predicate you would like to use

we can make this example really tiny.


If your goal is:

elect * from new_test where created_date between
to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss') and to_date('01 Sep
2009 00:00:00','dd mon yyyy hh24:mi:ss')


then create a globally partitioned index on CREATED_DATE, partitioning that index by CREATED_DATE.

like this:
 create index ix_global2 on new_test (created_date)
 GLOBAL PARTITION BY RANGE (create_date)
 (partition P_200612 values less than (to_date('01 Jan 2009 00:00:00','dd 
mon yyyy hh24:mi:ss')),
  partition P_200701 values less than (to_date('01 Feb 2009 00:00:00','dd 
mon yyyy hh24:mi:ss')),

adding partitions automatically

tariq, March 07, 2010 - 7:32 am UTC

Dear Tom,

I want to know any pl/sql block or script which add partitions automatically at the end of month.... Normally we are using manual procedure to add partitions for instance:

ALTER TABLE MSM_BIDUMP_HIST ADD PARTITION NOV2009 VALUES LESS THAN (TO_DATE ('2009-DEC-1','YYYY-MON-DD')) TABLESPACE HISTDATA_JAN;

we have two options in this situation.
1- for the same tablespace
2- different tablespace.

Regards,
Tom Kyte
March 09, 2010 - 11:02 am UTC

11g Release 1 does this via DDL (interval partitions)

otherwise, you would have to create logic specific to your needs to do this. In general, it would do something like:

read user_tab_parttions ordered by partition id to get the last partition name
use to_date to turn that name into a date
use add months to turn that date into next month
use to_char to turn that into a string (the next partition name)
use execute immediate to add that partition
use dbms_scheduler to schedule that job to run say 5 days before the end of a month and monitor that job.


A reader, March 08, 2010 - 10:22 am UTC

</B>

Tom,

tried not to bother you during the weekend. As you suggested, i created a global index on the non-partitioned column, but it never shows in the plan.
we actually have lots of partition table which partitioned on column RECEPTION_TIME, but we use column OPENING_TIME more often to query than RECEPTION_TIME (the way it designed).
Here is a real example (may be not 100%) FYR:

SQL>
SQL> create table test (ID number, RECEPTION_TIME date, OPENING_TIME date)
  2      partition by range (RECEPTION_TIME)
  3      (partition P_200812 values less than (to_date('01 Jan 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  4       partition P_200901 values less than (to_date('01 Feb 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  5       partition P_200902 values less than (to_date('01 Mar 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  6       partition P_200903 values less than (to_date('01 Apr 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  7       partition P_200904 values less than (to_date('01 May 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  8       partition P_200905 values less than (to_date('01 Jun 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  9       partition P_200906 values less than (to_date('01 Jul 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 10       partition P_200907 values less than (to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 11       partition P_200908 values less than (to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 12       partition P_200909 values less than (to_date('01 Oct 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 13       partition P_200910 values less than (to_date('01 Nov 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 14       partition P_200911 values less than (to_date('01 Dec 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 15       partition P_CURRENT values less than (maxvalue));

Table created.

SQL> insert into test select rownum, to_date( '01-dec-2008')+mod(rownum,365),  to_date( '01-dec-2008')+mod(rownum,365) + 1
  2    from all_objects;

21269 rows created.

SQL> commit;

Commit complete.

SQL> ALTER TABLE TEST ADD (
  2    CONSTRAINT PK_TEST
  3   PRIMARY KEY
  4   (ID, RECEPTION_TIME)
  5   USING INDEX LOCAL);

Table altered.

SQL> create index ix_global on test (opening_time)
  2   GLOBAL PARTITION BY RANGE (opening_time)
  3  (partition P_200812 values less than (to_date('01 Jan 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  4   partition P_200901 values less than (to_date('01 Feb 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  5   partition P_200902 values less than (to_date('01 Mar 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  6   partition P_200903 values less than (to_date('01 Apr 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  7   partition P_200904 values less than (to_date('01 May 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  8   partition P_200905 values less than (to_date('01 Jun 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
  9   partition P_200906 values less than (to_date('01 Jul 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 10   partition P_200907 values less than (to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 11   partition P_200908 values less than (to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 12   partition P_200909 values less than (to_date('01 Oct 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 13   partition P_200910 values less than (to_date('01 Nov 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 14   partition P_200911 values less than (to_date('01 Dec 2009 00:00:00','dd mon yyyy hh24:mi:ss')),
 15   partition P_CURRENT values less than (maxvalue));

Index created.

SQL> exec dbms_stats.gather_table_stats( user, 'TEST', cascade=>true );

PL/SQL procedure successfully completed.

SQL> @p

0 rows deleted.

Enter value for l: select * from test where opening_time between to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss') and to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')

Explained.


PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2757090350

--------------------------------------------------------------------------------------------
| Id  | Operation           | Name | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT    |      |  1928 | 38560 |    25   (4)| 00:00:01 |       |       |
|   1 |  PARTITION RANGE ALL|      |  1928 | 38560 |    25   (4)| 00:00:01 |     1 |    13 |
|*  2 |   TABLE ACCESS FULL | TEST |  1928 | 38560 |    25   (4)| 00:00:01 |     1 |    13 |
--------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("OPENING_TIME">=TO_DATE(' 2009-08-01 00:00:00', 'syyyy-mm-dd
              hh24:mi:ss') AND "OPENING_TIME"<=TO_DATE(' 2009-09-01 00:00:00', 'syyyy-mm-dd
              hh24:mi:ss'))

16 rows selected.


in this example, how to avoid 'PARTITION RANGE ALL' if the predicate is "where OPENING_TIME=?'

Thanks.

Tom Kyte
March 09, 2010 - 11:39 am UTC

... (may be not 100%) ...

why would you post it then? If it doesn't work 100% or show 100% of what you mean???

In this case, it said "I want 1928 rows out of 21,269 rows. I see these rows are scattered all over the place, hence I do not see this index as being better than a full scan - so, I'll full scan"

Normal, expected, would happen with or without partitioning.

Use a smaller range of values.

the cost of the index was more than the cost of the full scan - would happen regardless of your partitioning scheme

ops$tkyte%ORA11GR2> set autotrace traceonly explain
ops$tkyte%ORA11GR2> select * from test where opening_time between to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss') and to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')
  2  /

Execution Plan
----------------------------------------------------------
Plan hash value: 2199936479

--------------------------------------------------------------------------------------------
| Id  | Operation           | Name | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT    |      |  6488 |   133K|    91   (2)| 00:00:02 |       |       |
|   1 |  PARTITION RANGE ALL|      |  6488 |   133K|    91   (2)| 00:00:02 |     1 |    13 |
|*  2 |   TABLE ACCESS FULL | TEST |  6488 |   133K|    91   (2)| 00:00:02 |     1 |    13 |
--------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("OPENING_TIME">=TO_DATE(' 2009-08-01 00:00:00', 'syyyy-mm-dd
              hh24:mi:ss') AND "OPENING_TIME"<=TO_DATE(' 2009-09-01 00:00:00', 'syyyy-mm-dd
              hh24:mi:ss'))

ops$tkyte%ORA11GR2> select /*+ index( test ix_global ) */ * from test where opening_time between to_date('01 Aug 2009 00:00:00','dd mon yyyy hh24:mi:ss') and to_date('01 Sep 2009 00:00:00','dd mon yyyy hh24:mi:ss')
  2  /

Execution Plan
----------------------------------------------------------
Plan hash value: 3194046142

-----------------------------------------------------------------------------------------------------------------
| Id  | Operation                           | Name      | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |           |  6488 |   133K|   735   (0)| 00:00:09 |       |       |
|   1 |  PARTITION RANGE ITERATOR           |           |  6488 |   133K|   735   (0)| 00:00:09 |     9 |    10 |
|   2 |   TABLE ACCESS BY GLOBAL INDEX ROWID| TEST      |  6488 |   133K|   735   (0)| 00:00:09 | ROWID | ROWID |
|*  3 |    INDEX RANGE SCAN                 | IX_GLOBAL |  6488 |       |    23   (0)| 00:00:01 |     9 |    10 |
-----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("OPENING_TIME">=TO_DATE(' 2009-08-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
              "OPENING_TIME"<=TO_DATE(' 2009-09-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))

ops$tkyte%ORA11GR2> set autotrace off

adding partitions automatically

Tariq, March 10, 2010 - 2:19 am UTC

Dear Tom,

Thank you very much for assistance.
Can you please give any example w.r.t given suggestion for Oracle 9i or 10g. it will be more helpful for me.

Regards,
Tom Kyte
March 10, 2010 - 8:44 am UTC

I already did, re-read my response. It begins with

otherwise, you would have to create logic specific to your needs to do this. In general, it would do something like:

followed by what you need to do...

Global index interval partition

A reader, March 11, 2010 - 1:36 pm UTC

SQL> CREATE TABLE interval_test
  2  (
  3  id                 NUMBER,
  4  order_date  DATE,
  5  proc_date   DATE
  6  )
  7  PARTITION BY RANGE (order_date)
  8  INTERVAL ( NUMTODSINTERVAL (1, 'DAY') ) (
  9  PARTITION P01
 10  VALUES LESS THAN ('01-MAR-2010'));

Table created.

SQL> CREATE INDEX ix_g
  2  ON interval_test (proc_date)
  3  GLOBAL PARTITION BY RANGE ( proc_date )
  4  INTERVAL (NUMTODSINTERVAL(1,'DAY'))
  5  (partition P01 values less than ('01-MAR-2010'));
INTERVAL (NUMTODSINTERVAL(1,'DAY'))
*
ERROR at line 4:
ORA-00906: missing left parenthesis

it seems Oracle doesn't support global index interval partition?

Tom Kyte
March 12, 2010 - 2:36 pm UTC

correct.

in fact, not even for index organized tables.

Any alternate for 'partition by reference' in 10g?

Manjunath, June 10, 2010 - 10:55 am UTC

Hi Tom,

Is there a way to replicate the 'partition by reference' feature in 10g? We have some killer queries in the online application that would benefit a lot by it, and unfortunately 11g is still some time away for this app.

Below is a psuedo query and its explain plan:(after altering the session to use 'all_fows'). I am sorry, for not using the actual query itself.

The nat table has a partitioned index on nat_dt.

SELECT /*+ full(d) parallel(d,4,1) full(ds) parallel(ds,4,1) full(db) parallel(db,4,1) */
db.nat_batch_id,
ds.nat_slip_id,
ds.transaction_participant_id,
d.nat_dt,
db.don_batch_source_lkp_id
FROM nat_batch db,
nat d,
nat_slip ds
WHERE d.nat_dt >= '01-Jan-2009'
and d.nat_dt <= '31-Jan-2009'
and d.nat_batch_id = db.nat_batch_id
AND ds.nat_id = d.nat_id
AND ds.nat_adj_cd = 'A'
AND db.nat_BATCH_CODE='A'
AND db.POSTED_DATE is not null
and db.DON_BATCH_STAT_LKP_ID=64;

------------------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | TQ |IN-OUT| PQ Distrib |
------------------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 401K| 25M| 29400 (7)| 00:06:15 | | | | | |
| 1 | PX COORDINATOR | | | | | | | | | | |
| 2 | PX SEND QC (RANDOM) | :TQ10002 | 401K| 25M| 29400 (7)| 00:06:15 | | | Q1,02 | P->S | QC (RAND) |
|* 3 | HASH JOIN | | 401K| 25M| 29400 (7)| 00:06:15 | | | Q1,02 | PCWP | |
| 4 | PX RECEIVE | | 367K| 15M| 13973 (8)| 00:02:58 | | | Q1,02 | PCWP | |
| 5 | PX SEND BROADCAST | :TQ10001 | 367K| 15M| 13973 (8)| 00:02:58 | | | Q1,01 | P->P | BROADCAST |
|* 6 | HASH JOIN | | 367K| 15M| 13973 (8)| 00:02:58 | | | Q1,01 | PCWP | |
| 7 | PX RECEIVE | | 367K| 7544K| 11754 (8)| 00:02:30 | | | Q1,01 | PCWP | |
| 8 | PX SEND BROADCAST | :TQ10000 | 367K| 7544K| 11754 (8)| 00:02:30 | | | Q1,00 | P->P | BROADCAST |
| 9 | PX BLOCK ITERATOR | | 367K| 7544K| 11754 (8)| 00:02:30 | 1 | 104 | Q1,00 | PCWC | |
|* 10 | TABLE ACCESS FULL| NAT | 367K| 7544K| 11754 (8)| 00:02:30 | 1 | 104 | Q1,00 | PCWP | |
| 11 | PX BLOCK ITERATOR | | 1418K| 31M| 2211 (5)| 00:00:29 | 1 | 104 | Q1,01 | PCWC | |
|* 12 | TABLE ACCESS FULL | NAT_BAT | 1418K| 31M| 2211 (5)| 00:00:29 | 1 | 104 | Q1,01 | PCWP | |
| 13 | PX BLOCK ITERATOR | | 56M| 1195M| 15219 (5)| 00:03:14 | 1 | 104 | Q1,02 | PCWC | |
|* 14 | TABLE ACCESS FULL | NAT_SLIP | 56M| 1195M| 15219 (5)| 00:03:14 | 1 | 104 | Q1,02 | PCWP | |
------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

3 - access("DS"."NAT_ID"="D"."NAT_ID")
6 - access("D"."NAT_BATCH_ID"="DB"."NAT_BATCH_ID")
10 - filter("D"."NAT_DT">=TO_DATE(' 2009-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "D"."NAT_DT"<=TO_DATE('
2009-01-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))
12 - filter("DB"."DON_BATCH_STAT_LKP_ID"=64 AND "DB"."POSTED_DATE" IS NOT NULL AND "DB"."NAT_BATCH_CODE"='A')
14 - filter("DS"."NAT_ADJ_CD"='A')
********************************************
Plan without the hints:

-------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1001 | 66066 | 772 (1)| 00:00:10 | | |
|* 1 | TABLE ACCESS BY GLOBAL INDEX ROWID | NAT_SLIP | 1 | 22 | 1 (0)| 00:00:01 | ROWID | ROWID |
| 2 | NESTED LOOPS | | 1001 | 66066 | 772 (1)| 00:00:10 | | |
| 3 | NESTED LOOPS | | 918 | 40392 | 312 (0)| 00:00:04 | | |
| 4 | PARTITION RANGE SINGLE | | 367K| 7544K| 82 (0)| 00:00:02 | 8 | 8 |
| 5 | TABLE ACCESS BY GLOBAL INDEX ROWID| NAT | 367K| 7544K| 82 (0)| 00:00:02 | ROWID | ROWID |
|* 6 | INDEX RANGE SCAN | IX_NAT_DON_DT | 367K| | 1 (0)| 00:00:01 | 8 | 8 |
| 7 | PARTITION HASH ITERATOR | | 1 | 23 | 1 (0)| 00:00:01 | KEY | KEY |
|* 8 | TABLE ACCESS BY GLOBAL INDEX ROWID| NAT_BATCH | 1 | 23 | 1 (0)| 00:00:01 | ROWID | ROWID |
|* 9 | INDEX UNIQUE SCAN | PK_NAT_BATCH | 1 | | 1 (0)| 00:00:01 | KEY | KEY |
| 10 | PARTITION HASH ITERATOR | | 1 | | 1 (0)| 00:00:01 | KEY | KEY |
|* 11 | INDEX RANGE SCAN | FK_DON_SLIP_NAT | 1 | | 1 (0)| 00:00:01 | KEY | KEY |
-------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("DS"."NAT_ADJ_CD"='A')
6 - access("D"."NAT_DT">=TO_DATE(' 2009-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
"D"."NAT_DT"<=TO_DATE(' 2009-01-30 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))
8 - filter("DB"."DON_BATCH_STAT_LKP_ID"=64 AND "DB"."POSTED_DATE" IS NOT NULL AND "DB"."NAT_BATCH_CODE"='A')
9 - access("D"."NAT_BAT_ID"="DB"."NAT_BAT_ID")
11 - access("DS"."NAT_ID"="D"."NAT_ID")

Or if there is no such alternate, is there any other suggesgtion that I can try to see if it makes a difference? I have found that if the hints are not used, the plan will use all index scans and it will just hang. With the hints, atleast the query returns under 2 mins.

Thanks and regards
Manjunath
Tom Kyte
June 10, 2010 - 2:38 pm UTC

... Is there a way to replicate the 'partition by reference' feature in 10g?...

you would have to denormalize the partition key down from the parent into the child and maintain it yourself - there is no other magic.


Locally partitioned Non-Prefixed Vs Locally partitioned Prefixed index

Rajeshwaran, Jeyabal, August 04, 2010 - 10:16 am UTC

scott@10GR2> select * from v$version;

BANNER
----------------------------------------------------------------
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Prod
PL/SQL Release 10.2.0.1.0 - Production
CORE    10.2.0.1.0      Production
TNS for 32-bit Windows: Version 10.2.0.1.0 - Production
NLSRTL Version 10.2.0.1.0 - Production

Elapsed: 00:00:00.01
scott@10GR2> create table t(
  2     range_part_key number,
  3     y              number,
  4     z              date
  5  )
  6  partition by range (range_part_key)
  7  (
  8     partition p1 values less than (100001),
  9     partition p2 values less than (200001),
 10     partition p3 values less than (300001),
 11     partition p4 values less than (400001),
 12     partition p5 values less than (500001),
 13     partition p_max values less than (maxvalue)
 14  );

Table created.

Elapsed: 00:00:00.07
scott@10GR2>  insert /*+ append */ into t
  2  select level,level,sysdate
  3  from dual
  4  connect by level <= 1000000;

1000000 rows created.

Elapsed: 00:00:05.34
scott@10GR2> commit;

Commit complete.

Elapsed: 00:00:00.03
scott@10GR2> create index t_loc_non_prefix on t(y,range_part_key) local;

Index created.

Elapsed: 00:00:04.40
scott@10GR2> exec dbms_stats.gather_table_stats(ownname=>USER,tabname=>'T',estimate_percent=>dbms_Stats.auto_sample_size,cascade=>true,method_opt=>' for all indexed columns size 254');

PL/SQL procedure successfully completed.

Elapsed: 00:00:22.85
scott@10GR2> set autotrace traceonly explain statistics;
scott@10GR2> select *
  2  from T
  3  where range_part_key = 1
  4  and   y    = 1;

Elapsed: 00:00:00.03

Execution Plan
----------------------------------------------------------
Plan hash value: 3103131813

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name             | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |                  |     1 |    17 |     2   (0)| 00:00:01 |       |       |
|   1 |  PARTITION RANGE SINGLE            |                  |     1 |    17 |     2   (0)| 00:00:01 |     1 |     1 |
|   2 |   TABLE ACCESS BY LOCAL INDEX ROWID| T                |     1 |    17 |     2   (0)| 00:00:01 |     1 |     1 |
|*  3 |    INDEX RANGE SCAN                | T_LOC_NON_PREFIX |     1 |       |     1   (0)| 00:00:01 |     1 |     1 |
-----------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("Y"=1 AND "RANGE_PART_KEY"=1)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          4  consistent gets
          0  physical reads
          0  redo size
        530  bytes sent via SQL*Net to client
        396  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

scott@10GR2> set autotrace off;
scott@10GR2> drop index t_loc_non_prefix;

Index dropped.

Elapsed: 00:00:00.89
scott@10GR2> create index t_loc_prefix on t(range_part_key,y) local;

Index created.

Elapsed: 00:00:03.53
scott@10GR2> exec dbms_stats.gather_table_stats(ownname=>USER,tabname=>'T',estimate_percent=>dbms_Stats.auto_sample_size,cascade=>true,method_opt=>' for all indexed columns size 254');

PL/SQL procedure successfully completed.

Elapsed: 00:00:24.65
scott@10GR2> set autotrace traceonly explain statistics;
scott@10GR2> select *
  2  from T
  3  where range_part_key = 1
  4  and   y    = 1;

Elapsed: 00:00:00.01

Execution Plan
----------------------------------------------------------
Plan hash value: 3206085244

-------------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name         | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |              |     1 |    17 |     2   (0)| 00:00:01 |    |          |
|   1 |  PARTITION RANGE SINGLE            |              |     1 |    17 |     2   (0)| 00:00:01 |  1 |        1 |
|   2 |   TABLE ACCESS BY LOCAL INDEX ROWID| T            |     1 |    17 |     2   (0)| 00:00:01 |  1 |        1 |
|*  3 |    INDEX RANGE SCAN                | T_LOC_PREFIX |     1 |       |     1   (0)| 00:00:01 |  1 |        1 |
-------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("RANGE_PART_KEY"=1 AND "Y"=1)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          4  consistent gets
          0  physical reads
          0  redo size
        530  bytes sent via SQL*Net to client
        396  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

scott@10GR2> set autotrace off;
scott@10GR2>


Tom:
Quote from Expert Oracle Database Architecture.

<quote>
Local nonprefixed indexes: These indexes do not have the partition key on the leading
edge of their column list. The index may or may not contain the partition key columns.

The fact is that a query that uses a local prefixed index will always allow for index partition elimination,
whereas a query that uses a local nonprefixed index might not. This is why local nonprefixed
indexes are said to be “slower” by some people—they do not enforce partition elimination
</quote>

Questions

1) I did a Benchmark of having a Locally partitioned Non-Prefixed index (t_loc_non_prefix) and Locally partitioned Prefixed index (T_LOC_PREFIX). I don't see any performance improvement of having Locally partitioned Prefixed index. Both looks same for me. Am i doing things wrong here? or my understanding of Locally partitioned Non-Prefixed is incorrect?

If i Exclude the Partition key columns from index creation (Locally partitioned Non-Prefixed index). I could see that Optimizer is scanning all the partitions if Partition key is missing in predicates.

scott@10GR2> create index t_loc_non_prefix on t(y) local;

Index created.

Elapsed: 00:00:03.00
scott@10GR2> set autotrace traceonly explain statistics;
scott@10GR2> select *
  2  from T
  3  where y =1;

Elapsed: 00:00:00.01

Execution Plan
----------------------------------------------------------
Plan hash value: 2852055923

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name             | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |                  |     1 |    17 |    14   (0)| 00:00:01 |       |       |
|   1 |  PARTITION RANGE ALL               |                  |     1 |    17 |    14   (0)| 00:00:01 |     1 |     6 |
|   2 |   TABLE ACCESS BY LOCAL INDEX ROWID| T                |     1 |    17 |    14   (0)| 00:00:01 |     1 |     6 |
|*  3 |    INDEX RANGE SCAN                | T_LOC_NON_PREFIX |     1 |       |    13   (0)| 00:00:01 |     1 |     6 |
-----------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("Y"=1)


Statistics
----------------------------------------------------------
    0  recursive calls
    0  db block gets
   15  consistent gets
    0  physical reads
    0  redo size
  530  bytes sent via SQL*Net to client
  396  bytes received via SQL*Net from client
    2  SQL*Net roundtrips to/from client
    0  sorts (memory)
    0  sorts (disk)
    1  rows processed




Tom Kyte
August 04, 2010 - 11:55 am UTC

in both of your cases, you had the partition key in the where clause, partition elimination kicked in - you had to scan ONLY ONE partition (index or otherwise).


Come up with an example of a local non-prefixed index that doesn't include the partition key (does not enforce partition elimination)


As my book alludes, this performance "issue" is a big non-issue in real life. I don't see why the documentation calls them out - it is a big scare that isn't "real world"


You have two cases to consider when using local indexes when they are used:

a) partition elimination can happen
b) partition elimination won't happen


In the first case, for partition elimination to happen, you would have to be supplying the partition key in the where clause. Suppose you partition by X, but you locally (non-prefix) index column Y. The query:

where x = 5 and y = 7;

can OBVIOUSLY index partition eliminate - get to one index partition - because we know that all of "x=5" is contained in one and only one table partition and there is a 1:1 relation between the table and index partitions. So, we did not NEED to prefix that index in order to get partition elimination.


If you query:

where y=7;


then you CANNOT partition eliminate - you would range scan ALL local index partitions. Sounds bad right - no, not really, for consider what would happen if the index did not exist (full scan all partitions) or consider what would happen if the index was locally prefixed - that is, it was on (x,y). Two things would happen:

a) we still would not be able to partition eliminate - the data might be on zero, one, more than one or all partitions!

b) we probably wouldn't be able to use the index (because we'd like to have Y on the leading edge) and even if we did - it would be via a less efficient index skip scan.




Close your eyes, envision the data, think of the work that would have to be done in the various cases....

mark, August 04, 2010 - 12:03 pm UTC

Very good explanation. tx.

Partiitioning problem

Marcelo, August 05, 2010 - 7:42 am UTC

I have 4 tables T1,T2,T3,T4.

T1,T2,T3 are partitioned by column X3.

select * from t4

X3
--
0
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31

I'd like to reduce consistent gets for the second query. Is it possible ?

select *
from t1,t2,t3
where t1.x1 = t2.x1
and t1.x1 = t3.x1
and t2.x1 = t3.x1
and t1.x3 in (1,9,17,25)
and t2.x3 = t1.x3
and t3.x3 = t1.x3
and t3.x3 = t2.x3;


62500 filas seleccionadas.


Plan de Ejecución
----------------------------------------------------------
Plan hash value: 2175720709

-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 336 | 853 (6)| 00:00:11 | | |
| 1 | PARTITION RANGE INLIST| | 1 | 336 | 853 (6)| 00:00:11 |KEY(I) |KEY(I) |
|* 2 | HASH JOIN | | 1 | 336 | 853 (6)| 00:00:11 | | |
|* 3 | HASH JOIN | | 7769 | 1699K| 565 (5)| 00:00:07 | | |
|* 4 | TABLE ACCESS FULL | T3 | 62148 | 6797K| 275 (3)| 00:00:04 |KEY(I) |KEY(I) |
|* 5 | TABLE ACCESS FULL | T2 | 62675 | 6855K| 275 (3)| 00:00:04 |KEY(I) |KEY(I) |
|* 6 | TABLE ACCESS FULL | T1 | 62881 | 6877K| 275 (3)| 00:00:04 |KEY(I) |KEY(I) |
-----------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("T2"."X3"="T1"."X3" AND "T1"."X1"="T2"."X1" AND "T1"."X1"="T3"."X1" AND
"T3"."X3"="T1"."X3")
3 - access("T3"."X3"="T2"."X3" AND "T2"."X1"="T3"."X1")
4 - filter("T3"."X3"=1 OR "T3"."X3"=9 OR "T3"."X3"=17 OR "T3"."X3"=25)
5 - filter("T2"."X3"=1 OR "T2"."X3"=9 OR "T2"."X3"=17 OR "T2"."X3"=25)
6 - filter("T1"."X3"=1 OR "T1"."X3"=9 OR "T1"."X3"=17 OR "T1"."X3"=25)


Estadísticas
----------------------------------------------------------
0 recursive calls
0 db block gets
7685 consistent gets
0 physical reads
0 redo size
21215922 bytes sent via SQL*Net to client
46207 bytes received via SQL*Net from client
4168 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
62500 rows processed




select *
from t1,t2,t3
where t1.x1 = t2.x1
and t1.x1 = t3.x1
and t2.x1 = t3.x1
and t1.x3 in (select x3 from t4 where mod(x3,8) = 1)
and t2.x3 = t1.x3
and t3.x3 = t1.x3
and t3.x3 = t2.x3;


62500 filas seleccionadas.


Plan de Ejecución
----------------------------------------------------------
Plan hash value: 2223287253

------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time | Pstart| Pstop |
------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 338 | | 7420 (2)| 00:01:30 | | |
|* 1 | HASH JOIN | | 1 | 338 | 1168K| 7420 (2)| 00:01:30 | | |
|* 2 | HASH JOIN | | 5014 | 1106K| | 2254 (2)| 00:00:28 | | |
| 3 | NESTED LOOPS | | 5030 | 559K| | 72 (3)| 00:00:01 | | |
| 4 | SORT UNIQUE | | 1 | 2 | | 3 (0)| 00:00:01 | | |
|* 5 | TABLE ACCESS FULL | T4 | 1 | 2 | | 3 (0)| 00:00:01 | | |
| 6 | PARTITION RANGE ITERATOR| | 15720 | 1719K| | 68 (2)| 00:00:01 | KEY | KEY |
|* 7 | TABLE ACCESS FULL | T1 | 15720 | 1719K| | 68 (2)| 00:00:01 | KEY | KEY |
| 8 | PARTITION RANGE ALL | | 501K| 53M| | 2173 (2)| 00:00:27 | 1 | 32 |
| 9 | TABLE ACCESS FULL | T2 | 501K| 53M| | 2173 (2)| 00:00:27 | 1 | 32 |
| 10 | PARTITION RANGE ALL | | 497K| 53M| | 2173 (2)| 00:00:27 | 1 | 32 |
| 11 | TABLE ACCESS FULL | T3 | 497K| 53M| | 2173 (2)| 00:00:27 | 1 | 32 |
------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - access("T1"."X1"="T3"."X1" AND "T2"."X1"="T3"."X1" AND "T3"."X3"="T1"."X3" AND
"T3"."X3"="T2"."X3")
2 - access("T1"."X1"="T2"."X1" AND "T2"."X3"="T1"."X3")
5 - filter(MOD("X3",8)=1)
7 - filter("T1"."X3"="X3")


Estadísticas
----------------------------------------------------------
0 recursive calls
0 db block gets
24435 consistent gets
0 physical reads
0 redo size
21216138 bytes sent via SQL*Net to client
46207 bytes received via SQL*Net from client
4168 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
62500 rows processed




Partitioning vs Flashback

Parthiban Nagarajan, January 06, 2011 - 8:50 am UTC

Hi Tom
Consider a table T1 in a datawarehouse system, with partitions CMON and LMON.
CMON is to hold the current month data and LMON is to hold last month data.
We would not insert or update the LMON data. And it is also queried occasionally.
But CMON is frequently queried, also with some inserts and/or updates.
What I think is:
Why we need to hold the LMON partition?
Why we should not use Flashback to see the previous month data?
We may save some considerable amount of disk space.
(1) But what would be the penalty we would be paying to gain this advantage?
(2) Do you find any other disadvantage in this thought?
Please advise me on this.
Thanks in advance.
Tom Kyte
January 06, 2011 - 9:05 am UTC

... Why we should not use Flashback to see the previous month data?
..

because flashback query has a theoretical limit of 5 days in the past. I say theoretical because I don't know of many DBAs that would keep five days of undo around.

Also, the longer back in time you flashback query using undo - the longer it takes in general - as you have more and more undo to apply.


No, in 11g there is the flashback data archive as part of the total recall option. It is NOT undo based - it would let you query the data efficiently "as of last month"


However, if you just need "last month" and "current month" - the most space effective solution is precisely what you are doing. I wouldn't necessarily use CMON and LMON - I would use "PART_JAN_2010", "PART_FEB_2010" and so on - and every month add a new partition and drop the old partition.

Shiva Prasad, March 01, 2011 - 3:17 am UTC

Dear Tom,

We have a dealer inventory transaction table contains about around 5 TB of data and it has the following additional properties:

1.It has 11 sales company data
2.Only 5 years of data would remain in this table and past data will be archived to a archive table
3.We have decided to partition this transaction table using composite partition method using two key columns i.e START_DATE (Quarterly Range) and SALES_COMPANY_ID
4.Query Access Path: All the queries hitting this table will mandatory will have above said key columns in where clause to filter the data
5.Cardinality:
a. START_DATE : Quarterly Range – for 5 years cardinality would be 20
b. SALES_COMPANY_ID – 11 Distinct companies
c. The total cardinality is : 20 * 11 = 220 total partition chunks
However from performance improvement point of view and from data archival point of view, which composite partition would be an ideal candidate for our problem i.e. RANGE-LIST or LIST-RANGE partition mechanism? And why?

As team here breaking their heads in finalizing on this and it would be beneficial if you could shed some light on this.

Regards
Shiva

Tom Kyte
March 01, 2011 - 12:11 pm UTC

I would skip #2, if your predicates will include start_date and you partition by start_date, then the old stuff will be eliminated anyway. Why bother moving stuff around if you aren't going to hit it anyway.


range-list or list-range will effectively prune the same, so from a performance perspective - it is six one way half a dozen the other.

from an administrative perspective, range-list makes more sense, it would logically group things together by date which is how you would be archiving it (if you wanted to) and purging it (if you wanted to).


List Range vs Range List

Shiva Prasad, March 02, 2011 - 6:22 am UTC

Dear Tom,

Tons of thanks to you. for #2, as business itself requires only latest 5 years of data, so we did it accordingly.

However, Oracle 11g came up with a LIST-RANGE new partitioning method, as already we had this RANGE-LIST partitioning method prior to 11g, and I would like to know
1. what would be the ideal situation to use the LIST-RANGE partitioning and other input factors for the same

Regards
Shiva E


Tom Kyte
March 02, 2011 - 7:46 am UTC

list range might make sense if you had a multi-tenant situation.

For each company - they have their own companyid
And range partition within each company

and keep 5 years for company 1, 3 years for company 2, etc...


Just think of a time whereby you want to partition something by discrete values (companyid) and then further divide by date for examples...

List Range Partition

Shiva Prasad, March 03, 2011 - 7:22 am UTC

Tom,

Thanks very much for the great advicea and timely support.

Regards
Shiva E

List Range Partition

Shiva Prasad, March 03, 2011 - 7:23 am UTC

Tom,

Thanks very much for the great advice and timely support.

Regards
Shiva E

type of partition

A reader, March 03, 2011 - 1:09 pm UTC

Tom,


can you please suggest me on which partition should we prefer this.

I have table that has more than 30 mil rows and daily we load close 100,000 rows in this table . We cannot do partition on date column , because we don’t use the data column in the where condition.

Currently our DBA created the partition ( range ) partition by surrogate key. My questions what is best method and what is key we can go with partition table.

Thank you
Tom Kyte
March 03, 2011 - 1:16 pm UTC

... We cannot do partition on date column , because we don’t
use the data column in the where condition. ...

well, yes you can - but that is besides the point.


The only answer to this question is

IT DEPENDS

You don't tell us how you access this data
You don't tell us how you need to manage (purge for example) this data
You don't tell us why you are partitioning, what your goal is

In short, you don't tell us a lot more than what you tell us.


30,000,000 rows is a meaningless metric. That might be 30 mb or 300 tb - we have no idea.


What happens when we add OLS into the mix?

Bill S., May 05, 2011 - 9:34 am UTC

Just a quick follow-up. If I'm using OLS policies on a particular table, and the developers decide it makes sense for this table to be partitioned, will that affect the application of the OLS labels and policy? I didn't see anything I could directly attribute to partitioning in the OLS Admin guide for 10g (we are on 10gR2 on SuSe Linux).

If you know of a spot in the docs that speaks to that, just let me have that and I'll go read. :-D

Thanks!
Tom Kyte
May 06, 2011 - 10:08 am UTC

it would not affect Oracle Label Security - OLS as far as I know. It would affect your indexing strategy, but that is true even without OLS

partition

reader, May 26, 2011 - 10:25 am UTC

SQL> CREATE TABLE BALANCE(balance_id number,
       entry_date datetime,
                     settlement_date datetime,
                     other_columns)  
         PARTITION BY RANGE (entry_date)
         INTERVAL (NUMTOYMINTERVAL(1,'year')
         (PARTITION p_first VALUES LESS THAN ('30-DEC-2010');


I want to partition the table based on year as we ALWAYS query only current year's data as the table size is more than 25GB and is being used by most of the reports. However, 50% of the reports use entry_date and 50% uses settlement_date. There is a possibility that the settlement can come one month in advance with the previous month entry date.  

What is the best way to partition this table? 

If I create one global index on balance_id, and partition by either entry or settlement, would the performance be affected if the query filters by balance_id? 

Tom Kyte
May 26, 2011 - 11:55 am UTC

how much of the data do your queries return - that is vital to understand.

do you need to full scan a years worth of data, or do you get a few rows per query?

partition

A reader, May 26, 2011 - 1:04 pm UTC

40% of our queries are for a particular day, 40% month and 20% quarterly. one year old will be accessed very rarely, but cannot be removed from OLTP.

Thanks a lot for the response.
Tom Kyte
May 26, 2011 - 1:37 pm UTC

you told me nothing about the volume of data an individual query will hit. do your queries need to access thousands, millions, or what number of records?

when you say "40% of our queries are for a particular day", does that mean 40% of your queries access every row in a given day?

partition

A reader, May 26, 2011 - 2:20 pm UTC

Sorry about not being specific. The current record count for the table is six hundred ninety million approximately.. expected to grow by ~25% this year. Out of this ~98 million is one year data.
Tom Kyte
May 26, 2011 - 2:31 pm UTC

that still does not answer:

you told me nothing about the volume of data an individual query will hit. do your queries need to access thousands, millions, or what number of records?

when you say "40% of our queries are for a particular day", does that mean 40% of your queries access every row in a given day?

A reader, May 26, 2011 - 3:37 pm UTC

Most of the SQL's should hit about ~10 - ~20 million records.
Tom Kyte
May 26, 2011 - 6:26 pm UTC

indexing will not be relevant. You cannot get millions of rows via indexes. Say the index is entirely in cache - but the table in general is not.

10,000,000 IO's at 5ms/IO = ~13 1/2 hours

So, you'll be full scanning for them all. That index probably will never come into play and probably shouldn't exist. Unless you use it to get a FEW records.


A weeks worth of data looks to be around 1.8 - 2 million records.

However, 50% of the reports
use entry_date and 50% uses settlement_date.


that is going to be problematic. Can you make it such that the queries that use the date we DO NOT partition by - also use the other date. You said "settlement date could be a month before entry date" - if you query by settlement date - could you also add the predicate on entry date for that range so we can partition eliminate?

Range Partitioned Table

Reader, July 21, 2011 - 5:44 pm UTC


consultant from a local firm is insisting that we have to have a Local index created on a range partitioned table (partition key column is a date datatype). However, our developers suggest global index created on the partition key column (date datatype). which one is recommended and is there going to be any significant impact in performance one vs other? - by the way, sqls in the application are using date in the filter condition. Thanks.
Tom Kyte
July 22, 2011 - 2:08 pm UTC

this is impossible to answer given the information provided.

however.... if the partition key is on the leading edge of the index - I see no reason - I cannot think of any logical reason - why someone would want to create a global index????? it doesn't make sense?


Can the person wanting the global index provide any technical backing to their claim?


If I can have a local index - I prefer that for two reasons:

a) ease of administration - I can perform partition operations and affect JUST the local index partitions - I don't make global indexes go unusable

b) performance, a local index rowid is *marginally* faster than a global index rowid to dereference.



If the query has: 'where partition column <op> some_value...'

then both a local index would be able to partition eliminate as would a global.


I'd have to hear from them why they believe a global index is called for.

help on this

Venkata, August 10, 2011 - 6:14 am UTC

Hi Tom,

Sorry for the question on Analytics am working on that...am really sorry for that STUPID question it served no purpose to me either...

now i had a small discussion regarding partition.

I have a table of monthly sales with range partitions based on month. so is it better to scan all the partitions and scan 2 partitions at a time and will there be any performance impact when scanning all the partitions when fetching data from a table.

Tom Kyte
August 13, 2011 - 4:22 pm UTC

<i<>I have a table of monthly sales with range partitions based on month. so is it better to scan all the partitions and scan 2 partitions at a time and will there be any performance impact when scanning all the partitions when fetching data from a table.

better than what?

why scan 2 partitions at a time - what are the alternatives?

this is so vague as to be unanswerable.

Issue with partition exchange with blob columns

A reader, October 04, 2011 - 7:34 am UTC

Hi Tom,

Is there any restrictions on performing exchange partitions on tables with blob columns. I am trying to exchange partition but getting error "ORA-14098: index mismatch for tables in ALTER TABLE EXCHANGE PARTITION"

alter table T_TEST exchange partition TEST_P1 with table T_TEST_NEW including indexes without validation


I have compared the indexe types and column order etc every thing is same except the one for BLOB since its auto generated, it can't be same.

Tom Kyte
October 04, 2011 - 11:43 am UTC

add to this example - one thing at a time, making it look like your table, until it breaks. That'll probably lead you down the path of why yours is not working.

If you cannot figure it out, post the test case you have that built on this simple example so we can see what makes it 'break'

ops$tkyte%ORA11GR2> CREATE TABLE t
  2  (
  3    dt  date,
  4    x   int,
  5    y   blob
  6  )
  7  PARTITION BY RANGE (dt)
  8  (
  9    PARTITION part1 VALUES LESS THAN (to_date('13-mar-2003','dd-mon-yyyy')) ,
 10    PARTITION part2 VALUES LESS THAN (to_date('14-mar-2003','dd-mon-yyyy')) ,
 11    PARTITION junk VALUES LESS THAN (MAXVALUE)
 12  )
 13  /

Table created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> insert into t select to_date( '12-mar-2003', 'dd-mon-yyyy' )+mod(rownum,2), rownum, '0102030405' from all_users;

47 rows created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> create table t2 as select * from t partition(part2);

Table created.

ops$tkyte%ORA11GR2> update t2 set x = 42;

24 rows updated.

ops$tkyte%ORA11GR2> commit;

Commit complete.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> alter table t exchange partition part2 with table t2 including indexes without validation;

Table altered.

Analyzing a Partitioned Index

Rajeshwaran, Jeyabal, October 07, 2011 - 7:22 pm UTC

Tom:

We have table with 1700M records (avg_row_len=54) Hash Partitioned on PK(partitions=8).
We also have a Global Range partitioned index on create_dt column for 1 month Interval.

Table and Index was last_analyzed on 27-Aug-2011, We ran the report query for date range 01-SEP-2011 to 27-SEP-2011.
since the table was last_analyzed on 27-Aug-2011 so we have clustering_factor = 0,num_rows = 0, sample_size = 0 in user_ind_partitions for P_SEP2011 partition.
But, select count(*) from t partition(p_SEP2011) returned 28M records.

Due to this we came up with poor Explain plan for SEP_2011 period report query.

Now we regathered the stats on P_SEP2011 partition using dbms_stats.gather_index_stats & started the report query again.
But since the plan is available in shared pool It reused that poor plan.

1) We can flush the shared pool. which will Hard parse and produce new optimal plan, But we will be loosing all the Existing plan from shared pool.
2) We can added a dummy comments to the query like /*+ TEST */ which will Hard parse and come up with new plan.
But we dont want to do this since the report query is available inside Package in production. where we cannot make code changes.

Please let me know your thoughts on this.
Tom Kyte
October 08, 2011 - 6:53 am UTC

sys.dbms_shared_pool has a purge routine that can be sent a cursor identifier.


http://docs.oracle.com/docs/cd/E11882_01/appdev.112/e25788/d_shared_pool.htm#CHDCBEBB


but gathering statistics should cause the cursor to be purged after a short period of time regardless.

ORA-14313

Rajeshwaran Jeyabal, October 19, 2011 - 9:44 pm UTC

Tom:

test@TST02>  alter table rv_enc_dx split partition proj_default  values (100264000) into (partition p_100264000,partition proj_default
 alter table rv_enc_dx split partition proj_default  values (100264000) into (partition p_100264000,partition proj_default)
             *
ERROR at line 1:
ORA-14313: Value 100264000 does not exist in partition PROJ_DEFAULT


Elapsed: 00:00:00.04
test@TST02>


I was running this DDL on TEST database and ended up with this error ORA-14313. The Value 100264000 doesn't exists in PROJ_DEFAULT partition.

When i tried to reproduce this error, I am unable to get that.

rajesh@ORA10GR2> create table t(
  2  x number,
  3  y date)
  4  partition by list(x)
  5  (
  6   partition p_max values(default)
  7  );

Table created.

Elapsed: 00:00:00.07
rajesh@ORA10GR2> 
rajesh@ORA10GR2> alter table t split partition p_max
  2  values(5) into (partition p_5,partition p_max);

Table altered.

Elapsed: 00:00:00.11
rajesh@ORA10GR2> 
rajesh@ORA10GR2>


Questions
1) What does that error ORA-14313, Actually convey?

Tom Kyte
October 19, 2011 - 10:54 pm UTC

ops$tkyte%ORA11GR2> create table t(
  2  x number,
  3  y date)
  4  partition by list(x)
  5  (
  6   partition p1 values(1,2,3),
  7   partition p_max values (default)
  8  );

Table created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> alter table t split partition p_max
  2  values(5) into (partition p_5,partition p_max);

Table altered.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> alter table t split partition p_max
  2  values(3) into (partition p_3,partition p_max);
alter table t split partition p_max
            *
ERROR at line 1:
ORA-14313: Value 3 does not exist in partition P_MAX


ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> alter table t split partition p1
  2  values(4) into (partition p_4,partition p1);
alter table t split partition p1
            *
ERROR at line 1:
ORA-14313: Value 4 does not exist in partition P1





you would just want to ADD a partition if the value doesn't already exist. You cannot remove from some list partition - a value which *cannot possibly exist in there*.


In my example, the split works because we KNOW that if there is a row with 5 - it will be in p_max.

The second split does not work - because we know that 3 cannot be in p_max, it is in p1.

The third split does not work - for basically the same sort of reason.


So, in your example that didn't work, the value you tried to split out of that list partition is KNOWN to NOT BE in that partition - it is in some other partition (or is in NO partition)

You can only take away from a partition that which belongs in it.

Local Index on Reference Partition

Rajeshwaran Jeyabal, October 23, 2011 - 3:25 pm UTC

Tom:

Is that local indexes are not supported on Reference Patitioned tables? I am getting this error ORA-03113 when the child table has Local Index on it.

rajesh@ORA11GR2> select * from v$version;

BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - 64bit Production
PL/SQL Release 11.2.0.2.0 - Production
CORE    11.2.0.2.0      Production
TNS for Linux: Version 11.2.0.2.0 - Production
NLSRTL Version 11.2.0.2.0 - Production

Elapsed: 00:00:00.15
rajesh@ORA11GR2>
rajesh@ORA11GR2>
rajesh@ORA11GR2> create table parent_tab(
  2  x number,
  3  y varchar2(30),
  4  z date,
  5  constraint parent_tab_pk primary key(x))
  6  partition by range(z)
  7  (
  8     partition p_2007 values less than ( to_date('01-JAN-2008','dd-mon-yyyy')),
  9     partition p_2008 values less than ( to_date('01-JAN-2009','dd-mon-yyyy')),
 10     partition p_2009 values less than ( to_date('01-JAN-2010','dd-mon-yyyy')),
 11     partition p_2010 values less than ( to_date('01-JAN-2011','dd-mon-yyyy')),
 12     partition p_2011 values less than ( to_date('01-JAN-2012','dd-mon-yyyy'))
 13  );

Table created.

Elapsed: 00:00:00.09
rajesh@ORA11GR2>
rajesh@ORA11GR2> create table child_tab(
  2  col1 number not null,
  3  col2 varchar2(30),
  4  constraint child_tab_pk foreign key(col1) references parent_tab)
  5  partition by reference(child_tab_pk);

Table created.

Elapsed: 00:00:00.09
rajesh@ORA11GR2>
rajesh@ORA11GR2>
rajesh@ORA11GR2> set autotrace traceonly explain;
rajesh@ORA11GR2>
rajesh@ORA11GR2> select *
  2  from parent_tab p, child_tab c
  3  where p.x = c.col1
  4  and p.z between to_date('01-jul-2008','dd-mon-yyyy')
  5  and to_date('05-jul-2008','dd-mon-yyyy')
  6  /
Elapsed: 00:00:00.09

Execution Plan
----------------------------------------------------------
Plan hash value: 3982096211

-----------------------------------------------------------------------------------------------------
| Id  | Operation              | Name       | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |            |     1 |    69 |     2   (0)| 00:00:01 |       |       |
|   1 |  PARTITION RANGE SINGLE|            |     1 |    69 |     2   (0)| 00:00:01 |     2 |     2 |
|   2 |   NESTED LOOPS         |            |     1 |    69 |     2   (0)| 00:00:01 |       |       |
|*  3 |    TABLE ACCESS FULL   | PARENT_TAB |     1 |    39 |     2   (0)| 00:00:01 |     2 |     2 |
|*  4 |    TABLE ACCESS FULL   | CHILD_TAB  |     1 |    30 |     0   (0)| 00:00:01 |     2 |     2 |
-----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - filter("P"."Z">=TO_DATE(' 2008-07-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
              "P"."Z"<=TO_DATE(' 2008-07-05 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))
   4 - filter("P"."X"="C"."COL1")

Note
-----
   - dynamic sampling used for this statement (level=2)

rajesh@ORA11GR2>
rajesh@ORA11GR2>
rajesh@ORA11GR2> create index child_tab_idx on
  2  child_tab(col1) local;

Index created.

Elapsed: 00:00:00.09
rajesh@ORA11GR2>
rajesh@ORA11GR2> select *
  2  from parent_tab p, child_tab c
  3  where p.x = c.col1
  4  and p.z between to_date('01-jul-2008','dd-mon-yyyy')
  5  and to_date('05-jul-2008','dd-mon-yyyy')
  6  /
select *
*
ERROR at line 1:
ORA-03113: end-of-file on communication channel
Process ID: 6366
Session ID: 1991 Serial number: 26553


ERROR:
ORA-03114: not connected to ORACLE


Elapsed: 00:00:00.29
rajesh@ORA11GR2>
rajesh@ORA11GR2>
rajesh@ORA11GR2> connect rajesh/oracle@ORA11GR2
Connected.
rajesh@ORA11GR2>
rajesh@ORA11GR2> drop index child_tab_idx;

Index dropped.

Elapsed: 00:00:00.07
rajesh@ORA11GR2>
rajesh@ORA11GR2> set autotrace traceonly explain;
rajesh@ORA11GR2>
rajesh@ORA11GR2> set linesize 5000;
rajesh@ORA11GR2>
rajesh@ORA11GR2> select *
  2  from parent_tab p, child_tab c
  3  where p.x = c.col1
  4  and p.z between to_date('01-jul-2008','dd-mon-yyyy')
  5  and to_date('05-jul-2008','dd-mon-yyyy')
  6  /
Elapsed: 00:00:00.07

Execution Plan
----------------------------------------------------------
Plan hash value: 3982096211

-----------------------------------------------------------------------------------------------------
| Id  | Operation              | Name       | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |            |     1 |    69 |     2   (0)| 00:00:01 |       |       |
|   1 |  PARTITION RANGE SINGLE|            |     1 |    69 |     2   (0)| 00:00:01 |     2 |     2 |
|   2 |   NESTED LOOPS         |            |     1 |    69 |     2   (0)| 00:00:01 |       |       |
|*  3 |    TABLE ACCESS FULL   | PARENT_TAB |     1 |    39 |     2   (0)| 00:00:01 |     2 |     2 |
|*  4 |    TABLE ACCESS FULL   | CHILD_TAB  |     1 |    30 |     0   (0)| 00:00:01 |     2 |     2 |
-----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - filter("P"."Z">=TO_DATE(' 2008-07-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
              "P"."Z"<=TO_DATE(' 2008-07-05 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))
   4 - filter("P"."X"="C"."COL1")

Note
-----
   - dynamic sampling used for this statement (level=2)

rajesh@ORA11GR2>
rajesh@ORA11GR2>
rajesh@ORA11GR2> create index child_tab_idx on
  2  child_tab(col1) local;

Index created.

Elapsed: 00:00:00.09
rajesh@ORA11GR2>
rajesh@ORA11GR2> select *
  2  from parent_tab p, child_tab c
  3  where p.x = c.col1
  4  and p.z between to_date('01-jul-2008','dd-mon-yyyy')
  5  and to_date('05-jul-2008','dd-mon-yyyy')
  6  /
select *
*
ERROR at line 1:
ORA-03113: end-of-file on communication channel
Process ID: 12381
Session ID: 1991 Serial number: 26561


ERROR:
ORA-03114: not connected to ORACLE


Elapsed: 00:00:00.31
rajesh@ORA11GR2>

Tom Kyte
October 24, 2011 - 5:11 am UTC

ORA-03113 = contact support, plain an simple, something wrong happened there.


when you do, just supply them this:


drop table child_tab purge;
drop table parent_tab purge;

create table parent_tab(
x number,
y varchar2(30),
z date,
constraint parent_tab_pk primary key(x))
partition by range(z)
(
partition p_2007 values less than ( to_date('01-JAN-2008','dd-mon-yyyy')),
partition p_2008 values less than ( to_date('01-JAN-2009','dd-mon-yyyy')),
partition p_2009 values less than ( to_date('01-JAN-2010','dd-mon-yyyy')),
partition p_2010 values less than ( to_date('01-JAN-2011','dd-mon-yyyy')),
partition p_2011 values less than ( to_date('01-JAN-2012','dd-mon-yyyy'))
);

create table child_tab(
col1 number not null,
col2 varchar2(30),
constraint child_tab_pk foreign key(col1) references parent_tab)
partition by reference(child_tab_pk);

create index child_tab_idx on
child_tab(col1) local;

select *
from parent_tab p, child_tab c
where p.x = c.col1
and p.z between to_date('01-jul-2008','dd-mon-yyyy')
and to_date('05-jul-2008','dd-mon-yyyy')
/


the autotrace stuff is just noise. When preparing a test case - remove ANYTHING that is not relevant to the issue.


I believe this is related to bug 10188727 fixed in 11.2.0.3 and above - there are patches possibly available as well.


Index Edge

Tony Fernandez, October 24, 2011 - 12:39 pm UTC

Tom,

I still see many local indexes using, the column used for partitioning a table, as first column in a compound index.

Can you please give us your thoughts about:

1) Traditional case. First Column in local index is same as column table was partitioned on.

create table t1 ( col1 number, col2 varchar2(30), col3 varchar(40) )
partition by list ( col1 )
(
PARTITION PERIOD_1 VALUES (1),
PARTITION PERIOD_2 VALUES (2),
PARTITION PERIOD_3 VALUES (3)
);

create index i1 on t1(col1,col2,col3);


2) Alternative. Continue directly with other than partitioning column, as keys on the index.

create index i1 on t1(col2,col3); -- col1 is not included

Statistics on the query improve for option #2.

Regards,

Tom Kyte
October 24, 2011 - 12:57 pm UTC

1) in this case, since each partition only has one value, it doesn't make sense to have the partition key in the index.

If the partitions had many (or even just two) values for col1, it would make sense - but with just one value - it really isn't justified.

2) see #1

Index Edge

Tony Fernandez, October 24, 2011 - 3:27 pm UTC

Yes, all values same for the partition.

Thanks ;-)

partitioning a legacy system

A reader, November 11, 2011 - 2:54 pm UTC

We have a system that has been running for several years without partitioning.

Now the client wants to look at only holding X years worth of data, purging annually - so partitioning would make sense.

However, the tables we have contains around 800 million rows - just wonder what's the most efficient way to convert from non-partitioned to partition is for such large sized tables?

We're also concerned about performance if we do convert - the system has been running fine without partitioning - it is only this new requirement that has prompted us to explore partitioning. We're largely an OLTP based system and we worry that partitioning could cause DML and queries to be slower.

I guess if we don't go down the partition path, then we would be looking to purge the data on a daily basis instead of annually so we can issue less resource hungry "deletes", but then we could end up with High Water Mark issues for some non-OLTP type reports.

Can we have our cake and eat it ?!
Tom Kyte
November 11, 2011 - 3:13 pm UTC

However, the tables we have contains around 800 million rows - just wonder
what's the most efficient way to convert from non-partitioned to partition is
for such large sized tables?


it depends. can you take an extended outage? if so, create table as selects, re-indexing, granting, etc - dropping old - that would be feasible.

if not, dbms_redefinition - will take longer for the DBA - but the end user won't know (system might be slower, but will be available).


We're also concerned about performance if we do convert - the system has been
running fine without partitioning - it is only this new requirement that has
prompted us to explore partitioning. We're largely an OLTP based system and we
worry that partitioning could cause DML and queries to be slower.


excellent - very happy to hear that you understand that partitioning is not fast = true.

you will have to make use of some global indexes, you will have to test. This is important. But realize now - you will have global indexes - it is sort of mandatory. You will get push back from some people - but your queries will be massively impacted if you do not.

What the global indexes mean is that the "drop" or "truncate" of an old partition will take the DBA (but not the end user) longer - because you'll have to maintain those indexes - and the DBA might have to (*MIGHT*) shrink/coalesce those indexes after the drop/truncate making it take longer even still (to the DBA, but not the end user) - but I'm not really concerned about that bit (that is takes longer for the DBA).

why are global indexes mandatory

Sokrates, November 11, 2011 - 5:01 pm UTC

But realize now - you will have global indexes - it is sort of mandatory
why do you say that ?
probably local indexes suffice for her/him ?
how can you deduce from her/his input that global indexes are mandatory here ?
Tom Kyte
November 15, 2011 - 7:27 am UTC

Because of this statement:

We're
largely an OLTP based system and we worry that partitioning could cause DML and queries to be
slower.



In OLTP is would be exceedingly rare to find a system that is partitioned without a global index.

Say you range partition data by date (sort of assumed, this is in support of partitioning).

So, now, let's say it is monthly partitions - for five years. So, sixty partitions.

Now, please get me the customer history for customer id X. Do you want to

a) do sixty index range scans
b) do one index range scan

Get me the orders for customer with company name Y. Do you want to

a) do sixty index range scans
b) do one index range scan

And so on.

It is pretty much inevitable that there will be global indexes so as to not affect the performance of DML (which includes select's - both in the where clause of updates and deletes as well as select statements themselves)



I'm trying to set the mindset you will need to be good here - far too many people are in the "cannot have a global index at any cost - I've heard they are 'bad'"

Partitioning based on Hierarchy

Ananth, January 10, 2012 - 1:48 pm UTC

Hi Tom,

I would like to know if there is any way to partition the table based on the Hierarchy (each hierarchy).

For Ex: we have a enterprise wide content management system and typical table has columns
Nodeid,
nodename,
nodetype (folder, document, discussion etc..)
nodeparentid (foreign key to nodeid from same table)
nodecreatedate


Is there any possibility where we can parition the table by Nodeid. Paritioning criteria all nodes under LOB come under same partition.

Currently the table size has 30million rows.

we have Root folder and have LOB folders under it, and under it we have different folders, documents, files etc..

Tom Kyte
January 10, 2012 - 10:30 pm UTC

Is there any possibility where we can parition the table by Nodeid.


sure, but how do we know what LOB (I assume line of business?) it goes with?

Partitioning based on Hierarchy

Ananth, January 11, 2012 - 1:36 pm UTC

LOB - Lines of Business.

For Ex:
Under Root Folder we have the folders which represents each business like HR, Finance, IT, Sales, Legal etc.

I would like to partition the table based on LOB. (HR , its sub-folders, files under one partition, Finance and its sub-folders in another partition etc..).

Regards
Ananth


Tom Kyte
January 11, 2012 - 3:34 pm UTC

since this will be 'static', meaning partitioning cannot be table driven, the update of a row in table 1 cannot, will not cause rows in table 2 to "move" partitions, you can use list partitioning to put HR and its sub-folders into partition 1 and Finance into another.


The line of business would have to be an attribute of the rows in the table.

Table Partition

A reader, January 28, 2012 - 12:52 am UTC

Hi Tom,

I have two requirements.

Requirement 1:
--------------

I have a table TABLE_A which has 60 columns. The table has the primary key as CustomerNumber. The user can search over
CustomerNumber, DateRange - StartDate and EndDate. We have only one tablespace.

Tha requirement is we can delete the records after 7 years from the table TABLE_A. The table will be inserted with 1 million rows every month.

I was assuming to create an composite partition over the table.
CREATE TABLE TABLE_A (CustomerNumber varchar2(100), StartDate Date, EndDate Date...., createdDate Date)
PARTITION BY RANGE(createdDate)
SUBPARTITION BY HASH(CustomerNumber)
SUBPARTITIONS 8
(
Data_pre05
VALUES LESS THAN (TO_DATE('01/01/2005','DD/MM/YYYY')),
PARTITION Data_2005
VALUES LESS THAN(TO_DATE('01/01/2006','DD/MM/YYYY')),
PARTITION Data_2006
VALUES LESS THAN(TO_DATE('01/01/2007','DD/MM/YYYY')),
PARTITION Data_2007
VALUES LESS THAN(TO_DATE('01/01/2008','DD/MM/YYYY')),
PARTITION Data_2008
VALUES LESS THAN(TO_DATE('01/01/2009','DD/MM/YYYY')),
PARTITION Data_2009
VALUES LESS THAN(TO_DATE('01/01/2010','DD/MM/YYYY')),
PARTITION Data_2010
VALUES LESS THAN(TO_DATE('01/01/2011','DD/MM/YYYY')),
PARTITION Data_2011
VALUES LESS THAN(TO_DATE('01/01/2012','DD/MM/YYYY')),
PARTITION Data_future
VALUES LESS THAN(MAXVALUE));
);


Now as per my understanding: I can create a range hash partition which may help me in purging the data through partitions.

And since I am using hash partition over CustomerNumber, so this also helps in using the partition more efficiently.

For the dateRange search, I can create a non-unique index over StartDate and EndDate if required.


Requirement 2:
----------------
The second table has more or less same structure as the earlier table. It is used as an intermediate table to the above
table. Only difference is that it should be purged/deleted after every one day. If I am in Thursday, 29-JAN-2010, so it should truncate/delete the records of Tuesday 27-JAN-2010.
I am not sure how can we make a table for that. It will be highly appreciated if you help me in deciding the partition
clause.

Do we need partition for that or simple delete can handle it? In case of delete, do we have the issue of HWM reset?

CREATE TABLE TABLE_B (CustomerNumber varchar2(100), StartDate Date, EndDate Date...., createdDate Date);


Please suggest.


Tom Kyte
January 31, 2012 - 5:09 pm UTC

1) you could do that, but it would only be "necessary" if you were planning on using a full scan to retrieve the data.

If you are going to use an index - you would end up doing 7 index range scans - regardless.

If you are going to full scan - then this would cause you to full scan 1/8th as much data - it would be useful.


so - index access, doesn't do much for you. full scan - it would help you (but I'd suggest going for many more subpartitions in that case probably)


and if you use an index on anything, it should be on either

customerNumber, startDate, endDate

or
customerNumber, endDate, startDate


so that a predicate like "where customerNumber = :x and startDate <= :y and endDate >= :y could use it effectively.



2) why partition it at all? Just truncate it.

why would you delete from it and generate gobs of under and redo?

Follow up

A reader, February 08, 2012 - 3:39 pm UTC

Hi Tom,

regarding the partitioning question above, if I understood your comment correctly:

so - index access, doesn't do much for you. full scan - it would help you (but I'd suggest going for many more subpartitions in that case probably)


Now I updated my table script as:

CREATE TABLE TABLE_A (CustomerNumber varchar2(100), StartDate Date, EndDate Date, createdDate 
Date)
PARTITION BY RANGE(createdDate) 
SUBPARTITION BY HASH(CustomerNumber)
SUBPARTITIONS 8
(
PARTITION Data_pre05 VALUES LESS THAN (TO_DATE('01/01/2005','DD/MM/YYYY')),
PARTITION PART_2005_Q1 VALUES LESS THAN (TO_DATE('01-APR-2005', 'DD-MON-YYYY')),
PARTITION PART_2005_Q2 VALUES LESS THAN (TO_DATE('01-JUL-2005', 'DD-MON-YYYY')),
PARTITION PART_2005_Q3 VALUES LESS THAN (TO_DATE('01-OCT-2005', 'DD-MON-YYYY')),
PARTITION PART_2005_Q4 VALUES LESS THAN (TO_DATE('01-JAN-2006', 'DD-MON-YYYY')),
PARTITION PART_2006_Q1 VALUES LESS THAN (TO_DATE('01-APR-2006', 'DD-MON-YYYY')),
PARTITION PART_2006_Q2 VALUES LESS THAN (TO_DATE('01-JUL-2006', 'DD-MON-YYYY')),
PARTITION PART_2006_Q3 VALUES LESS THAN (TO_DATE('01-OCT-2006', 'DD-MON-YYYY')),
PARTITION PART_2006_Q4 VALUES LESS THAN (TO_DATE('01-JAN-2007', 'DD-MON-YYYY')),
.....
PARTITION PART_2012_Q1 VALUES LESS THAN (TO_DATE('01-APR-2012', 'DD-MON-YYYY')),
PARTITION PART_2012_Q2 VALUES LESS THAN (TO_DATE('01-JUL-2012', 'DD-MON-YYYY')),
PARTITION PART_2012_Q3 VALUES LESS THAN (TO_DATE('01-OCT-2012', 'DD-MON-YYYY')),
PARTITION PART_2012_Q4 VALUES LESS THAN (TO_DATE('01-JAN-2013', 'DD-MON-YYYY')),
.....
PARTITION PART_2020_Q1 VALUES LESS THAN (TO_DATE('01-APR-2020', 'DD-MON-YYYY')),
PARTITION PART_2020_Q2 VALUES LESS THAN (TO_DATE('01-JUL-2020', 'DD-MON-YYYY')),
PARTITION PART_2020_Q3 VALUES LESS THAN (TO_DATE('01-OCT-2020', 'DD-MON-YYYY')),
PARTITION PART_2020_Q4 VALUES LESS THAN (TO_DATE('01-JAN-2021', 'DD-MON-YYYY')),
PARTITION Data_future
VALUES LESS THAN(MAXVALUE)
)
ENABLE ROW MOVEMENT;



I need some clarifications:

1. Since I am creating partitions for 10 years (2011-2020) with subpartition of quarters.

Which means we have number of partitions = 10*4=40

Now these are further subpartitioned on HASH(customerNumber) so we have total number of sub-partitions = 40*8=320

Is this acceptable?

2. What could be disadvantage of this approach?

In case you have any better suggestions, please do let know.

Thanks for your time.


Tom Kyte
February 08, 2012 - 9:01 pm UTC

1) sure, 320 is small

2) disadvantage of what approach?

if you truncate - data disappears, no redo no undo generated.

if you delete - data will eventually disappear after a long time and lots of redo/undo

Check your requirements

Mike, February 09, 2012 - 12:42 pm UTC

Your requirement of 'you can delete a customer after 7 years' may be worth clarifying. It looks like you plan to purge a customer 7 years after creation, but you have START_DATE and END_DATE. Are you sure your requirement isn't more like 'you can delete a customer row 7 years after its end date'?

This would be harder to address with partition drops. I suspect the 'end date' does not stay fixed over the life of the row (perhaps it is null on a new customer) so if you partitioned on that you would have lots of rows moving between partitions as that happens.

Also...Your primary key is Customer Number; to enforce uniqueness that you would need a global index since your primary partitioning does not involve Customer Number. This would experience significant churn whenever you drop a partition.

Partition Joins in Explain plan

Rajeshwaran, Jeyabal, March 07, 2012 - 12:27 am UTC

Tom:

Can you please help me that my understanding about this explain plain is correct?

1) id=3 reads all the 4 partitions from table T2
2) id=4 reads all the 4 partitions from table T1
3) id=2 performs the Hash join & this Hash join such that
a) Partition p1 from Table T1 is joined with only partiton p1 in table T2. simillarly for p2, p3 and p_max
b) there is no way that partition p1 from table t1 is joined with partition p2 in table t2 (since the step PARTITION LIST ALL appears above the Hash join in this plan)

rajesh@ORA10GR2> select t1.*,t2.*
  2  from t1, t2
  3  where t1.object_id = t2.object_id
  4  /
Elapsed: 00:00:00.03

Execution Plan
----------------------------------------------------------
Plan hash value: 3942422932

--------------------------------------------------------------------------------------------
| Id  | Operation           | Name | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT    |      |   166 | 28220 |   189   (3)| 00:00:03 |       |       |
|   1 |  PARTITION LIST ALL |      |   166 | 28220 |   189   (3)| 00:00:03 |     1 |     4 |
|*  2 |   HASH JOIN         |      |   166 | 28220 |   189   (3)| 00:00:03 |       |       |
|   3 |    TABLE ACCESS FULL| T2   |   166 | 12616 |     3   (0)| 00:00:01 |     1 |     4 |
|   4 |    TABLE ACCESS FULL| T1   | 57219 |  5252K|   183   (2)| 00:00:03 |     1 |     4 |
--------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("T1"."OBJECT_ID"="T2"."OBJECT_ID")

rajesh@ORA10GR2>

The script used to create table T1 and T2 are below (both tables are equi-partitioned)
create table t1
partition by list(object_id)
(
 partition p1 values (10000),
 partition p2 values (20000),
 partition p3 values (30000),
 partition pmax values (default)
)
as
select * from all_objects;

create table t2
partition by list(object_id)
(
 partition p1 values (10000),
 partition p2 values (20000),
 partition p3 values (30000),
 partition pmax values (default)
)
as
select * from user_objects;

begin
 dbms_stats.gather_table_stats(
 ownname=>user,
 tabname=>'T1',
 estimate_percent=>dbms_stats.auto_sample_size,
 cascade=>true);
 
 dbms_stats.gather_table_stats(
 ownname=>user,
 tabname=>'T2',
 estimate_percent=>dbms_stats.auto_sample_size,
 cascade=>true); 
end;
/

Tom Kyte
March 08, 2012 - 5:39 am UTC

well, technically it is more like:

read all of t2 and hash it into a hash table (hopefully in memory)
as you are reading all of t1, probe the hash table and output the row after the join

You can see this by making your example use all_objects twice (instead of user objects)

then:

onnect /
set pagesize 60
set pause on
alter session set sql_trace=true;

select /*+ use_hash(t1,t2) */ t1.*,t2.*
from t1, t2
where t1.object_id = t2.object_id
/




Hit enter twice - once to start the query, once to display the first rows. In the tkprof - you'll see something like:

rows       Row Source Operation
---------  ---------------------------------------------------
       16  PARTITION LIST ALL PARTITION: 1 4 (cr=1046 pr=0 pw=0 time=903 us cost=1373 size=14155120 card=72220)
       16   HASH JOIN  (cr=1046 pr=0 pw=0 time=81947 us cost=1373 size=14155120 card=72220)
    72225    TABLE ACCESS FULL T2 PARTITION: 1 4 (cr=1037 pr=0 pw=0 time=55360 us cost=307 size=7078050 card=72225)
       16    TABLE ACCESS FULL T1 PARTITION: 1 4 (cr=9 pr=0 pw=0 time=190 us cost=307 size=7077560 card=72220)



Now, my all objects has 72,220 rows - the entire table was read, hashed and then we started reading t1 and started returning rows.

A reader, March 07, 2012 - 8:54 pm UTC

read all of t1 and hash it into a hash table (hopefully in memory)
as you are reading all of t2, probe the hash table and output the row after the join


But in hash join smaller table will be hashed which in this case will be t2 which as per plan has lesser rows than t1


Tom Kyte
March 08, 2012 - 5:38 am UTC

you are correct, that was a typo on my part, I've updated that - thanks!

partition elimination

A reader, April 16, 2012 - 7:09 pm UTC

Hi Tom,
Can you help me with your expert advice conceptually (on 10gr2):
If we have (10 years of data; around 2.5 million rows per month) sales fact table & few dim tables - month_dim, branch_dim etc. mth_dim table has flags current month, previous month, current quarter, current half year, current year etc. User wants to get the result set based upon these flags, with ad hoc queries coming from BI tool (with an example of current month year data) as below:
SELECT sf.mth_year, sf.branch_code...., SUM(sf.sales)
FROM sales_fact sf, mth_dim md, branch_dim bd
WHERE sf.mth_year= md.mth_year
AND sf.branch_code = branch_dim.branch_code
AND md.mth_year = 'Y'
...
GROUP BY ...
as data needs to be fetched from one partition, will this eliminate partition? if not, how should we design (for such type of ad hoc queries - current month, previous month, this quarter etc.) so that we can use partition pruning feature of oracle for such ad hoc queries?

Regards,



Tom Kyte
April 17, 2012 - 1:29 am UTC

... as data needs to be fetched from one partition, ...

ok, that would be the *first* mention of partitioning. what is partitioned?

if SF is partitioned by month (assumption), your above query would have to hit pretty much every partition. There is no metadata, no rule, nothing in the data dictionary that would tell the optimizer "md.mth_year = y after joining by sf.mth_year=md.mth_year would read only every 12th partition" or anything like that.

In looking at this query - I don't know how you can say "one partition", but then again, I know nothing at all about your schema.

Partition Elimination

A reader, April 17, 2012 - 11:27 pm UTC

Hi Tom,
My apologies. The sample data & query is like this...

SF:

mth_year branch_code sale_qty ...

201204 01 1000
201203 01 500
......

md:
Note: Current month is Apr 2012, Current Half Year: first six months of current calendar year; Previous Half Year: last six months of current calendar year, current calendar year is 2012, so in April 2012, the data in md table is below:

mth_year curr_mth prv_mth curr_halfyear curr_year prv_year...
201204 Y N Y Y N
201203 N Y Y Y N
...
201112 N N N N Y

bd:
branch_code branch_name......
01 My Branch
....

SELECT sf.mth_year, sf.branch_code, bd.branch_name..., SUM(sf.sale_qty)
FROM sales_fact sf, mth_dim md, branch_dim bd
WHERE sf.mth_year= md.mth_year
AND sf.branch_code = bd.branch_code
AND md.curr_mth = 'Y'
...



Tom Kyte
April 18, 2012 - 3:05 am UTC

I laughed out loud when I realized you hadn't supplied anything asked for...


...In looking at this query - I don't know how you can say "one partition", but then again, I know nothing at all about your schema. ....



no clue what your table is actually partitioned by.

no idea how you can say "only one partition" would be hit. sure looks like more than one would be to me, but then again, I know nothing about your partitioning scheme


use the code button when you post stuff so that your code is looking like code so we can actually read it too please.


If curr_mth is Y for ONLY ONE record in MD, you probably want to code:


SELECT sf.mth_year, sf.branch_code, bd.branch_name..., SUM(sf.sale_qty)
FROM sales_fact sf, branch_dim bd
WHERE sf.mth_year= (select md.mth_year from md where md.curr_mth='Y')
AND sf.branch_code = bd.branch_code ;

and if your partitioning key is mth_year, then partition elimination should kick else.

Else, I doubt it would since your partition key doesn't appear in the predicate. It would have be really useful to know the partitioning key don't you think? :(



Oops!

A reader, April 18, 2012 - 8:55 am UTC

Hi Tom,
Thanks - there is range partition on sf.mth_year:-)

Since the query is generated from front end BI tool, so users don't have control in writing the query the way you mentioned, until and unless Oracle can re-write some way!

Regards,

Tom Kyte
April 19, 2012 - 4:32 am UTC

well, here is a simple test that shows partition elimination can happen - if it couldn't, the query would get an IO error due to the offline tablespaces:

ops$tkyte%ORA11GR2> CREATE TABLE sf
  2  (
  3    mth_year    date,
  4    branch_code number,
  5    sale_qty    number
  6  )
  7  PARTITION BY RANGE (mth_year)
  8  (
  9    PARTITION jan2012 VALUES LESS THAN (to_date('01-feb-2012','dd-mon-yyyy')) tablespace example,
 10    PARTITION feb2012 VALUES LESS THAN (to_date('01-mar-2012','dd-mon-yyyy')) tablespace example,
 11    PARTITION mar2012 VALUES LESS THAN (to_date('01-apr-2012','dd-mon-yyyy')) tablespace example,
 12    PARTITION apr2012 VALUES LESS THAN (to_date('01-may-2012','dd-mon-yyyy')) tablespace users
 13  )
 14  /

Table created.

ops$tkyte%ORA11GR2> insert into sf
  2  select add_months( to_date( '01-jan-2012', 'dd-mon-yyyy' ), mod(rownum,4)), mod(rownum,10)+1, object_id
  3    from all_objects
  4  /

72933 rows created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> create table md
  2  ( mth_year     date,
  3    curr_mth     varchar2(1),
  4    other_stuff  varchar2(20)
  5  )
  6  /

Table created.

ops$tkyte%ORA11GR2> insert into md values ( to_date( '01-jan-2012', 'dd-mon-yyyy' ), 'N', 'xxxx' );

1 row created.

ops$tkyte%ORA11GR2> insert into md values ( to_date( '01-feb-2012', 'dd-mon-yyyy' ), 'N', 'xxxx' );

1 row created.

ops$tkyte%ORA11GR2> insert into md values ( to_date( '01-mar-2012', 'dd-mon-yyyy' ), 'N', 'xxxx' );

1 row created.

ops$tkyte%ORA11GR2> insert into md values ( to_date( '01-apr-2012', 'dd-mon-yyyy' ), 'Y', 'xxxx' );

1 row created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> create table bd
  2  ( branch_code number,
  3    branch_name varchar2(30)
  4  )
  5  /

Table created.

ops$tkyte%ORA11GR2> insert into bd select level, 'br-'||level from dual connect by level <= 10;

10 rows created.

ops$tkyte%ORA11GR2> commit;

Commit complete.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> set linesize 1000
ops$tkyte%ORA11GR2> alter tablespace example offline;

Tablespace altered.

ops$tkyte%ORA11GR2> set autotrace on explain
ops$tkyte%ORA11GR2> SELECT sf.mth_year, sf.branch_code, bd.branch_name, SUM(sf.sale_qty)
  2  FROM sf, md, bd
  3  WHERE sf.mth_year= md.mth_year
  4  AND sf.branch_code = bd.branch_code
  5  AND md.curr_mth = 'Y'
  6  group by sf.mth_year, sf.branch_code, bd.branch_name
  7  /

MTH_YEAR  BRANCH_CODE BRANCH_NAME                    SUM(SF.SALE_QTY)
--------- ----------- ------------------------------ ----------------
01-APR-12           2 br-2                                  149318862
01-APR-12           6 br-6                                  149418401
01-APR-12           4 br-4                                  149461029
01-APR-12          10 br-10                                 149574234
01-APR-12           8 br-8                                  149472287


Execution Plan
----------------------------------------------------------
Plan hash value: 4069567637

----------------------------------------------------------------------------------------------------
| Id  | Operation                   | Name | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |      |    82 |  6232 |     8  (13)| 00:00:01 |       |       |
|   1 |  HASH GROUP BY              |      |    82 |  6232 |     8  (13)| 00:00:01 |       |       |
|*  2 |   HASH JOIN                 |      |    82 |  6232 |     7   (0)| 00:00:01 |       |       |
|   3 |    NESTED LOOPS             |      |    82 |  3772 |     4   (0)| 00:00:01 |       |       |
|*  4 |     TABLE ACCESS FULL       | MD   |     1 |    11 |     3   (0)| 00:00:01 |       |       |
|   5 |     PARTITION RANGE ITERATOR|      |    82 |  2870 |     1   (0)| 00:00:01 |   KEY |   KEY |
|*  6 |      TABLE ACCESS FULL      | SF   |    82 |  2870 |     1   (0)| 00:00:01 |   KEY |   KEY |
|   7 |    TABLE ACCESS FULL        | BD   |    10 |   300 |     3   (0)| 00:00:01 |       |       |
----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("SF"."BRANCH_CODE"="BD"."BRANCH_CODE")
   4 - filter("MD"."CURR_MTH"='Y')
   6 - filter("SF"."MTH_YEAR"="MD"."MTH_YEAR")

Note
-----
   - dynamic sampling used for this statement (level=2)

ops$tkyte%ORA11GR2> set autotrace off
ops$tkyte%ORA11GR2> alter tablespace example online;

Tablespace altered.

Reader, April 25, 2012 - 6:57 am UTC

Hi Tom,
I'm basically stuck into a small partitioning logic. I have a table with a date column. If that column is NULL, it means that record is active. If NOT NULL, then inactive. The table is partitioned on that date column. Can I sub-partition each partition further into active and inactive on basis of that date column being NULL/NOT NULL. I'm sure there isn't any way but still would like to get a confirmation from you.
Thanks in advance.
Tom Kyte
April 25, 2012 - 10:12 am UTC

well, only one partition would have nulls in them. In fact, you could just have a partition with active records in it if you wanted.

You must already have row movement enabled since you probably update this attribute to make a record inactive - so the rows would move into the right partition by themselves - and you'd have a single partition with all of the nulls

I cannot foresee any benefit of subpartitioning here.

partitioning

Maggie, April 27, 2012 - 2:57 pm UTC

I want to write a script to drop partitions that are older than 35 days and the partitions are system generated. How do I do that? please help!

thanks in advance.
Tom Kyte
April 28, 2012 - 8:22 am UTC

select * 
  from user_objects 
 where created < sysdate-35 
   and object_type = 'TABLE PARTITION' 
   and object_name = 'Your Table Name';

Function-based index vs. Partition by List

Davis M., May 02, 2012 - 5:00 am UTC

Hi Tom,
I've a table with following structure:

a1 VARCHAR2(15 BYTE),
a2 VARCHAR2(100 BYTE),
a3 DATE,
a4 VARCHAR2(2 BYTE),
a5 VARCHAR2(10 BYTE),
a6 DATE,
a7 TIMESTAMP(3)

The table contains a little over 3 million lines and grows by ABOUT 120.000 LINES PER MONTH.
There is a procedure who needs to create a cursor selecting only rows where a4 is NULL.

a4 can assume only values s, N, Y, M, E and NULL with this actual distribution:

NULL 236
s 770
Y 3031502
M 2
N 3257
E 1

query for selecting only rows where a4 is NULL takes some seconds.
Number ow rows where a4 is NULL remains more or less constant.

We're evaluating 2 ways:

1) create an function-based index with NVL on a4 and using a where condition like NVL(FL_IMPORTED,'NU') = 'NU'

2) partitioning the table by List with a partition for 'Y' value, a partition for NULL and a partition containing all other values (E, M, N, s)
and creating a cursor with the query SELECT * FROM table PARTITION(part_null)

What could be the better solution?

Tom Kyte
May 02, 2012 - 1:42 pm UTC

I'd be inclined to create this index:
create index t_idx on t( decode( a4,null,1) );


and then query
where decode(a4,null,1) = 1;


that would be a teeny tiny index - it would have only 236 entries in it because the remaining rows would all contribute an entirely null key and we don't index entirely null keys in a b*tree index.


If you cannot modify the where clause, you could instead;

create index t_idx on (a4,0);


that would cause us to include the null values in the index (but it would index every single row in the table). You'd almost certainly want a histogram on that column as well for that.


http://asktom.oracle.com/Misc/something-about-nothing.html



I'd want to save partitioning for purging of data - if you are growing at a rate of 120k rows per month, you are adding about 1.5 million rows over the course of a year. Eventually I assume you'll archive some of that?

Function-based index vs. Partition by List: RE

Davis M., May 16, 2012 - 5:55 am UTC

Thank you Tom for your exhaustive reply.
But what's the difference (if there is one)of using the index with decode function instead of nvl function?
Even creating the index as NVL(a4,1) it would contains only 236 entries?

Tom Kyte
May 16, 2012 - 6:01 am UTC

creating the index on nvl(a4,1) would index EVERY ROW IN THE TABLE, not just 236 of them - all of them

an index on decode(a4,null,1) would only index the null columns.

Function-based index vs. Partition by List: RE

Davis M., May 16, 2012 - 7:04 am UTC

Ok, now it's clear. Thanks!

So, if I have to modify the query the create cursor for adding a further condition on a5, like:

select *
from t
where a4 is null and a5 = 'AAAA'

(a5 does not contains NULL value)

I have to add a5 to my index.

Is, in this case, the NVL-based index better than DECODE-based index?

I make the test creating the two index:

CREATE INDEX idx ON t
(DECODE("a4",NULL,1), a5)


CREATE INDEX idx ON t
(NVL("a4",'NU'), a5)

and with NVL index I got significantly better perfomance.

(Sorry if it's an obvious question)

Tom Kyte
May 17, 2012 - 2:19 am UTC

for that one, if you have an index on (a4,a5) - everything will work "as is"

you wouldn't need to change any sql or anything.

ops$tkyte%ORA11GR2> create table t (
  2  a1  VARCHAR2(15 BYTE),
  3  a2  VARCHAR2(100 BYTE),
  4  a3  DATE,
  5  a4  VARCHAR2(2 BYTE),
  6  a5  VARCHAR2(10 BYTE),
  7  a6  DATE,
  8  a7  TIMESTAMP(3)
  9  );

Table created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> create index t_idx on t(a4,a5);

Index created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> set autotrace traceonly explain
ops$tkyte%ORA11GR2> select * from t where a4 is null and a5 = 'xxx';

Execution Plan
----------------------------------------------------------
Plan hash value: 470836197

-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |     1 |   102 |     1   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| T     |     1 |   102 |     1   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |     1 |       |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("A4" IS NULL AND "A5"='xxx')
       filter("A5"='xxx')

Note
-----
   - dynamic sampling used for this statement (level=2)

ops$tkyte%ORA11GR2> set autotrace off

A reader, May 17, 2012 - 6:01 pm UTC

Hi Tom,

In above example even though both column (a4 and a5) are nullable, how optimizer decided to go for index access?

I remeber in 10g if column define as nullable as in above case will not peek index path, can you please explain?

Thanks in Advance


Tom Kyte
May 18, 2012 - 2:41 am UTC

because you said "and a5 = 'something'"

therefore a5 *cannot be null* and it will appear in the index.


regardless of version


If you have "where X is null and Y = 'something' "

and you have an index on (x,y) or (y,x) - the database can use that index since we KNOW that Y is not null in the context of that query.

partitioning ..

A Reader, December 08, 2012 - 5:00 am UTC

Tom,
we have Oracle version - 10gR2

on day #1 : table t ( id number, c1 number) is range partitioned on c1 column
id is a primary key column - generated from sequence

....
....

on day# 100 : Need of the day is that aging of the data is the objective and not the one which was on day#1

selection of data to purge from t table is based on traversing data through another table t2 ( t2 table has date column .. and requirement is purge older than 1 year from t and t2 based on STATUS column - closed cases). I have just quoted 02 tables.. there are around 10 tables which are related and data ( referenced ) has to be purged from all the tables.


Question :

1) aging of the data can only be done if table is range partitioned.. but the table t doesnt have the column ( say date..) which can be used as partition key instead of column c1.. in such scenario would it be practically possible achieve the aging goal?

2) if above answer is NO. then what is the best way to achieve aging.. by adding date column in t and.. updating the same ( using app logic) whenever there is update on the table t2 date field?.. so we are adding / rewriting code to do so insetad of using just delete command..


3) can we meet the both end of a line here ? I mean leveraging the performance benifits on most frequently accessed column c1 and at the same time..achiving aging of data ( data selection for purge is not based on c1 directly) ?

4) Is it fair to say - aging of data from a partitioned table would not be possible .. in case the requirement is complex in nature.. i.e. purge the data from 10 related tables ( including the t )? I see in this scenario each of the 10 tables has to be partitioned on the date column .. and data in each partition should map to each other functionally... then we can introduce purging emplying partitioning?

5) your suggestion to achive the new goal ( seeing the requirement) using any other method?


regards

Tom Kyte
December 14, 2012 - 2:20 pm UTC

given your current design, you cannot purge by dropping/truncating a partition.

You would have had to of partitioned table T1 by a field it doesn't even have, a field that is in T2.

In 11g (so not applicable to you) you don't say if T2 is a parent table of T1 - if it is, you could reference partition T1/T2 and then T1 would be partitioned by the attribute that you want to purge by.


If you want to purge by dropping/truncating a partition, you would have to put the date field into T1 somehow and range partition T1 on that attribute.

Week wise partitioned table with STORAGE(BUFFER_POO KEEP) growing to fast

Rajesh Ranjan, January 11, 2013 - 1:23 am UTC

Hi Tom,

I have created a week wise partitioned table using range partition and global partitioned index with STORAGE(BUFFER_POOL KEEP).

The table is replica of existing table which is containing 150000000+ records (not partitioned) size of the table is 11 GB.

When I have imported 70000000 from non partitioned to week wise partitioned table with /*+ APPEND*/ hint.
And I used /*+ APPEND_VALUES*/ withing application as inline insert query.

Now the Problem that I am facing is size of the table is 30 GB and growing too fast and performance is degrading.
It's critical for us please help..

Thanks
Rajesh Ranjan
Tom Kyte
January 14, 2013 - 1:33 pm UTC

And I used /*+ APPEND_VALUES*/ withing application as inline insert query.

that is probably a really bad idea. do you have any idea how that actually works??? how many rows at a time do you insert with that???


it is probably due to the insert with append_values that the table is growing. show your work here, what is the application logic.



(and why wouldn't you just PARTITION THE EXISTING TABLE????? it seems rather "not smart" to replicate 150,000,000 rows just for the fun of it)

and I question your use of the keep pool too - it sounds like "a really cool low level feature so if I use it I'll look good" thing. It is almost never necessary (or good even). It has very limited use in most applications.

Exchange partition

Shiva, April 10, 2013 - 5:25 pm UTC

Hi Tom,

Good Morning.

We have a weekly partitioned ORDER table on ORDER_DATE using range partition with interval partition feature. ETL needs to refresh data weekly once.

ETL process truncates and loads source data into stage table which is also partitioned as like base ORDER table. The challenge here is that, incremental order data contains new order which are raised in current week and modified orders of previous weeks orders will get loaded into different partition table. In order to refresh base table, we need to have control table to store all metadata information like number of partitions, partition name, etc.. and handle one by one partition between base ORDER table with the stage ORDER table. This process is taking longer duration currently.

Hence request you to indicate whether do we have any standard SQL routines to handle in a optimized way?

One more question, do we have any new feature in 11g R2 for exchanging partitions between 2 partition table without using any swapping non-partitioned table?

what is size of table to justify for partitioning

andrew, September 30, 2013 - 4:36 am UTC

In general, how large should the table be to justify for partitioning?

thanks

andrew

Add Partition to a new table

Rob, October 30, 2013 - 6:49 pm UTC

I'm using Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production and TNS for Linux: Version 11.2.0.3.0 - Production.
Requirement is to create a script to add a LIST partition to some selected tables in a schema (tables do not have data, they are not partitioned).
There are about 300 such tables (can vary) and their names are maintained in a separate table. I need to generate a DDL script with additional PARTITION BY LIST clause for all these tables.

Example -
Existing table -
CREATE TABLE test_part
(id number (2),
name varchar2(20),
audit_userid number (9));

Expected table -
CREATE TABLE test_part
(id number (2),
name varchar2(20),
audit_userid number (9))
PARTITION BY LIST (audit_userid)
(PARTITION p1_audit_userid VALUES (1));

Ultimate goal is to add more partitions based on the amount of data to be populated (that I can do by generating ALTER TABLE ADD PARTITION script).
Appreciate your help!
Tom Kyte
November 01, 2013 - 9:25 pm UTC

dbms_metadata.get_ddl

can be used to get the create table statement, to which you can append anything you need.

there are many examples of dbms_metadata.get_ddl on this site (and others)

Got a solution, is this the right way?

Rob, October 31, 2013 - 1:39 pm UTC

SET SERVEROUTPUT ON;
SET FEEDBACK OFF;

spool E:\ddl_part.sql

DECLARE
lv_table_ddl VARCHAR2 (32767);
lv_t_owner VARCHAR2 (30) := 'SCOTT';

CURSOR t_list_cur
IS
SELECT DISTINCT RTRIM (xm_list.target_table_name, '_') tname
FROM xm_tab_control_dtl xm_list
INNER JOIN
dba_tables dict_list
ON ( XM_LIST.TARGET_TABLE_NAME = dict_list.table_name
AND dict_list.owner = lv_t_owner)
WHERE xm_list.TARGET_TABLE_STG = 'TRG';

l_table_name t_list_cur%ROWTYPE;
BEGIN
DBMS_METADATA.SET_TRANSFORM_PARAM (DBMS_METADATA.SESSION_TRANSFORM,
'SEGMENT_ATTRIBUTES',
FALSE);
DBMS_METADATA.SET_TRANSFORM_PARAM (DBMS_METADATA.SESSION_TRANSFORM,
'CONSTRAINTS',
FALSE);
DBMS_METADATA.SET_TRANSFORM_PARAM (DBMS_METADATA.SESSION_TRANSFORM,
'REF_CONSTRAINTS',
FALSE);

OPEN t_list_cur;

LOOP

FETCH t_list_cur INTO l_table_name;

EXIT WHEN t_list_cur%NOTFOUND;

lv_table_ddl :=
DBMS_METADATA.get_ddl ('TABLE', l_table_name.tname, lv_t_owner);
lv_table_ddl :=
lv_table_ddl || 'PARTITION BY LIST (audit_userid)
(PARTITION p1_audit_userid VALUES (160));';
DBMS_OUTPUT.put_line (lv_table_ddl);

END LOOP;

CLOSE t_list_cur;
END;
/

spool off
/
exit
/

how large is the table to be justified for partitioning?

andrew, November 11, 2013 - 4:20 am UTC

Hi Tom,

will you please advise,
In general, how large should the table be to justify for partitioning?

thanks

andrew

Partition Pruning

Raghav, January 13, 2015 - 5:53 am UTC

Hi Tom

I have a small (may be silly question) question on partition pruning. When I was going through the link http://docs.oracle.com/cd/E11882_01/server.112/e25523/part_avail.htm it is mentioned like below.

Example 3-1 Creating a table with partition pruning

CREATE TABLE sales_range_hash(
s_productid NUMBER,
s_saledate DATE,
s_custid NUMBER,
s_totalprice NUMBER)
PARTITION BY RANGE (s_saledate)
SUBPARTITION BY HASH (s_productid) SUBPARTITIONS 8
(PARTITION sal99q1 VALUES LESS THAN
(TO_DATE('01-APR-1999', 'DD-MON-YYYY')),
PARTITION sal99q2 VALUES LESS THAN
(TO_DATE('01-JUL-1999', 'DD-MON-YYYY')),
PARTITION sal99q3 VALUES LESS THAN
(TO_DATE('01-OCT-1999', 'DD-MON-YYYY')),
PARTITION sal99q4 VALUES LESS THAN
(TO_DATE('01-JAN-2000', 'DD-MON-YYYY')));

SELECT * FROM sales_range_hash
WHERE s_saledate BETWEEN (TO_DATE('01-JUL-1999', 'DD-MON-YYYY'))
AND (TO_DATE('01-OCT-1999', 'DD-MON-YYYY')) AND s_productid = 1200;

Oracle uses the predicate on the partitioning columns to perform partition pruning as follows:

When using range partitioning, Oracle accesses only partitions sal99q2 and sal99q3, representing the partitions for the third and fourth quarters of 1999.

My question is: The partitions were defined with LESS THAN dates. When, in the query BETWEEN is used, why two partitions Q2 and Q3 will be selected?

I.e., Q2 will have values less than 01 July 99 and Q3 will have values less than 01 oct 99. When the query uses BETWEEN 01 july 99 and 01 oct 99 it has to select only the values >= 01 july 99 and < 01 oct 99. That means, it should have selected only one partition Q3 and no need to select Q2.
Please clarify.

Partitioning table

Paul, September 24, 2021 - 8:48 am UTC

Greetings !

I am reviewing a table for partitioning it. The table does not have natural partition key column.

SQL> desc MSGBT.INSTR_XREF
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 INSTR_ID                                  NOT NULL NUMBER(19)
 IDENTIFIER_TYPE                           NOT NULL NUMBER(10)
 RECORDED_DATE_START                       NOT NULL TIMESTAMP(6)
 RECORDED_DATE_END                                  TIMESTAMP(6)
 EFFECTIVE_DATE_START                      NOT NULL TIMESTAMP(6)
 EFFECTIVE_DATE_END                                 TIMESTAMP(6)
 IDENTIFIER                                         VARCHAR2(30)
 LOADED_BY                                          VARCHAR2(100)


1) Use case is,most of the queries running against the table have filter predicates:

"Where IDENTIFIER_TYPE =? and IDENTIFIER = ?"

2) "Where IDENTIFIER = ?"

3) very rarely few queries, use "Where RECORDED_DATE_END between :DATE1 and :DATE2".

==> count (distinct identifier_type) is 44
==> atmost one row returned by unique combination of (IDENTIFIER_TYPE and IDENTIFIER) column.

  1*  select IDENTIFIER_TYPE, IDENTIFIER from MSGBT.INSTR_XREF where IDENTIFIER_TYPE=2 and IDENTIFIER='DE000GF185H2'
SQL> /

IDENTIFIER_TYPE IDENTIFIER
--------------- ------------------------------
              2 DE000GF185H2
 


1) As the table is growing big , we want to consider looking into partitioning.
So, can you please suggest the correct partitioning method to use here.
2)
We have index as follows on the table. Table has Primary Key as well.
INDEX_NAME                     COLUMN_NAME                     COLUMN_POSITION
------------------------------ ------------------------------  ---------------
INSTR_XREF_IDX1            IDENTIFIER_TYPE                              1
INSTR_XREF_IDX1            IDENTIFIER                                   2
INSTR_XREF_PK              INSTR_ID                                     1
INSTR_XREF_PK              IDENTIFIER_TYPE                              2
INSTR_XREF_PK              RECORDED_DATE_START                          3
INSTR_XREF_PK              EFFECTIVE_DATE_START                         4

Chris Saxon
September 24, 2021 - 3:43 pm UTC

So, can you please suggest the correct partitioning method to use here.

There is no single "correct" partitioning method. It's all about trade-offs.

So start by answering this question:

What do you what to achieve by partitioning the table?

Faster queries? If so, which is it most important that you make faster? Which queries is it acceptable to run slower (there will almost certainly be some slower after you add partitioning)?
Faster archival of data?
Easier/faster maintenance? (e.g. adding indexes, moving the table, ...)

Answering this will help guide your solution.

Based on your information, candidate strategies include:

list partition by IDENTIFIER_TYPE
hash partition by IDENTIFIER
interval partition by RECORDED_DATE_END

You'll have to test and compare the performance of these on your application. Which of these come closest to meeting your goals while with minimal downsides?

Paul, September 25, 2021 - 12:41 am UTC

Hey Chris,

Thanks for your suggestion.

>> What do you what to achieve by partitioning the table?
Faster queries? If so, which is it most important that you make faster? Which queries is it acceptable to run slower (there will almost certainly be some slower after you add partitioning)?
Faster archival of data?
Easier/faster maintenance? (e.g. adding indexes, moving the table, ...)

Considering partitioning the table is, primarily to manage the segment size under control as well as for performance as the table projected to grow.
Data in the table will stay for ever (no purging at this time) and historical data will be compressed.

>>
Based on your information, candidate strategies include:

1. list partition by IDENTIFIER_TYPE
2. hash partition by IDENTIFIER
3. interval partition by RECORDED_DATE_END
You'll have to test and compare the performance of these on your application. Which of these come closest to meeting your goals while with minimal downsides?
>>

Yes, agree its kind of trade-offs here. identifier column is the common attribute in all the queries.
So option 2 (hash partition by IDENTIFIER) is the closest to choose in my view. Any thoughts ?

We will test the performance of the queries.

Here are the common queries in application.
===========================================

select identifier_type,identifier from MSGBT.Instr_xref where identifier='XXXXXXXX' and recorded_date_end> sysdate and effective_date_end>sysdate

select identifier_type,identifier from MSGBT.Instr_xref where identifier='XXXXXXXXX' and identifier_type=66 and recorded_date_end> sysdate and effective_date_end>sysdate

select identifier from MSGBT.Instr_xref where identifier='XXXXXXXX' and identifier_type=1 and recorded_date_end> sysdate and effective_date_end>sysdate

select identifier from MSGBT.Instr_xref where identifier='XXXXXXXX'



Thanks!

Chris Saxon
September 27, 2021 - 1:46 pm UTC

primarily to manage the segment size under control

So why exactly do you want to do that? What benefits are you hoping to get?

Data in the table will stay for ever (no purging at this time) and historical data will be compressed.

If you want to compress old partitions you need to know which are the "old" partitions. Range/interval partitioning by insert date is often the only feasible way to do this.

So option 2 (hash partition by IDENTIFIER) is the closest to choose in my view. Any thoughts?

From a query perspective, that's probably best.

But see my point above about compressing old data - if you (only) partition by this, how will you compress old partitions? If you're hash partitioning, it's almost certain you'll old and new data in the partitions.

Partition by HASH subpartition by RANGE

A reader, October 07, 2021 - 4:39 am UTC

Thanks for your good work to oracle community.

I have a question. We have a Yearly partition table,

PARTITION BY HASH (NUMBER_column)
SUBPARTITION BY RANGE (DATE_column)

Tried to convert to interval partition and got this error:

SQL> alter table HIST.M_PRICE set INTERVAL (NUMTOYMINTERVAL(1,'YEAR')) ;

ERROR at line 1:
ORA-14759: SET INTERVAL is not legal on this table.


1) Does Oracle support Interval partitioning in HASH-RANGE composite partitioned table ?

2) Can we use subpartition template here ?

3) How to add partition yearly if interval partition is not supported .?

Thanks!



Chris Saxon
October 07, 2021 - 11:49 am UTC

1. You can have INTERVAL-HASH partitioned tables, but not HASH-INTERVAL; you can't use interval partitioning at the subpartition level

2. Yes

3. You'll have to alter the subpartitions to add the new year as needed

mixture of daily + monthly partition on range+hash partition table

A reader, October 15, 2021 - 5:40 am UTC

Thanks for your response and inputs. Appreciate it.

Currently, we have Yearly partition table (partition by DATE column, subpartition by NUMBER column).
We want to convert the table to daily partition, meaning the current partition will be on daily partition and as data ages, we want to move the old partitions to monthly partition by consolidating it.

Question-
Does Oracle supports having mixture of current day partitions as daily and historical partitions as monthly?

Can you please show an example how to implement this .


Thanks!
Chris Saxon
October 19, 2021 - 9:36 am UTC

Yes - though you'll have to convert your daily partitions to monthly.

One way to tackle this is to interval partition by day, then merge the partitions into months as needed.

For example, this creates daily partitions, then merges the first to days into one:

create table t (
  c1 date
) partition by range ( c1 ) 
  interval ( interval '1' day ) (
  partition p0 values less than ( date'2021-01-01' )
);

insert into t 
with rws as (
  select date'2020-12-31' + level dt from dual
  connect by level <= 365
)
  select * from rws;
  
alter table t
  merge partitions 
  for ( date'2021-01-01' ) 
  to for ( date'2021-01-02' );
  
select * from t
  partition for ( date'2021-01-01' );


Just repeat the merge process as needed.

More to Explore

VLDB

If you are new to partitioning, check out Connor McDonald's introduction series here.

VLDB

Documentation set on VLDB and Partitioning.