Recently I came across an issue related to the sequence object (shipped in SQL Server 2012) because usually we generate the next ID from the sequence object without checking whether it has reached its limit and it cannot generate a new ID. Due to this it generates an error as well. Given below are the error details.
Msg 11728, Level 16, State 1, Line 1
The sequence object ‘Seq_Sample1’ has reached its minimum or maximum value. Restart the sequence object to allow new values to be generated. Sequence object maintain its minimum and maximum value by default.
So what is the solution ? But before proceeding with the solution let me create a sample.
SAMPLE :
--This script is compatible with SQL Server 2012 and above. --Create a sequence object USE [AdventureWorks2012] GO --DROP SEQUENCE [dbo].[Seq_Sample1] --GO CREATE SEQUENCE [dbo].[Seq_Sample1] AS [tinyint] START WITH 1 INCREMENT BY 1 MINVALUE 1 MAXVALUE 4 GO --Generate sequence number up to 4 ID --because it has a maximum limit of 4. SELECT Next value for [dbo].[Seq_Sample1] GO 4
SOLUTION 1 : (Not recommended)
In this solution, you need to check the minimum and maximum value of the sequence with the current value and if it matches either of them, it means that sequence has been reached to its minimum or value and you cannot generate a new ID. It is not recommended because it is a lengthy procedure. Given below is the script.
--This script is compatible with SQL Server 2012 and above. DECLARE @minimum_value As sql_variant DECLARE @maximum_value As sql_variant DECLARE @current_value As sql_variant SELECT @minimum_value=[minimum_value] ,@maximum_value=[maximum_value] ,@current_value=[current_value] FROM sys.sequences AS seq WHERE name ='Seq_Sample1' SELECT IIF(@minimum_value=@current_value OR @maximum_value=@current_value ,'You cannot generate a new ID' ,'You can generate a new ID') AS [Result] --OUTPUT
SOLUTION 2 : Using Is_exhausted property (Recommended)
In this solution, we will use a sequence property namely “is_exhausted” and can quickly check whether it reached its limit or not.
Given below is the script.
--This script is compatible with SQL Server 2012 and above. SELECT IIF((SELECT is_exhausted FROM sys.sequences AS seq WHERE name ='Seq_Sample1')=1 ,'You cannot generate a new ID' ,'You can generate a new ID') AS [Result] --OUTPUT
CONCLUSION :
As you can see, both solutions generate the same output but solution 2 is recommended because we used a property namely “is_exhausted” and reduced the size of the script.
Leave a Reply