Even though SEQUENCE object is available with much more flexibility, we still use IDENTITY property for adding sequence values to tables, specifically when we need to introduce a surrogate key. However, if you need the same with Memory-Optimized tables, you need to know certain things.
Can I add the IDENTITY property to Memory-Optimized tables?
Yes, it is possible but it should be always IDENTITY(1,1). You cannot use a different values for seed and increment, they should be always set as 1.
CREATE TABLE dbo.MemoryOptimizedTable ( Id int IDENTITY(1,1) NOT NULL primary key nonclustered, CurrentDate datetime NULL default (getdate()) )WITH ( MEMORY_OPTIMIZED = ON , DURABILITY = SCHEMA_AND_DATA ) GO INSERT INTO dbo.MemoryOptimizedTable (CurrentDate) VALUES (DEFAULT); GO 5
Can I reset the IDENTITY seed using DBCC CHECKIDENT?
No, this is not supported. If you need to reset the IDENTITY seed, only way is inserting a new value explicitly by turning SET IDENTITY_INSERT on. As shown in the example, once the record with value 100 is inserted, the next value of the seed is set to 100+1.
SET IDENTITY_INSERT dbo.MemoryOptimizedTable ON GO INSERT INTO dbo.MemoryOptimizedTable (Id, CurrentDate) VALUES (100, DEFAULT); GO SET IDENTITY_INSERT dbo.MemoryOptimizedTable OFF GO INSERT INTO dbo.MemoryOptimizedTable (CurrentDate) VALUES (DEFAULT); GO SELECT * FROM dbo.MemoryOptimizedTable;
What if insert a lower value explicitly?
It is possible as long as it does not violate any rules. Look at the code below. It inserts a record with value 50 explicitly. But it does not mean that the seed is getting reset to 50+1. This does not happen because the last generated value is greater than 50+1. Therefore, the value of next record is 102, not 51.
SET IDENTITY_INSERT dbo.MemoryOptimizedTable ON GO INSERT INTO dbo.MemoryOptimizedTable (Id, CurrentDate) VALUES (50, DEFAULT); GO SET IDENTITY_INSERT dbo.MemoryOptimizedTable OFF GO INSERT INTO dbo.MemoryOptimizedTable (CurrentDate) VALUES (DEFAULT); GO SELECT * FROM dbo.MemoryOptimizedTable;
No comments:
Post a Comment