How to Synchronize Oracle Identity Column Sequences

ยท

4 min read

Introduction

Many customers are moving data from production environments to lower environments like development or testing. During this process, they often overlook the primary key and simply import the records. Consequently, when they try to add new records, they encounter the ORA-00001 error, indicating a unique constraint violation.

Investigating the problem and fixing it

Let's start by demonstrating the problem with a simple example using a colors table.

create table colors (
    id      number generated by default on null as identity
            constraint colors_id_pk primary key,
    name    varchar2(255 char) not null
);

Next, add a few values to that table.

begin
   insert into colors (name) values ('Olive');
   insert into colors (name) values ('Brown');
   insert into colors (name) values ('Grey');
   insert into colors (name) values ('Red');
   insert into colors (name) values ('Violet');
   commit;
end;
/

Now, imagine that after a few days, weeks, or months, someone decides to copy the data from production to development using a script like this one:

truncate table colors;

begin
   insert into colors (id,name) values (1,'Olive');
   insert into colors (id,name) values (2,'Brown');
   insert into colors (id,name) values (3,'Grey');
   insert into colors (id,name) values (4,'Red');
   insert into colors (id,name) values (5,'Violet');
   insert into colors (id,name) values (6,'White');
   insert into colors (id,name) values (7,'Green');
   insert into colors (id,name) values (8,'Forest');
   insert into colors (id,name) values (9,'Orange');
   insert into colors (id,name) values (10,'Pink');
   insert into colors (id,name) values (11,'Teal');
   insert into colors (id,name) values (12,'Cyan');
   insert into colors (id,name) values (13,'Black');
   insert into colors (id,name) values (14,'Blue');
   insert into colors (id,name) values (15,'Yellow');
   commit;
end;
/

Looks good, right? But the next time an insert is made, an error will occur.

insert into colors (name) values ('Magenta');

Error starting at line : 1 in command -
insert into colors (name) values ('Magenta')
Error report -
ORA-00001: unique constraint (ADMIN.COLORS_ID_PK) violated


More Details :
https://docs.oracle.com/error-help/db/ora-00001/

This happens because the sequence behind the identity column is not synchronized. The first step to check this is to find the sequence name used to populate the primary key by using the user_tab_columns view. The column data_default contains the SQL expression to get the next sequence value.

select data_default
  from user_tab_columns  
 where table_name = 'COLORS'
   and column_name = 'ID'

You should obtain something like "SCHEMA_NAME"."ISEQ$$_XXXXXX".nextval where XXXXXX is a number. Execute that expression to get the next number.

โ—
Note that by calling "SCHEMA_NAME"."ISEQ$$_XXXXXX".nextval, we actually increment the sequence.
select "SCHEMA_NAME"."ISEQ$$_XXXXXX".nextval
  from dual

Then, we have to find the maximum value for the primary key in our colors table.

select max(id)
  from colors

If you followed all the steps, you should have the following values:

Sequence Last NumberPrimary Key Max Value
615

As you can see the maximum value of the primary key column is greater than the last sequence number, so we can fix that by executing the following DDL statement

alter table colors modify id generated by default on null as identity (start with limit value);

After that, we are able to insert a new row in a table

insert into colors (name) values ('Magenta');

1 row inserted.

Putting all the pieces together

But it's a lot of manual steps to make it work for a single table, which is usually not the case. So I came up with a script that identifies unsynchronized identity columns and provides you with the DDL statement. And yes, that's because I'm very lazy ๐Ÿค“

set serveroutput on
begin
   for rec in (
      select table_name, column_name, data_default
        from user_tab_columns
       where identity_column = 'YES'
         and default_on_null = 'YES'
   )
   loop
      sys.dbms_output.put_line(
            'alter table '
            || lower(rec.table_name)
            ||' modify '
            || lower(rec.column_name)
            ||' generated by default on null as identity (start with limit value);'); 
   end loop;
end;
/
โ—
I am sharing this snippet to help you identify synchronization issues with identity column sequences. I do not provide any guarantees, so you should review the generated alter statements before running them.

Conclusion

Synchronizing Oracle Identity Column Sequences is crucial for maintaining data integrity when moving data between environments. By understanding the problem and implementing the right solutions, you can avoid common errors like the ORA-00001 unique constraint violation.

I hope you enjoyed reading this, and if it helped you, please leave a comment ๐Ÿค“

Edit: Thank you so much to Roel Hartman for pointing me to a much easier solution with the start with limit value clause

ย