The only requirement for indexes to support an FK is that the leading
columns of the index match the columns of the FK.

I believe that they must also be in the same order, but I'll let you look
that up in the fine manual.

So, if you find that you need an index made up of the columns 
RESP_PARTY_NAME,
CUSTIMER_MOT_ID and FROM_EVENT, the following index would prevent
locking:

create index benchmark_hdr_custresp_idx 
on benchmark_hdr ( 
   RESP_PARTY_NAME
  ,CUSTIMER_MOT_ID
  , FROM_EVENT
);

There's no need for a separate index on just the FK columns.

HTH

Jared







"Krishnaswamy, Ranganath" <[EMAIL PROTECTED]>
Sent by: [EMAIL PROTECTED]
 01/14/2003 02:29 AM
 Please respond to ORACLE-L

 
        To:     Multiple recipients of list ORACLE-L <[EMAIL PROTECTED]>
        cc: 
        Subject:        Foreign key indexes on individual columns or multiple columns


Hi List,

                 I have a table by name Benchmark_hdr with the following 
columns:

  BENCHMARK_HDR_ID    NUMBER        NOT NULL 
  CALENDAR_TYPE     CHAR (1), 
  UOM               VARCHAR2 (10), 
  CALENDAR_PORT     CHAR (1), 
  CUSTOMER_MOT_ID   NUMBER        NOT NULL 
  RESP_PARTY_NAME   VARCHAR2 (10), 
  FROM_EVENT        NUMBER, 
  TO_EVENT          NUMBER, 
  LAST_UPDATED      DATE 

I have created foreign key constraints using the below commands: 

  ALTER TABLE BENCHMARK_HDR ADD  CONSTRAINT BENCHAMRK_HDR_CUSTOMERESP_FK
 FOREIGN KEY (RESP_PARTY_NAME, CUSTOMER_MOT_ID) 
  REFERENCES XM.CUSTOMER_RESPONSIBLE_PARTY (RESP_PARTY_NAME,
CUSTOMER_MOT_ID) ;

ALTER TABLE BENCHMARK_HDR ADD  CONSTRAINT BENCHAMRK_HDR_CUSTOMEREVENT_FK
 FOREIGN KEY (FROM_EVENT) 
  REFERENCES XM.CUSTOMER_EVENT (CUSTOMER_EVENT_ID) ON DELETE CASCADE;

ALTER TABLE BENCHMARK_HDR ADD  CONSTRAINT BENCHMARK_HDR_CUSTOMEREVENT_FK
 FOREIGN KEY (TO_EVENT) 
  REFERENCES XM.CUSTOMER_EVENT (CUSTOMER_EVENT_ID) ON DELETE CASCADE;

  The foreign keys need to be indexed so that the child table is not 
locked
when a record in the parent table is being updated or deleted.  If the
foreign keys are indexed the corresponding child record or records are 
only
locked when the parent table record is being updated or deleted.  In this
context I would like to seek the advice of the list as to whether I should
create indexes on individual foreign keys or should I create one or more
composite index(es) on foreign keys?  If I need to create a composite 
index
on which columns should I base my index on?  Could anybody advise me on 
this
with the reasons for following that particular approach?  Any help in this
regard is very much appreciated.

Thanks and Regards,

Ranganath




WARNING: The information in this message is confidential and may be 
legally
privileged. It is intended solely for the addressee.  Access to this 
message
by anyone else is unauthorised.  If you are not the intended recipient, 
any
disclosure, copying, or distribution of the message, or any action or
omission taken by you in reliance on it, is prohibited and may be 
unlawful.
Please immediately contact the sender if you have received this message in
error. Thank you.
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Krishnaswamy, Ranganath
  INET: [EMAIL PROTECTED]

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (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).




-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: 
  INET: [EMAIL PROTECTED]

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (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).

Reply via email to