Skip to Main Content
  • Questions
  • The new Identity clause doesn't increment the id

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Nicolas.

Asked: August 04, 2016 - 2:24 pm UTC

Last updated: August 08, 2017 - 9:09 am UTC

Version: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production

Viewed 10K+ times! This question is

You Asked

To reproduce the problem :

CREATE TABLE MY_TABLE (
  ID NUMBER(19, 0) GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
  name NVARCHAR2(255) NOT NULL
);

INSERT INTO MY_TABLE (ID, name) VALUES (1, 'test1');
INSERT INTO MY_TABLE (name) VALUES ('test2');


As we can see, I first try to manually insert the ID and after I let the IDENTITY mechanism do the work. But when I try to run the last line I receive the following error :
ORA-00001: unique constraint violated

The sequence behind the IDENTITY mechanism doesn't seem to be able to take into account manually inserted ID. Is this a desired behavior or am I missing something?



and Chris said...

You provided a value in the first insert. So Oracle didn't access the identity's sequence to increment it!

The sequence behind the IDENTITY mechanism doesn't seem to be able to take into account manually inserted ID. Is this a desired behavior

Yes, this is expected behaviour.

SQL> CREATE TABLE MY_TABLE (
  2    ID NUMBER(19, 0) GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
  3    name NVARCHAR2(255) NOT NULL
  4  );

Table created.

SQL>
SQL> INSERT INTO MY_TABLE (ID, name) VALUES (1, 'test1');

1 row created.

SQL>
SQL> select sequence_name, last_number from user_sequences
  2  where  sequence_name like 'ISEQ$$%';

SEQUENCE_NAME        LAST_NUMBER
-------------------- -----------
ISEQ$$_133885                  1

SQL>
SQL> INSERT INTO MY_TABLE (name) VALUES ('test2');
INSERT INTO MY_TABLE (name) VALUES ('test2')
*
ERROR at line 1:
ORA-00001: unique constraint
(CHRIS.SYS_C0025610) violated


SQL>
SQL> INSERT INTO MY_TABLE (name) VALUES ('test2');

1 row created.

SQL>
SQL> select * from my_table;

        ID NAME
---------- --------------------
         1 test1
         2 test2


Take care if you mixing providing your own values with identities...

Rating

  (4 ratings)

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

Comments

generated always

Laurent Schneider, August 05, 2016 - 11:02 am UTC

To avoid mixing own values with identities, use ALWAYS

SQL> create table t(id number GENERATED ALWAYS AS IDENTITY primary key, x number)
Table created.
SQL> insert into t values (1,1)
insert into t values (1,1)
Error at line 11
ORA-32795: cannot insert into a generated always identity column

A reader, August 05, 2016 - 11:40 am UTC


generated always

Rajeshwaran, Jeyabal, August 05, 2016 - 2:24 pm UTC

Thanks Laurent. Never thought of that, it helps. Thanks.

There is an option GENERATED BY DEFAULT ON NULL AS IDENTITY

Chinmay Patel, August 08, 2017 - 12:44 pm UTC

Try below solution. It is working...

CREATE TABLE MY_TABLE (
ID NUMBER(19, 0) GENERATED BY DEFAULT ON NULL AS IDENTITY PRIMARY KEY,
name NVARCHAR2(255) NOT NULL
);

INSERT INTO MY_TABLE (ID, name) VALUES (1, 'test1');
INSERT INTO MY_TABLE (name) VALUES ('test2');
Chris Saxon
August 08, 2017 - 9:09 am UTC

It doesn't work for me...

CREATE TABLE MY_TABLE ( 
ID NUMBER(19, 0) GENERATED BY DEFAULT ON NULL AS IDENTITY PRIMARY KEY, 
name NVARCHAR2(255) NOT NULL 
); 

INSERT INTO MY_TABLE (ID, name) VALUES (1, 'test1'); 
INSERT INTO MY_TABLE (name) VALUES ('test2'); 

ORA-00001: unique constraint (CHRIS.SYS_C0017753) violated

select * from my_table;

ID  NAME   
1   test1