By: Koen Verbeeck | Updated: 2018-09-12 | Comments (20) | Related: 1 | 2 | 3 | 4 | > Temporal Tables
Problem
Temporal tables - not to be mistaken with temporary tables - were introduced as a new feature in SQL Server 2016. Temporal tables, also named system-versioned tables, allow SQL Server to automatically keep history of the data in the table. This tip will introduce you to this feature and will explain how to create a system-versioned table. A second part of the tip will dive deeper into querying temporal tables.
Solution
Temporal tables were introduced in the ANSI SQL 2011 standard and has been released as part of SQL Server 2016.
A system-versioned table allows you to query updated and deleted data, while a normal table can only return the current data. For example, if you update a column value from 5 to 10, you can only retrieve the value 10 in a normal table. A temporal table also allows you to retrieve the old value 5. This is accomplished by keeping a history table. This history table stores the old data together with a start and end data to indicate when the record was active.
These are the most common use cases for temporal tables:
- Audit. With temporal tables you can find out what values a specific entity has had over its entire lifetime.
- Slowly changing dimensions. A system-versioned table exactly behaves like a dimension with type 2 changing behavior for all of its columns.
- Repair record-level corruptions. Think of it as a sort of back-up mechanism on a single table. Accidentally deleted a record? Retrieve it from the history table and insert it back into the main table.
Temporal tables or system-versioned tables are an example of an assertion table, meaning that it captures the lifetime of a record based on the physical dates the record was removed or updated. Temporal tables currently do not support versioning, meaning the versioning of records based on logical dates. For example, suppose you have a table keeping product prices. If you update the price at 12PM using an UPDATE statement, the temporal table will keep the history of the old price until 12PM of that day. Starting from 12PM, the new price is valid. However, what if the price change was actually meant to start from 1PM (a logical change)? This means you have to time your update statement perfectly in order to make it work and you should have executed the UPDATE statement at 1PM instead of 12PM. The difference between assertion and version tables, and in more general uni- and bi-temporal tables is discussed in the article Conventional, Uni-Temporal and Bi-Temporal Tables.
Note that temporal tables are not a replacement for the change data capture (CDC) feature. CDC uses the transaction log to find the changes and typically those changes are kept for a short period of time (depending on your ETL timeframe). Temporal tables store the actual changes in the history table and they are intended to stay there for a much longer time.
Creating a system-versioned table
When you want to create a new temporal table, a couple of prerequisites must be met:
- A primary key must be defined
- Two columns must be defined to record the start and end date with a data type of datetime2. If needed, these columns can be hidden using the HIDDEN flag. These columns are called the SYSTEM_TIME period columns.
- INSTEAD OF triggers are not allowed. AFTER triggers are only allowed on the current table.
- In-memory OLTP cannot be used in SQL Server 2016. Later on, this limitation has been lifted. Check out the documentation for more information.
- By default, the history table is page compressed.
- ON DELETE/UPDATE CASCADE is not permitted on the current table. This limitation has also been lifted in SQL Server 2017.
There are also some limitations:
- Temporal and history table cannot be FILETABLE
- The history table cannot have any constraints
- INSERT and UPDATE statements cannot reference the SYSTEM_TIME period columns
- Data in the history table cannot be modified
For a full list of considerations and limitations, refer to the documentation page Temporal Table Considerations and Limitations.
The following script creates a simple system-versioned table:
CREATE TABLE dbo.TestTemporal (ID int primary key ,A int ,B int ,C AS A * B ,SysStartTime datetime2 GENERATED ALWAYS AS ROW START NOT NULL ,SysEndTime datetime2 GENERATED ALWAYS AS ROW END NOT NULL ,PERIOD FOR SYSTEM_TIME (SysStartTime,SysEndTime)) WITH(SYSTEM_VERSIONING = ON);
If you don't specify a name for the history table, SQL Server will automatically generate one of the following structure: dbo.MSSQL_TemporalHistoryFor_xxx, where xxx is the object id of the main table.
The result looks like this:
The history table has an identical set of columns, but with all constraints removed. It also has its own set of indexes and statistics. Creating your own indexes such as a clustered columnstore index on the history table can greatly improve performance.
Note it is also possible to enable system-versioning on an existing table. Either you already have an existing history table and you just include it in the ALTER TABLE statement, or you create one yourself. For example, if you have an existing type 2 dimension with all the history, you can create a new table with only the current values. This will become the current table and the dimension will become the history table. There is an optional clause DATA_CONSISTENCY_CHECK that allows you to perform a data consistency check to verify if time periods in the history do not overlap. For more information, take a look at ALTER TABLE.
Let's test the functionality of temporal table by inserting data into the table and then modify it.
-- Initial Load INSERT INTO dbo.TestTemporal(ID, A, B) VALUES (1,2,3) ,(2,4,5) ,(3,0,1); SELECT * FROM dbo.TestTemporal;
Now let's delete one row and update another.
-- Modify Data DELETE FROM dbo.TestTemporal WHERE ID = 2; UPDATE dbo.TestTemporal SET A = 5 WHERE ID = 3;
The main table displays the current state of the data:
Note that the SysEndTime column is not necessary, as it only displays the maximum datetime2 value.
The history displays the old versions of the different rows and they are properly dated.
Alter the schema of a system-versioned table
In SQL Server 2016, when system-versioning is enabled on a table, modifications on the table are severely limited. These were the allowed modifications:
- ALTER TABLE … REBUILD
- CREATE INDEX
- CREATE STATISTICS
All other schema modifications were disallowed. However, in SQL Server 2017 many limitations were removed. Check out Changing the Schema of a System-Versioned Temporal Table for more information. In SQL Server 2016 and 2017 it's still not possible to drop a temporal table while system-versioning is enabled.
But what when you to alter the schema of the table and the modification is not supported? In this case, system-versioning has to be disabled first:
ALTER TABLE dbo.TestTemporal SET (SYSTEM_VERSIONING = OFF);
This command will remove system_versioning and turn the main table and the history table into two regular tables.
Now you can do any modifications you like on both tables. Make sure they stay in sync and history is still consistent. After the modifications, you can turn system-versioning back on.
ALTER TABLE dbo.TestTemporal SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE=dbo.TestTemporal_History,DATA_CONSISTENCY_CHECK=[ON/OFF]) );
The ALTER TABLE documentation has an example on how to modify a temporal table. For an example on how to drop a temporal table, check out How to drop a Temporal Table.
Retention Policy
SQL Server 2017 introduced a new concept to temporal tables: a retention policy. Without any action, history will grow for a temporary tables. Over time, these history tables can grow to large sizes, especially if data is modified often. With retention policies, you can automatically control the growth of a temporal table. For more information, check out the tip Temporal history table retention in SQL Server 2017 and the documentation page Manage historical data in Temporal Tables with retention policy.
Conclusion
Temporal tables are an exciting feature introduced in SQL Server 2016 and expanded in SQL Server 2017. With temporal tables, SQL Server automatically tracks history for the data into a separate history table. Possible use cases are type 2 dimensions in data warehouses, auditing, protection against unwanted deletes and updates and any other example where versioning is required. In a second part of the tip we'll discuss how you can query the temporal table using the new FOR SYSTEM_TIME clause!
Next Steps
- Try it out yourself! Get your hands on a developer edition of SQL Server and create your own temporal tables.
- Be sure to check out the official documentation: Temporal Tables.
- The following tip gives an overview of all new features in SQL Server 2016 CTP2.
About the author
This author pledges the content of this article is based on professional experience and not AI generated.
View all my tips
Article Last Updated: 2018-09-12