Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: How to create 2 unique indexes (Field1, Field2) and (Field1, Fiel
"CHAN Chor Ling Catherine (CSC)" wrote:
>
> Hi Gurus,
>
> How do I create 2 unique indexes (STDID,PAYGRP) and (ACCTNO,PAYGRP) on the
> same table ?
>
> I created the first index successfully but encountered the error "ORA-01452:
> cannot CREATE UNIQUE INDEX; duplicate keys found" when I tried to create the
> 2nd index.
>
> SELECT INDEX_NAME,TABLE_NAME,UNIQUENESS FROM USER_INDEXES WHERE
> TABLE_NAME='SPY_ADHOC_PAYMENT'
>
> INDEX_NAME TABLE_NAME UNIQUENES
> ------------------------------ ------------------------------ ---------
> U_SPYADH_1 SPY_ADHOC_PAYMENT UNIQUE
>
> SQL> SELECT * FROM USER_IND_COLUMNS WHERE TABLE_NAME='SPY_ADHOC_PAYMENT';
>
> INDEX_NAME TABLE_NAME COLUMN_NAME
> ------------------------------ ------------------------------
> ------------------------------
> U_SPYADH_1 SPY_ADHOC_PAYMENT STDID
> U_SPYADH_1 SPY_ADHOC_PAYMENT PAYGRP
>
> SQL> CREATE UNIQUE INDEX U_SPYADH_2 ON SPY_ADHOC_PAYMENT (ACCTNO,PAYGRP);
> CREATE UNIQUE INDEX U_SPYADH_2 ON SPY_ADHOC_PAYMENT (ACCTNO,PAYGRP)
> *
> ERROR at line 1:
> ORA-01452: cannot CREATE UNIQUE INDEX; duplicate keys found
>
> Any advice ? Thanks.
>
> Regds,
> New Bee
>
Catherine,
To solve this type of problem it may be easier to create a UNIQUE CONSTRAINT (which creates a unique index behind the scene) than creating the index directly. The reason is that if you run a script named (out of memory) utlexcpt.sql located under $ORACLE_HOME/rdbms/admin you can create a table EXCEPTIONS which will hold pointers to duplicate rows and which you can populate using
ALTER TABLE ...
ADD CONSTRAINT ...
EXCEPTIONS INTO EXCEPTIONS
(by the way always name your constraint and specify USING INDEX).
You can then clean-up your data using
CREATE TABLE PROBLEM_LINES
AS SELECT *
FROM <your table> WHERE ROWID IN (SELECT ROW_ID FROM EXCEPTIONS);
Then, in your case, check that you have TRUE duplicates in PROBLEM_LINES. If this is the case you can do :
DELETE <your table>
WHERE ROWID IN (SELECT ROW_ID FROM EXCEPTIONS);
INSERT INTO <your table>
SELECT DISTINCT * FROM PROBLEM_LINES;
This is, I think, cleaner than a group by of death to try to identify
duplicates, especially if your table is big.
-- Regards, Stephane Faroult Oriole Corporation Voice: +44 (0) 7050-696-269 Fax: +44 (0) 7050-696-449 Performance Tools & Free Scripts -------------------------------------------------------------- http://www.oriole.com, designed by Oracle DBAs for Oracle DBAs -------------------------------------------------------------- -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Stephane Faroult INET: sfaroult_at_oriole.com Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: 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 Thu May 31 2001 - 15:35:09 CDT