Skip to Main Content
  • Questions
  • Question about sequence with lower nextval than column

Breadcrumb

May 4th

Question and Answer

Chris Saxon

Thanks for the question, JOSHI.

Asked: January 18, 2021 - 9:58 am UTC

Last updated: January 19, 2021 - 1:23 pm UTC

Version: PL/SQL Release 11.2.0.1.0 - Production

Viewed 1000+ times

You Asked

Hi,

I have a sequence name s1 start with 1 and incremented by 1 and end with 999.

I am inserting these sequence value into one table name 'e'. E table contains eno (pk) column.

insert into e values(s1.nextval);

I inserted 9 rows. sequence current value is 9 and 10 is already inserted in backend. I try to

insert into e values(s1.nextval);

then it will come pk violation error. In this case i want to insert 11 in place of 10

and Chris said...

There's no good solution to this in 11g. You have to manually consume the sequence values up to the current PK max by calling sequence.nextval or drop/recreate the sequence.

From 12c you can define identity columns. These use sequences under the covers. And you can bump them up to the current highest value in the column with alter table:

create table t (
  c1 int 
    generated by default as identity
    primary key
);

begin
  for i in 1 .. 9 loop
    insert into t values ( default );
  end loop;
  
  insert into t values ( 10 );
  insert into t values ( 20 );
  commit;
end;
/

insert into t values ( default );

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

alter table t
  modify c1 
  generated by default as identity (
      start with limit value 
  );

var id number;
insert into t values ( default )
  returning c1 into :id;
  
print :id

        ID
----------
        21


Or from 18c you can use the restart clause to set the nextval:

create sequence s;

select s.nextval from dual;

NEXTVAL   
         1 

alter sequence s
  restart start with 99;
  
select s.nextval from dual;

drop sequence s;

NEXTVAL   
        99 


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

More to Explore

SQL

The Oracle documentation contains a complete SQL reference.