On the other hand, we can use a trick to change the value of a sequence without dropping/recreating it.
Let’s say we have a sequence and its value is 1000, and we want to set it to 500.
SQL> CREATE SEQUENCE test_seq
INCREMENT BY 1
START WITH 1000
MINVALUE 1
MAXVALUE 99999999;
SQL> SELECT last_number
FROM user_sequences
WHERE sequence_name = 'TEST_SEQ';
LAST_NUMBER
-----------
1000
SQL> ALTER SEQUENCE test_seq INCREMENT BY -500;
SQL> SELECT test_seq.NEXTVAL FROM dual;
SQL> ALTER SEQUENCE test_seq INCREMENT BY 1;
SQL> SELECT last_number
FROM user_sequences
WHERE sequence_name = 'TEST_SEQ';
LAST_NUMBER
-----------
500
By this way, we can set the new value of the given sequence.
Just for fun and for easy use of that logic in the future, let’s create a procedure for it.
Just for fun and for easy use of that logic in the future, let’s create a procedure for it.
CREATE OR REPLACE PROCEDURE Set_Sequence_value
( pi_owner IN VARCHAR2,
pi_seq_name IN VARCHAR2,
pi_new_seq_value IN NUMBER)
IS
PRAGMA AUTONOMOUS_TRANSACTION;
l_last_number NUMBER;
l_incr_by NUMBER;
CURSOR c_get_seq_param IS
SELECT increment_by
FROM all_sequences
WHERE sequence_owner = UPPER (pi_owner)
AND sequence_name = UPPER (pi_seq_name);
BEGIN
OPEN c_get_seq_param;
FETCH c_get_seq_param INTO l_incr_by;
CLOSE c_get_seq_param;
IF l_incr_by IS NOT NULL
THEN
EXECUTE IMMEDIATE 'SELECT '||pi_owner||'.'||pi_seq_name||'.CURRVAL FROM DUAL' INTO l_last_number;
EXECUTE IMMEDIATE 'ALTER SEQUENCE '||pi_owner||'.'||pi_seq_name||' INCREMENT BY '||(pi_new_seq_value - l_last_number);
EXECUTE IMMEDIATE 'SELECT '||pi_owner||'.'||pi_seq_name||'.NEXTVAL FROM DUAL' INTO l_last_number;
EXECUTE IMMEDIATE 'ALTER SEQUENCE '||pi_owner||'.'||pi_seq_name||' INCREMENT BY ' || l_incr_by;
END IF;
END Set_Sequence_value;
Note: In order to not affect the transaction control, the procedure is created under AUTONOMOUS_TRANSACTION.
Have a fun and thank you for your time to read this article.