Time Traveling with Temporal Tables on SQL Server 2016

  • Comments posted to this topic are about the item Time Traveling with Temporal Tables on SQL Server 2016

  • Great article. I hadn't really thought about the practical uses for this new feature beyond some sort of audit trail. This has opened my eyes to the possibilities.

    Cheers 🙂


    I'm on LinkedIn

  • this is great info. thanks so much.

    one question though.

    when you ALTER an existing table and ADD the needed datetime2 columns and then ALTER it again to SET SYSTEM_VERSION = ON, will that create a new table in the database appended with the word HISTORY?

    thanks!

  • Geoff A (10/18/2016)


    this is great info. thanks so much.

    one question though.

    when you ALTER an existing table and ADD the needed datetime2 columns and then ALTER it again to SET SYSTEM_VERSION = ON, will that create a new table in the database appended with the word HISTORY?

    thanks!

    Hi Geoff,

    When you alter an existing table to SET SYSTEM_VERSIONING = ON, it will automatically create a history table if needed (or reuse an existing history table).

    You can specify the name of the history table by the option HISTORY_TABLE = "", like in my CREATE TABLE example. If you don't specify the name of the history table, it will be something like MSSQL_TemporalHistoryFor_<objectid>. Probably you want to specify your own name instead.

    Best Regards

    Johan

  • Hi,

    great post!

    Finally SQL Server can handle History data.

    Is there any chance that the user that caused the change is also kept in the history file?

    Regards,

    Nico

  • nicoboey (10/18/2016)


    Hi,

    great post!

    Finally SQL Server can handle History data.

    Is there any chance that the user that caused the change is also kept in the history file?

    Regards,

    Nico

    Hi Nico,

    No - there is no such information stored. You will have to add it from your application.

    Best Regards

    Johan

  • It is possible to add a new column, to modify a column and drop a column, while system_versioning is ON!!!

    USE master;

    GO

    DROP DATABASE IF EXISTS TemporalDB;

    GO

    CREATE DATABASE TemporalDB;

    GO

    USE TemporalDB;

    GO

    CREATE TABLE dbo.Person

    (

    Personid INT NOT NULL IDENTITY PRIMARY KEY,

    Firstname VARCHAR(20) NOT NULL,

    Lastname VARCHAR(20) NULL,

    Adress VARCHAR(30) NOT NULL,

    Zipcode SMALLINT NOT NULL,

    SysStartTime DATETIME2(0) GENERATED ALWAYS AS ROW START NOT NULL,

    SysEndTime DATETIME2(0) GENERATED ALWAYS AS ROW END NOT NULL,

    PERIOD FOR SYSTEM_TIME (SysStartTime,SysEndTime)

    )

    WITH (SYSTEM_VERSIONING = ON (HISTORY_TABLE = dbo.PersonHistory));

    GO

    ALTER TABLE dbo.Person

    ADD Tlfno VARCHAR(8) NULL;

    GO

    SELECT *

    FROM sys.columns

    WHERE object_id IN(OBJECT_ID('dbo.Person'), OBJECT_ID('dbo.PersonHistory'))

    ORDER BY object_id;

    GO

    ALTER TABLE dbo.Person

    ALTER COLUMN Tlfno CHAR(10) NULL;

    GO

    SELECT *

    FROM sys.columns

    WHERE object_id IN(OBJECT_ID('dbo.Person'), OBJECT_ID('dbo.PersonHistory'))

    ORDER BY object_id;

    GO

    ALTER TABLE dbo.Person

    DROP COLUMN Tlfno;

    GO

    SELECT *

    FROM sys.columns

    WHERE object_id IN(OBJECT_ID('dbo.Person'), OBJECT_ID('dbo.PersonHistory'))

    ORDER BY object_id;

  • csj (10/20/2016)


    It is possible to add a new column, to modify a column and drop a column, while system_versioning is ON!!!

    USE master;

    GO

    DROP DATABASE IF EXISTS TemporalDB;

    GO

    CREATE DATABASE TemporalDB;

    GO

    USE TemporalDB;

    GO

    CREATE TABLE dbo.Person

    (

    Personid INT NOT NULL IDENTITY PRIMARY KEY,

    Firstname VARCHAR(20) NOT NULL,

    Lastname VARCHAR(20) NULL,

    Adress VARCHAR(30) NOT NULL,

    Zipcode SMALLINT NOT NULL,

    SysStartTime DATETIME2(0) GENERATED ALWAYS AS ROW START NOT NULL,

    SysEndTime DATETIME2(0) GENERATED ALWAYS AS ROW END NOT NULL,

    PERIOD FOR SYSTEM_TIME (SysStartTime,SysEndTime)

    )

    WITH (SYSTEM_VERSIONING = ON (HISTORY_TABLE = dbo.PersonHistory));

    GO

    ALTER TABLE dbo.Person

    ADD Tlfno VARCHAR(8) NULL;

    GO

    SELECT *

    FROM sys.columns

    WHERE object_id IN(OBJECT_ID('dbo.Person'), OBJECT_ID('dbo.PersonHistory'))

    ORDER BY object_id;

    GO

    ALTER TABLE dbo.Person

    ALTER COLUMN Tlfno CHAR(10) NULL;

    GO

    SELECT *

    FROM sys.columns

    WHERE object_id IN(OBJECT_ID('dbo.Person'), OBJECT_ID('dbo.PersonHistory'))

    ORDER BY object_id;

    GO

    ALTER TABLE dbo.Person

    DROP COLUMN Tlfno;

    GO

    SELECT *

    FROM sys.columns

    WHERE object_id IN(OBJECT_ID('dbo.Person'), OBJECT_ID('dbo.PersonHistory'))

    ORDER BY object_id;

    Hi Csj,

    Thanks very much for pointing this out. It has obviously changed since I did my research and testing on Temporal Tables. I will update the article!

    Best Regards!

    Johan

  • Great idea, thanks.

  • Thanks for the article, Johan!

    It's good to know what's out there even though in many cases you can't really apply it in your workplace.

    In regards to history clean-up, I'm surprised there isn't a standard option to set it up when creating a temporal table. Something like KEEP FOR n DAY/WEEK/MONTH.

  • csj (10/20/2016)


    It is possible to add a new column, to modify a column and drop a column, while system_versioning is ON!!!

    What happens to the historical data in the column when it's dropped from the main table?

    _____________
    Code for TallyGenerator

  • Yev.d (10/20/2016)


    Thanks for the article, Johan!

    It's good to know what's out there even though in many cases you can't really apply it in your workplace.

    In regards to history clean-up, I'm surprised there isn't a standard option to set it up when creating a temporal table. Something like KEEP FOR n DAY/WEEK/MONTH.

    Yes, a standard solution for cleaning up history would be nice!

    Best Regards!

    Johan

  • Sergiy (10/20/2016)


    csj (10/20/2016)


    It is possible to add a new column, to modify a column and drop a column, while system_versioning is ON!!!

    What happens to the historical data in the column when it's dropped from the main table?

    The column is dropped from the history table, so you will loose any history for it.

    Best Regards

    Johan

  • Hi,

    when you drop a column, the column is also droped in the history table. So you must save the columns data from the history table in another table before you drop the column.

    if you add a column and the new column has a default, the default is also used on the history table. if you want different defaults, you should remove system_version, add the columns to the two tables with difeerent defaults and then enable system_version again.

    The two tables should always have the exact same schema - names, datatypes, nullability, columns in the same order and the same number of columns. The only difference is, when working with computed columns - the column is only computed in the actual table and is a 'normal' persisted column in the history table.

    Best regards

    Carsten

  • csj (10/21/2016)


    Hi,

    when you drop a column, the column is also droped in the history table. So you must save the columns data from the history table in another table before you drop the column.

    if you add a column and the new column has a default, the default is also used on the history table. if you want different defaults, you should remove system_version, add the columns to the two tables with difeerent defaults and then enable system_version again.

    The two tables should always have the exact same schema - names, datatypes, nullability, columns in the same order and the same number of columns. The only difference is, when working with computed columns - the column is only computed in the actual table and is a 'normal' persisted column in the history table.

    Best regards

    Carsten

    That could be a workaround for having a userid in the history file: add a calculated field that returns the current user, and it will be persisted in th history table.

Viewing 15 posts - 1 through 15 (of 25 total)

You must be logged in to reply to this topic. Login to reply