SQL 2016 Temporal Tables.

Here is the situation for SQL DBA/Developer.

  1. A new startup company started with 5 employees, after an year no of employees grows to 100, subsequently 3-5 employees leaving in every month. Now DBA/Developer needs to get report of all employees those either worked OR currently working in organization. The other requirement is to get report to know all employees for those ‘first name’/’last name’ got change over the time.
  2. A product based company keep introducing new products and retires the old products from their list in regular interval. Now DBA needs to know the all products those were present in one specific old date.

All above situation can be done using complex front end code OR making lots of different tables for generating such reports. Now SQL 2016 comes up with new feature called “Temporal Table” that can help achieving above requirement with minimal code change. In this blog, I am going to show you how this can be done. Please note Temporal table in NOT same as Temporarily table.

Temporal Tables is “A system-versioned temporal table is designed to keep a full history of data changes and allow easy point in time analysis”

Here is list of prerequisite for temporal tables

  1. A primary key must be defined in the table.
  2. Two columns must be defined to record the start and end date with a data type of ‘datetime2’, these two columns can hide using ‘Hidden’ keyword.

Let’s now move to SQL 2016 LAB to see how this feature works.

USE [master]
CREATE DATABASE TemporalTableDemo
GO 

USE [TemporalTableDemo]
CREATE TABLE EmployeeData 
(
EMPID INT PRIMARY KEY,  ---Primary key is required
Firstname  VARCHAR(50),
LastName  VARCHAR(50),
City VARCHAR(50), 
/*Period columns needed for temporal tables*/
ValidFrom DATETIME2 GENERATED ALWAYS AS ROW START HIDDEN NOT NULL,
ValidTo DATETIME2 GENERATED ALWAYS AS ROW END HIDDEN NOT NULL,
PERIOD FOR SYSTEM_TIME (ValidFrom,ValidTo)
)
/*The system-versioning configuration needed for temporal If we don’t specify the history table then system will create automatically dbo.MSSQL_TemporalHistoryFor_XXX
*/
WITH (SYSTEM_VERSIONING = ON (History_Table=[dbo].EmployeeDataHistory)
GO

This is how Temporal table schema should look like.

TableStruture.jpg

Now let’s insert 8 rows.

USE [TemporalTableDemo]
INSERT INTO EmployeeData (EMPID, FIRSTNAME, LASTNAME, CITY) VALUES
              (1, 'Employee1', 'Lastname1', 'city1'), 
              (2, 'Employee2', 'Lastname2', 'city2'), 
              (3, 'Employee3', 'Lastname3', 'city3'),
              (4, 'Employee4', 'Lastname4', 'city4'),
              (5, 'Employee5', 'Lastname5', 'city5'), 
              (6, 'Employee6', 'Lastname6', 'city6'),
              (7, 'Employee7', 'Lastname7', 'city7'), 
              (8, 'Employee8', 'Lastname8', 'city8')
GO

Now let’s retrieve all the rows to confirm the records are inserted.

/*Select all employees data */
USE [TemporalTableDemo]
SELECT * FROM EmployeeData
GO 

/*Above select statement will not return all columns due to hidden keyword in table definition, however you can manually give columns.
*/
USE [TemporalTableDemo]
SELECT EMPID,Firstname, LastName, City, ValidFrom, ValidTo FROM EmployeeData
GO

Let assume few employees left over the time, new employees joined & some of employees details such as first name, last name OR city got changed.

USE [TemporalTableDemo]
DELETE FROM EmployeeData WHERE Firstname IN ('Employee1', 'Employee2')  
UPDATE EmployeeData SET LastName = 'ChangedLastName3' WHERE Firstname = 'Employee3'
UPDATE EmployeeData SET LastName = 'ChangedLastName4' WHERE Firstname = 'Employee4' 
INSERT INTO EmployeeData  (EMPID, FIRSTNAME, LASTNAME, CITY) VALUES
              (9, 'Employee9', 'LastName9', 'City9'), 
              (10, 'Employee10', 'LastName10','City10') 
GO

The reference of every update OR delete record is inserted in history table and DBA can query historical data to do point in time analysis.

Example 1 All current employees.

USE [TemporalTableDemo]
SELECT  EMPID, Firstname, LastName, City FROM EmployeeData
GO

Example 2 All current employees for whom details such as first name, last name OR city got changed over time.

USE [TemporalTableDemo]
SELECT  
EmployeeData.EMPID, EmployeeDataHistory.Firstname, EmployeeDataHistory.LastName, EmployeeDataHistory.City, EmployeeDataHistory.ValidTo as UpdatedON 
FROM EmployeeData
INNER JOIN EmployeeDataHistory on EmployeeDataHistory.EMPID=EmployeeData.EMPID
GO

Example 3 All Employees those left company.

USE [TemporalTableDemo]
SELECT  
EmployeeData.EMPID, EmployeeDataHistory.Firstname, EmployeeDataHistory.LastName, EmployeeDataHistory.City, EmployeeDataHistory.ValidTo as UpdatedON 
FROM EmployeeData
INNER JOIN EmployeeDataHistory on EmployeeDataHistory.EMPID=EmployeeData.EMPID
GO

Example 4 The temporal table can also be queried with a new clause ‘FOR SYSTEM TIME’ such as example below. More details

USE [TemporalTableDemo]
SELECT EMPID,Firstname, LastName, City FROM EmployeeData
FOR SYSTEM_TIME AS OF '2017-03-03 09:52:07.5372573'
--OR use between
--FOR SYSTEM_TIME BETWEEN '2017-03-03 09:52:07.5372573' AND
'2017-03-03 09:59:01.5704154'
GO

Limitation with temporal tables.

  1. Temporal and history table cannot be FILETABLE.
  2. The history table cannot have any constraints.
  3. INSERT and UPDATE statements cannot reference the SYSTEM_TIME period columns.
  4. Data in the history table cannot be modified.

Here is the example of power-shell script that generate HTML report for all above queries for better understanding.

#Script start,  
#Change FilePath & SQL server name 
$SQLServer='LABSQL'
$FilePath='C:\temp\CurrentEmployee.HTML'
$connectionString = "Data Source=$SQLServer;Integrated Security=true;Initial Catalog=TemporalTableDemo;"
$connection= New-Object System.Data.SqlClient.SqlConnection
$connection.ConnectionString = $connectionString
$connection.Open()
$query1= “SELECT  EMPID, Firstname, LastName, City FROM EmployeeData”
$query2= “SELECT  EmployeeData.EMPID,EmployeeDataHistory.Firstname, EmployeeDataHistory.LastName,
EmployeeDataHistory.City, EmployeeDataHistory.ValidTo as UpdatedON 
FROM EmployeeData INNER JOIN EmployeeDataHistory on EmployeeDataHistory.EMPID=EmployeeData.EMPID”
$query3= “SELECT EmployeeDataHistory.EMPID, EmployeeDataHistory.Firstname, EmployeeDataHistory.LastName, EmployeeDataHistory.City, EmployeeDataHistory.ValidTo as TerminatedOn 
FROM EmployeeDataHistory LEFT JOIN EmployeeData ON EmployeeData.EMPID = EmployeeDataHistory.EMPID
WHERE EmployeeData.EMPID IS NULL"
$command1= $connection.CreateCommand()
$command1.CommandText =$query1 
$result1= $command1.ExecuteReader()
$table1= new-object "System.Data.DataTable"
$table1.load($result1)
$command2= $connection.CreateCommand()
$command2.CommandText =$query2
$result2= $command2.ExecuteReader()
$table2= new-object "System.Data.DataTable"
$table2.load($result2)
$command3= $connection.CreateCommand()
$command3.CommandText =$query3
$result3= $command3.ExecuteReader()
$table3= new-object "System.Data.DataTable"
$table3.load($result3) 
$Header
= @"
<style>
TABLE {border-width:4px;border-style: solid;border-color: black;border-collapse: collapse;}
TH {border-width:1px;padding: 3px;border-style: solid;border-color: black;background-color:#FE642E;}
TD {border-width: 1px;padding:3px;border-style: solid;border-color: black;}
</style>
"@
$frag1= $table1| SELECT EMPID, Firstname, LastName, City | ConvertTo-HTML -PreContent '<H2> Details of current Employees</H2>' |Out-String
$frag2= $table2| SELECT EMPID, Firstname, LastName, City, UpdatedON |ConvertTo-HTML -PreContent '<H2> Updated Employees</H2>' |Out-String
$frag3= $table3| SELECT EMPID, Firstname, LastName, City, TerminatedOn |ConvertTo-HTML -PreContent '<H2> All Terminated Employees </H2>'|Out-String
ConvertTo-Html -Head $Header -PostContent $frag1,$frag2,$frag3 -PreContent '<h1>Employees Report<h1>' |Out-File $FilePath
$connection.Close()
#Script Ends, The output should look like below. 
HTML report.jpg
Advertisements

#pointintimeanalysis, #sql2016, #sqlaudit, #temporaltable

SQL 2016 Live Query Statistics

In my last post we learned how ‘Query Store’ works, now this is the time to show one other amazing feature called ‘Live Query Statistic’ that is also released with SQL 2016. Just to clarify this feature is included with SQL Management studio 2016 that means it will work if it connects to SQL version 2014.

Let’s now see how this feature can be beneficial for DBA/Consultant OR support engineers.

The steps of preparing LAB environment is same as steps mentioned in ‘Query store’ Blog.

/* Please note, the database and tables are design only for training purpose so it doesn't necessarily have the best design.*/
-- Create Database & two tables 'Region' and 'EmployeeData'
USE [master]
CREATE DATABASE QueryStoreDemo
GO

USE [QueryStoreDemo]
CREATE TABLE Region
       (
       ID INT IDENTITY(1,1),
       RNAME VARCHAR (100),
       HQ VARCHAR(100)
       )
GO

USE [QueryStoreDemo]
CREATE TABLE EmployeeCity
       (
       ID INT IDENTITY (1, 1),
       NAME VARCHAR (100),
       City VARCHAR(100), 
       RegionID INT
       )
GO

-- Insert values, the second insertion might take time (3-5 minutes) as we are inserting 6 rows 50K times. 
USE [QueryStoreDemo]
INSERT INTO Region  VALUES
       ('PUNE', 'SOUTH'),
       ('GOA', 'EAST'),
       ('NASHIK', 'WEST'),
       ('NASIK','NORTH'),
       ('SOLAPUR','Center')
GO

USE [QueryStoreDemo]
INSERT INTO EmployeeCity
VALUES
       ('Pradeep', 'Pune', 1),  
       ('Vikram', 'Mumbai', 2),
       ('Darshan', 'Goa', 3),
       ('AJAY', 'Nashik', 4),
       ('Yogesh', 'Solapur', 5)
GO 50000

Continue reading

#live-query-statistics, #query-plan, #sql, #sql2016

SQL 2016 Query Store

One of amazing new feature that came up with SQL 2016 release is ‘Query store’. This is going to be the game changer and most useful for SQL DBA, Support Engineers and consultant those used to rely on ‘plan cache’ (AKS ‘Procedure Cache’) to track down query statistics and execution plans for queries run in past. Plan cache is useful to know what got change after XYZ changes such as missing index, application upgrade…etc.

The biggest disadvantage with ‘planned cache’ is that it remain in memory and get flush out once SQL service restart (OR sever reboot). High memory pressure on SQL Instance also cause plan cache to flush out from memory.

Now with SQL 2016, if ‘Query store’ is enabled, execution plans are saved on disk and can be accessed even if server is rebooted. This new feature is enabled on an individual database with minimum configuration change. The saved execution plan can be accessed using GUI reports OR built in DMV queries.

Continue reading

#plancache, #query-performance, #querystore, #sql

SQL 2016 on Linux OS

Since SQL version 2016, customer can decide platform other than windows OS. SQL 2016 can be installed and configured on Linux OS and it’s completely supported. In my opinion the decision of allowing Linux platform is to compete with open source database engine such as MySQL, PostgreSQL and ORACLE those provide similar capabilities. The licensing & editions are still not clear but the platform provide most of features a DBA will look for.

Supported Linux Operating System

Red Hat Enterprise Linux 7.3 Workstation, Server, and Desktop
SUSE Enterprise Linux Server v12 SP2
Ubuntu 16.04LTS and 16.10
Docker Engine 1.8+ on Windows, Mac, or Linux
Operating system should minimum 3.25 GB of RAM and it’s tested up to 1 TB.

UN-Supported Features

Replication/mirroring
Poly-base, stretched DB
System extended stored procedures (XP_CMDShell, etc.)
Windows/AD authentication
User certificate SSL/TLS
Agent service / Brower / Reporting service
More Details

Installation demo of SQL on Ubuntu 16.04 Server

Configure prerequisite

Step 1 Download Ubuntu server ISO

Step 2 Create a new Linux OS in your virtual environment. You should have atleast 4 GB RAM &  20 GB disk space (Recommend  Test environment). Supply ‘User Name’ & ‘Password’ that will be used to login in terminal (command prompt of Linux), start the installation.

Step 3. Installation will continue without any user intervention.

Step 4. Once installed successfully, supply user name / password (Refer Step 2) to login in terminal.

Step 5. Get yourself familiarize with Linux Ubuntu commands.
Get the OS details.
IP address of machine
Hostname of machine
Check connectivity with internet using ‘ping’

lsb_release –a
ifconfig
hostname
ping help.ubuntu.com

If you wish to change IP address then refer

Step 6. Install the Open SSH client applications on Ubuntu server so  you will be able to take terminal access remotely using putty  and it will help to insert commands easily.

sudo apt-get install openssh-server openssh-client

 

(All above steps are shown in following slide show)

This slideshow requires JavaScript.

Installation & configuration of SQL Server

Step 1 Ensure your system is fully updated before installing SQL.

sudo apt-get update

Step 2. Install curl (curl is a tool to transfer data from OR to a server using supported protocol (http,imap, ldap…etc)

sudo su
sudo apt-get install curl

STEP 3 Add ‘SQL Server’ information to the repository on ‘/etc/apt/sources.list.d/’

curl https://packages.microsoft.com/config/ubuntu/16.04/mssql-server.list >/etc/apt/sources.list.d/mssql-server.list
curl https://packages.microsoft.com/keys/microsoft.asc | apt-key add

STEP 4 Install SQL server.

sudo apt-get install mssql-server

STEP 5 Run the configuration script to accept the license agreement and provide the System Administrator (SA) password.

sudo /opt/mssql/bin/mssql-conf setup

STEP 6 SQL service will be enable/start by default. If it does not then enable and start the service. Also verify if SQL is listening on port 1433

sudo systemctl enable mssql-server
sudo systemctl start mssql-server
sudo netstat -peant | grep ":1433"

STEP 7 The SQL server is ready, DBA now can access SQL server using ADO.NET client OR SQL Management Studio installed on Windows machine for Admin purpose.

(All above steps are shown in following slide show)

This slideshow requires JavaScript.

Installation of SQL Server command-line tools (SQLCMD)

Step1 Download SQLCMD tool and ODBC Drivers..

curl https://packages.microsoft.com/config/ubuntu/16.04/prod.list>/etc/apt/sources.list.d/ms-prod.list
sudo apt-get update

Step 2 Install SQLCMD tool and ODBC Drivers.

sudo apt-get install mssql-tools

Accept license agreement.
Step 3 Create symlink for SQLCMD and

ln -sfn /opt/mssql-tools/bin/sqlcmd /usr/bin/sqlcmd

Step 4 Connect SQL server using SQLCMD then create database, table & inserts few rows.

sqlcmd -S 192.168.132.132 -U SA -P Password123#

Use [master]
create database LinuxDBTest
go
use LinuxDBTest
create table t1 (c1 int, c2 varchar(100))
go
insert into t1 values (1, 'pradeep')
go
select * from t1

Step 5 Verify DB, Tables & row using SSMS.

This slideshow requires JavaScript.

#linux, #sqlonlinux