Re: How to create 2 unique indexes (Field1, Field2) and (Field1, Fiel

2001-05-31 Thread Stephane Faroult

"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 
   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 
WHERE ROWID IN (SELECT ROW_ID FROM EXCEPTIONS);
INSERT INTO 
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: [EMAIL PROTECTED]

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: [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).



Re: How to create 2 unique indexes (Field1, Field2) and (Field1, Fiel

2001-05-31 Thread Rachel Carmichael

Advice? Yes -- find out which records in your table have the duplicate 
combination of ACCTNO,PAYGRP  and either delete the duplicate row, correct 
the problem row or don't create a unique index


>From: "CHAN Chor Ling Catherine (CSC)" <[EMAIL PROTECTED]>
>Reply-To: [EMAIL PROTECTED]
>To: Multiple recipients of list ORACLE-L <[EMAIL PROTECTED]>
>Subject: How to create 2 unique indexes (Field1, Field2) and (Field1, Fiel
>Date: Wed, 30 May 2001 17:55:21 -0800
>
>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
>--
>Please see the official ORACLE-L FAQ: http://www.orafaq.com
>--
>Author: CHAN Chor Ling Catherine (CSC)
>   INET: [EMAIL PROTECTED]
>
>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: [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).

_
Get your FREE download of MSN Explorer at http://explorer.msn.com

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

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: [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).



RE: How to create 2 unique indexes (Field1, Field2) and (Field1,

2001-05-30 Thread CHAN Chor Ling Catherine (CSC)

Hi,

I would like to thank those who replied. Yes, my problem has been resolved
after removing duplicate values in the table. Thanks.

Regds,
New Bee
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: CHAN Chor Ling Catherine (CSC)
  INET: [EMAIL PROTECTED]

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: [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).



RE: How to create 2 unique indexes (Field1, Field2) and (Field1,

2001-05-30 Thread Jacques Kilchoer
Title: RE: How to create 2 unique indexes (Field1, Field2) and (Field1, Fiel





> -Original Message-
> From: CHAN Chor Ling Catherine (CSC) [mailto:[EMAIL PROTECTED]]
> 
> 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



You are getting an error because you are trying to create an index on columns that don't have unique values. Example:


SQL> create table t (a number, b number, c number) ;
Table created.


SQL> insert into t (a, b, c) values (1, 2, 3) ;
1 row created.


SQL> create unique index t_u1 on t (a, b) ;
Index created.


SQL> create unique index t_u2 on t (b, c) ;
Index created.


SQL> drop index t_u2 ;
Index dropped.


SQL> insert into t (a, b, c) values (4, 2, 3) ;
1 row created.


SQL> create unique index t_u2 on t (b, c) ;
create unique index t_u2 on t (b, c)
    *
ERROR at line 1:
ORA-01452: cannot CREATE UNIQUE INDEX; duplicate keys found


--
Jacques R. Kilchoer
(949) 754-8816
Quest Software, Inc.
8001 Irvine Center Drive
Irvine, California 92618
U.S.A.
http://www.quest.com





RE: How to create 2 unique indexes (Field1, Field2) and (Field1,

2001-05-30 Thread Ross Collado

Hi,

The second index failed because of dups found.  You will need to check the
data and correct them before creating the index.  
The following should tell you which ones have dupl. values and how many
occured:

SELECT ACCTNO,PAYGRP,count(*)  from SPY_ADHOC_PAYMENT group by ACCTNO,PAYGRP
having count(*) > 1;

HTH,
Ross

> -Original Message-
> From: CHAN Chor Ling Catherine (CSC) [mailto:[EMAIL PROTECTED]]
> Sent: Thursday, 31 May 2001 11:55
> To: Multiple recipients of list ORACLE-L
> Subject: How to create 2 unique indexes (Field1, Field2) and (Field1,
> Fiel
> 
> 
> 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
> -- 
> Please see the official ORACLE-L FAQ: http://www.orafaq.com
> -- 
> Author: CHAN Chor Ling Catherine (CSC)
>   INET: [EMAIL PROTECTED]
> 
> 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: [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.com
-- 
Author: Ross Collado
  INET: [EMAIL PROTECTED]

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: [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).