This is the third article in the series of articles on the Temporal Tables, below is the complete list of articles on System-Versioned Temporal Tables. This article explains how we can enable system versioning on an existing regular table and link it to a new or existing table as history table.
Let us first create demo database by using the following script
IF DB_ID('SqlhintsTemporalDemoDB') IS NULL
BEGIN
CREATE DATABASE SqlhintsTemporalDemoDB
END
GO
USE SqlhintsTemporalDemoDB
GO
Enabling System-Versioning for an existing regular table and linking it to a new history table
Let us first create a regular Product table with Sample data by executing the following script:
CREATE TABLE dbo.product
(
Id INT NOT NULL PRIMARY KEY CLUSTERED,
Name NVARCHAR(100) NOT NULL
)
GO
INSERT INTO dbo.Product VALUES( 1, 'Television')
GO
Now try to enable the system versioning by executing the below statement:
ALTER TABLE dbo.Product
SET (SYSTEM_VERSIONING = ON)
RESULT
Msg 13510, Level 16, State 1, Line 1
Cannot set SYSTEM_VERSIONING to ON when SYSTEM_TIME period is not defined.
From the result it is clear that to enable system-versioning the table needs to have two period DATETIME2 columns with period definition in it.
Let’s try to add the two datetime2 datatype period columns and the period definition by the following script
ALTER TABLE dbo.Product
ADD StartTime DATETIME2 GENERATED ALWAYS AS ROW START
HIDDEN NULL,
EndTime DATETIME2 GENERATED ALWAYS AS ROW END
HIDDEN NULL,
PERIOD FOR SYSTEM_TIME (StartTime, EndTime)
RESULT
Msg 13587, Level 16, State 1, Line 1
Period column ‘StartTime’ in a system-versioned temporal table cannot be nullable.
From the result it is clear that the period columns shouldn’t be nullable column.
Now try to execute the below statement to add two datetime2 type NOT NULL period columns (if null constraint is not specified for period columns they are considered as NOT NULL) and the period definition:
ALTER TABLE dbo.Product
ADD StartTime DATETIME2 GENERATED ALWAYS AS ROW START HIDDEN,
EndTime DATETIME2 GENERATED ALWAYS AS ROW END HIDDEN,
PERIOD FOR SYSTEM_TIME (StartTime, EndTime)
RESULT
Msg 4901, Level 16, State 1, Line 1
ALTER TABLE only allows columns to be added that can contain nulls, or have a DEFAULT definition specified, or the column being added is an identity or timestamp column, or alternatively if none of the previous conditions are satisfied the table must be empty to allow addition of this column. Column ‘StartTime’ cannot be added to non-empty table ‘Product’ because it does not satisfy these conditions.
From the result it is clear that we are not allowed to add NOT NULL columns to an existing table with data in it.
Let us now try to add NOT NULL PERIOD columns to the existing table with DEFAULT value by executing the following statement:
ALTER TABLE dbo.Product
ADD StartTime DATETIME2 GENERATED ALWAYS AS ROW START
HIDDEN DEFAULT GETUTCDATE(),
EndTime DATETIME2 GENERATED ALWAYS AS ROW END
HIDDEN DEFAULT
CONVERT(DATETIME2, '9999-12-31 23:59:59.9999999'),
PERIOD FOR SYSTEM_TIME (StartTime, EndTime)
We have successfully added the PERIOD columns and PERIOD definition to the Product table, now enable the system versioning by executing the below statement. Here we are mentioning the new history table name as dbo.ProductHistoy. Specifying History table name is optional, if we don’t specify the history table name then Sql Server creates a new history table with name like MSSQL_TemporalHistoryFor
ALTER TABLE dbo.Product
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory))
GO
After executing the above statement, if we look into the SSMS window we can see that a dbo.Product table is marked as System-Versioned table. Inside this table we can see a new nested table dbo.ProductHistory table created and marked as History Table as shown below.
SUMMARY
Below is the script for enabling System-Versioning for an existing regular table and linking it to a new history table
BEGIN TRAN
--Add two PERIOD datetime2 columns and PERIOD definition
ALTER TABLE dbo.Product
ADD StartTime DATETIME2 GENERATED ALWAYS AS ROW START
HIDDEN NOT NULL DEFAULT GETUTCDATE(),
EndTime DATETIME2 GENERATED ALWAYS AS ROW END
HIDDEN NOT NULL DEFAULT
CONVERT(DATETIME2, '9999-12-31 23:59:59.9999999'),
PERIOD FOR SYSTEM_TIME (StartTime, EndTime)
--Enable System Versioning
ALTER TABLE dbo.Product
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory))
COMMIT TRAN
CLEAN-UP
Let us drop the Product and ProductHistory tables by the following script
--Disable the system versioning
ALTER TABLE dbo.Product
SET (SYSTEM_VERSIONING = OFF)
GO
--Drop Period definition
ALTER TABLE dbo.Product
DROP PERIOD FOR SYSTEM_TIME
GO
--Now drop Product and ProductHistory tables
DROP TABLE dbo.Product
DROP TABLE dbo.ProductHistory
Enabling System-Versioning for an existing regular table and linking it to an existing history table
Let us create a regular Product and ProductHistory table by using the following script:
---Create a regular Product table
CREATE TABLE [dbo].[Product](
[ProductId] [int] NOT NULL PRIMARY KEY CLUSTERED ,
[Name] [nvarchar](100) NOT NULL,
[StartTime] DATETIME NOT NULL,
[EndTime] DATETIME NOT NULL,
[Price] [float] NULL
)
GO
---Create a regular ProductHistory table
CREATE TABLE [dbo].[ProductHistory](
[ProductHistoryId] [int] IDENTITY(1,1) NOT NULL ,
[ProductId] [int] NOT NULL,
[Name] [nvarchar](100) NOT NULL,
[StartTime] DATETIME NOT NULL,
[EndTime] DATETIME NOT NULL,
CONSTRAINT [PK_ProductHistory]
PRIMARY KEY CLUSTERED ([ProductHistoryId]),
CONSTRAINT FK_ProductHistory_Product
FOREIGN KEY ([ProductId])
REFERENCES Product([ProductId])
) ON [PRIMARY]
GO
Let us execute the following statement to enable System-Versioning for the Product table and link it to an existing table ProductHistory as the history table
ALTER TABLE [dbo].[Product]
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory) )
GO
RESULT
Msg 13510, Level 16, State 1, Line 23
Cannot set SYSTEM_VERSIONING to ON when SYSTEM_TIME period is not defined.
From the result it is clear that to enable system-versioning table needs to have PERIOD definition
Let us try to add PERIOD definition to the table by using the following script
ALTER TABLE dbo.Product
ADD PERIOD FOR SYSTEM_TIME (StartTime, EndTime)
RESULT
Msg 13501, Level 16, State 3, Line 31
Temporal generated always column ‘StartTime’ has invalid data type.
From the result it is clear that PERIOD column has invalid data type
Let us change the data type of the PERIOD columns to DATETIME2 type and then add the PERIOD definition
--Alter StartTime Column type to DATETIME2
ALTER TABLE dbo.Product
ALTER COLUMN [StartTime] DATETIME2 NOT NULL
--Alter EndTime Column type to DATETIME2
ALTER TABLE dbo.Product
ALTER COLUMN [EndTime] DATETIME2 NOT NULL
GO
--Add the period definition
ALTER TABLE dbo.Product
ADD PERIOD FOR SYSTEM_TIME (StartTime, EndTime)
Now try to enable System-Versioning
ALTER TABLE [dbo].[Product]
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory) )
RESULT
Msg 13515, Level 16, State 1, Line 55
Setting SYSTEM_VERSIONING to ON failed because history table ‘SqlhintsTemporalDemoDB.dbo.ProductHistory’ has custom unique keys defined. Consider dropping all unique keys and trying again.
From the error it is clear that System-Versioning can’t be enabled when we primary key on the history table.
Let us drop the primary key from ProductHistoryId column by the following script
ALTER TABLE ProductHistory
DROP CONSTRAINT [PK_ProductHistory]
Now try to enable System-Versioning
ALTER TABLE [dbo].[Product]
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory) )
RESULT
Msg 13516, Level 16, State 1, Line 67
Setting SYSTEM_VERSIONING to ON failed because history table ‘SqlhintsTemporalDemoDB.dbo.ProductHistory’ has foreign keys defined. Consider dropping all foreign keys and trying again.
From the above error it is clear that we can’t enable SYSTEM_VERSIONING when history table has foreign key constraints
Let us drop the foreign key constraint using the following script
ALTER TABLE ProductHistory
DROP CONSTRAINT FK_ProductHistory_Product
Now try to enable System-Versioning
ALTER TABLE [dbo].[Product]
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory) )
RESULT
Msg 13518, Level 16, State 1, Line 83
Setting SYSTEM_VERSIONING to ON failed because history table ‘SqlhintsTemporalDemoDB.dbo.ProductHistory’ has IDENTITY column specification. Consider dropping all IDENTITY column specifications and trying again.
From the error it is clear that we can’t enable system-versioning when the history table has identity columns in it
Let us drop the identity coluimn [ProductHistoryId] from the ProductHistory table using the following script
ALTER TABLE [dbo].[ProductHistory]
DROP COLUMN [ProductHistoryId]
Now try to enable System-Versioning
ALTER TABLE [dbo].[Product]
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory) )
RESULT
Msg 13523, Level 16, State 1, Line 99
Setting SYSTEM_VERSIONING to ON failed because table ‘SqlhintsTemporalDemoDB.dbo.Product’ has 5 columns and table ‘SqlhintsTemporalDemoDB.dbo.ProductHistory’ has 4 columns.
From the above error it is clear that to enable system versioning the number columns in the Temporal and the history tables should be same.
Let us add price column to the ProductHistory table too
ALTER TABLE [dbo].[ProductHistory]
ADD [Price] [Float]
Now try to enable System-Versioning
ALTER TABLE [dbo].[Product]
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory) )
RESULT
Msg 13525, Level 16, State 1, Line 115
Setting SYSTEM_VERSIONING to ON failed because column ‘StartTime’ has data type datetime in history table ‘SqlhintsTemporalDemoDB.dbo.ProductHistory’ which is different from corresponding column type datetime2(7) in table ‘SqlhintsTemporalDemoDB.dbo.Product’.
From the error it is clear that even the column data types should match in order to enable system versioning
Let us match ProductHistory tables all the columns data types with the corresponding columns in the Product table
--Alter StartTime Column type to DATETIME2
ALTER TABLE dbo.ProductHistory
ALTER COLUMN [StartTime] DATETIME2 NOT NULL
--Alter EndTime Column type to DATETIME2
ALTER TABLE dbo.ProductHistory
ALTER COLUMN [EndTime] DATETIME2 NOT NULL
GO
Now try to enable System-Versioning
ALTER TABLE [dbo].[Product]
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory) )
After executing the above statement, if we look into the SSMS window we can see that a dbo.Product table is marked as System-Versioned table. And dbo.ProductHistory table is nested in the dbo.Product table and marked as History Table as shown below.
SUMMARY
In summary following are the some of the major list of rules needs to be satified by the existing history table in order for it to be linked by the Temporal table as the history table
- History Table shouldn’t have Primary Key Constraint
- History Table shouldn’t have any Foreign key coinstraints
- History table shouldn’t have any identity column
- Number of columns in the history table should be same as that of the parent table
- The columns Ordinal position in the history table should match with the column in the parent table
- Data type of all the columns in the history tables should match with the columns in the parent table
- No Triggers/CDC/Change Tracking defined on the History table
Below is the script for enabling System-Versioning for an existing regular table (i.e. dbo.Product) linking it to an existing history table (i.e. dbo.ProductHistory )
BEGIN TRAN
--Add two PERIOD datetime2 columns and PERIOD definition
ALTER TABLE dbo.Product
ADD StartTime DATETIME2 GENERATED ALWAYS AS ROW START
HIDDEN NOT NULL DEFAULT GETUTCDATE(),
EndTime DATETIME2 GENERATED ALWAYS AS ROW END HIDDEN NOT NULL
DEFAULT CONVERT(DATETIME2,'9999-12-31 23:59:59.9999999'),
PERIOD FOR SYSTEM_TIME (StartTime, EndTime)
--Enable System Versioning
ALTER TABLE dbo.Product
SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.ProductHistory))
COMMIT TRAN
CLEAN-UP
Let us drop the Product and ProductHistory tables by the following script
--Disable the system versioning
ALTER TABLE dbo.Product
SET (SYSTEM_VERSIONING = OFF)
GO
--Drop Period definition
ALTER TABLE dbo.Product
DROP PERIOD FOR SYSTEM_TIME
GO
--Now drop Product and ProductHistory tables
DROP TABLE dbo.Product
DROP TABLE dbo.ProductHistory
[ALSO READ] New features in Sql Server 2016: