Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Can I locally partition my primary key constraint index?
Kevin,
Have you actually done this?
I have a test copy of the database now and have been testing this. I successfully created a locally partitioned index and then tried to add the primary key constraint to the same table using the same columns (in the same order) as the index was created using and I got the following error:
ORA-01408: such column list already indexed.
Is there any way to tell the alter table create constraint command not to try to create a new index?
Thanks,
Cherie
"Toepke, Kevin M" To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> <ktoepke_at_cms.ce cc: ndant.com> Subject: RE: Can I partition my primary key constraint index? Sent by: root_at_fatcity.co m 05/14/01 12:36 PM Please respond to ORACLE-L
Ok, I'll jump in here 'cause I may be able to simplify the issue.
Starting with Oracle 8, you can create a Primary Key that uses an existing index. This makes the administration stuff easier. You can create your own locally partitioned unique index (using regular CREATE INDEX syntax).
Once the index is created, you can create the PK (ALTER TABLE x ADD CONSTRAINT y PRIMARY KEY (z);). The existing index will be used if Oracle can use it.
This works with partitioned tables as long as the PK index is equipartitioned with the base table.
Kevin
-----Original Message-----
Sent: Monday, May 14, 2001 10:17 AM
To: Multiple recipients of list ORACLE-L
Diana,
Can I build the initial local primary key index using the storage and tablespace clause to place the index in the correct index tablespace to begin with. This index is multiple gigs and my database is tight on space right now. I'm not sure that I have enough room to put the index in the data tablespace and then move it to the appropriate index partition tablespaces?
Do you put each of your primary key index partitions in a separate tablespace?
The last DBA put all of our indexes into three tablespaces (small, medium, large) which doesn't work very well when you go to get rid of a partition.
Thanks,
Cherie
Diana_Duncan_at_ttpa rtners.com To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> Sent by: cc: root_at_fatcity.com Subject: Re: Can Ipartition my primary key constraint index?
05/13/01 02:55 PM Please respond to ORACLE-L
Yes, Cherie, you can. When creating the primary key constraint, use the "USING INDEX" clause to specify any storage parameters you want for the automatically created primary key index. I always use the clause, because I am a picky DBA and I want my indices in their own tablespace and with their own storage parameters. Also, if you specify that the index is LOCAL, the partitioning will follow the same algorithm as the table. Unfortunately, if you do LOCAL, the index partitions will automatically be placed in the same tablespace as the table, but you can "move" the partitions if you wish.
HTH,
Diana Duncan
TITAN Technology Partners
One Copley Parkway, Ste 540
Morrisville, NC 27560
VM: 919.466.7337 x 316
F: 919.466.7427
E: Diana_Duncan_at_ttpartners.com
Cherie_Machler @gelco.com To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> Sent by: cc: root_at_fatcity.c Fax to: om Subject: Can I partition myprimary key constraint index?
05/11/2001 04:51 PM Please respond to ORACLE-L
Oracle will automatically create an index for your primary key constraint.
I have a lot of large partitioned tables in my data warehouse. All of my primary key indexes are non-partitioned. I would like them to be partitioned.
When I drop the constraint and re-enable it, can I specify at that time that I want the index to be partitioned? Or do I need to drop my index and rebuild it to be partitioned after the fact?
Is there any problem with having partitioned primary key indexes?
Thanks,
Cherie
--
Please see the official ORACLE-L FAQ: http://www.orafaq.com
--
Author:
INET: Diana_Duncan_at_ttpartners.com
Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Liststo: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
--
Please see the official ORACLE-L FAQ: http://www.orafaq.com
--
Author:
INET: Cherie_Machler_at_gelco.com
Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Liststo: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Liststo: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
--
Please see the official ORACLE-L FAQ: http://www.orafaq.com
--
Author:
INET: Cherie_Machler_at_gelco.com
Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Liststo: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing). Received on Fri Aug 03 2001 - 19:14:08 CDT
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message