grant select on dba_constraints to elxis_db_user;grant select on dba_cons_columns to elxis_db_user;grant execute on dbms_sql to elxis_db_user;grant create procedure to elxis_db_user;
CREATE OR REPLACE PROCEDURE FIX_SEQUENCE_PROBLEMIS CURSOR seq_cur IS SELECT a.owner, a.table_name, a.constraint_name, a.constraint_type, b.column_name, b.POSITION, c.SEQUENCE_NAME FROM dba_constraints a, dba_cons_columns b, (select replace(SEQUENCE_NAME,'SEQ_','') seq_table, SEQUENCE_NAME from user_sequences) c WHERE a.constraint_name = b.constraint_name AND a.owner = 'ELXIS_DB_USER' /* replace "ELXIS_DB_USER" with your oracle user/schema, must Upper Case*/ AND a.constraint_type = 'P' and a.table_name = c.seq_table ORDER BY a.owner, a.table_name, a.constraint_name, b.POSITION; seq_rec seq_cur%ROWTYPE; iqnore integer; sql_max varchar2(4000); sql_max_cur integer; max_id_var number(10); sql_seq_next varchar(4000); sql_seq_next_cur integer; seq_last_var number(10);BEGIN OPEN seq_cur; LOOP FETCH seq_cur INTO seq_rec; EXIT WHEN seq_cur%NOTFOUND; sql_max := 'select max(nvl('||seq_rec.column_name||',1)) as MAX_ID from '||seq_rec.table_name; sql_max_cur := dbms_sql.open_cursor; dbms_sql.parse(sql_max_cur,sql_max,dbms_sql.native); dbms_sql.define_column(sql_max_cur,1,max_id_var); iqnore := dbms_sql.execute(sql_max_cur); IF DBMS_SQL.FETCH_ROWS(sql_max_cur)>0 THEN dbms_sql.column_value(sql_max_cur,1,max_id_var); end if; sql_seq_next := 'select '||seq_rec.SEQUENCE_NAME||'.NEXTVAL from dual'; sql_seq_next_cur := dbms_sql.open_cursor; dbms_sql.parse(sql_seq_next_cur,sql_seq_next,dbms_sql.native); dbms_sql.define_column(sql_seq_next_cur,1,seq_last_var); iqnore := dbms_sql.execute(sql_seq_next_cur); IF DBMS_SQL.FETCH_ROWS(sql_seq_next_cur)>0 THEN dbms_sql.column_value(sql_seq_next_cur,1,seq_last_var); end if; if (seq_last_var <= max_id_var) then while (seq_last_var <= max_id_var) loop if seq_last_var > max_id_var then exit; end if; sql_seq_next := 'select '||seq_rec.SEQUENCE_NAME||'.NEXTVAL from dual'; sql_seq_next_cur := dbms_sql.open_cursor; dbms_sql.parse(sql_seq_next_cur,sql_seq_next,dbms_sql.native); dbms_sql.define_column(sql_seq_next_cur,1,seq_last_var); iqnore := dbms_sql.execute(sql_seq_next_cur); IF DBMS_SQL.FETCH_ROWS(sql_seq_next_cur)>0 THEN dbms_sql.column_value(sql_seq_next_cur,1,seq_last_var); end if; if dbms_sql.is_open(sql_seq_next_cur) then dbms_sql.close_cursor(sql_seq_next_cur); end if; end loop; end if; END LOOP; CLOSE seq_cur; if dbms_sql.is_open(sql_max_cur) then dbms_sql.close_cursor(sql_max_cur); end if; if dbms_sql.is_open(sql_seq_next_cur) then dbms_sql.close_cursor(sql_seq_next_cur); end if;EXCEPTION when others then begin CLOSE seq_cur; if dbms_sql.is_open(sql_max_cur) then dbms_sql.close_cursor(sql_max_cur); end if; if dbms_sql.is_open(sql_seq_next_cur) then dbms_sql.close_cursor(sql_seq_next_cur); end if; end;END FIX_SEQUENCE_PROBLEM;
begin FIX_SEQUENCE_PROBLEM;end;
revoke select on dba_constraints from elxis_db_user;revoke select on dba_cons_columns from elxis_db_user;revoke execute on dbms_sql from elxis_db_user;revoke create procedure from elxis_db_user;