In previous post, we saw how to create Temporal tables or enable System Versioning on an existing table
In this post, we will review how to access History data
Using below code, we will create simple Temporal table and inserted 5 records and querying both the Main and History table
CREATE TABLE dbo.Demo ( DemoID int NOT NULL PRIMARY KEY CLUSTERED IDENTITY , DemoName varchar(50) NOT NULL , 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 (HISTORY_TABLE = dbo.DemoHistory)) ; INSERT INTO dbo.Demo (DemoName) VALUES ('Demo1') INSERT INTO dbo.Demo (DemoName) VALUES ('Demo2') INSERT INTO dbo.Demo (DemoName) VALUES ('Demo3') INSERT INTO dbo.Demo (DemoName) VALUES ('Demo4') INSERT INTO dbo.Demo (DemoName) VALUES ('Demo5') SELECT DemoID, DemoName, SysStartTime, SysEndTime FROM dbo.Demo SELECT DemoID, DemoName, SysStartTime, SysEndTime FROM dbo.DemoHistory
Output: Main table has 5 rows and and History has no data, because no changes were made yet to the data, Also if you notice the SysEndTime, all of them are set to 12/31/9999 23:59:59.9999999, which refer to them as current record
Let us modify some data in 2 minute intervals
First Change – Update 1 row and delete 1 row
UPDATE dbo.Demo SET DemoName='Demo11' WHERE DemoID=1 DELETE FROM dbo.Demo WHERE DemoID=4
Output: Now we can see that Main table has 4 rows and History has 2 rows , the green highlighted is the record we updated as you can history table contains the previous version of record and also SysEndTime in History table indicates when it was updated
Similarly Red highlighted record in history is the deleted with Deleted time
Second Update: Update 1 record and Delete 1 record
UPDATE dbo.Demo SET DemoName='Demo12' WHERE DemoID=2 DELETE FROM dbo.Demo WHERE DemoID=3
Output:
Let us now review how we can access the History data
Method 1: AS OF
We can use FOR SYSTEM_TIME AS OF to get records in Demo as of the specific time, This will be helpful for scenarios when you want to see How much Inventory was in hand as of a particular date and time or What products were in hand as of particular date and time
In below example we are using 3 different time with 2 minute intervals
SELECT DemoID, DemoName, SysStartTime, SysEndTime FROM dbo.Demo FOR SYSTEM_TIME AS OF '2017-10-20 14:42:34' ORDER BY DemoID SELECT DemoID, DemoName, SysStartTime, SysEndTime FROM dbo.Demo FOR SYSTEM_TIME AS OF '2017-10-20 14:44:34' ORDER BY DemoID SELECT DemoID, DemoName, SysStartTime, SysEndTime FROM dbo.Demo FOR SYSTEM_TIME AS OF '2017-10-20 14:46:34' ORDER BY DemoID
Output: As we can see in first output we are able to see all records as how it was inserted and in 2nd put, we can see 1st record was updated and Demo ID 4 record is missing and in output 3 23 can seem Demo ID 1 and 2 are updated and 3 and 4 are deleted
Method 2: FROM…TO and BETWEEN…AND option
We can use FROM…TO and BETWEEN…AND option to get records changed between 2 specified date times
SELECT DemoID, DemoName, SysStartTime, SysEndTime FROM dbo.Demo FOR SYSTEM_TIME FROM '2017-10-20 14:42:33' TO '2017-10-20 14:46:55' ORDER BY DemoID, SysStartTime SELECT DemoID, DemoName, SysStartTime, SysEndTime FROM dbo.Demo FOR SYSTEM_TIME BETWEEN '2017-10-20 14:42:33' AND '2017-10-20 14:46:55' ORDER BY DemoID, SysStartTime
Output: In below output you can see all changes made between the specified time intervals, but if you notice it, its providing us both version of the records, so based on your application need, you will need to use this or else, it might provide more records for display than you need
Method 3: CONTAINED IN
When we use CONTAINED IN option, it provides data from history table only for the specified datetime(s)
SELECT DemoID, DemoName, SysStartTime, SysEndTime FROM dbo.Demo FOR SYSTEM_TIME CONTAINED IN ('2017-10-20 14:42:33', '2017-10-20 14:45:56') ORDER BY DemoID, SysStartTime
Output: As we can see the below output doesn’t contain the current version of record or other records from Main table
Method 4: ALL
When we use ALL option, it provides data from both Main and History table for all the changes made so far
SELECT DemoID, DemoName, SysStartTime, SysEndTime FROM dbo.Demo FOR SYSTEM_TIME ALL ORDER BY DemoID, SysStartTime
Output
We can see all records from main and history table combined, Please be cautious using this option when running without Filter criteria for larger tables
We can create Views using Temporal Tables and those views supports these clauses as well
Hope you find this post helpful !!!
3 thoughts on “Temporal Tables–Simple Guide to implement History Tables using SQL Server 2016/2017–Part 2–Accessing History data”