Feeds:
Posts
Comments

Archive for the ‘Backup & Restore’ Category

In SQL Server 2022, a new column namely last_valid_restore_time has been added to the table backupset as a part of the enhancements. It contains the information regarding the last valid restore time, and it became very handy when something happens to your database and you need to restore data from the backup and you want to know the exact last valid restore time. Actually, it is the time when you post your last transaction in your database before taking backup. By the way, last transaction can be way before you take your backup.

One important point is that it shows the last_valid_restore_time in Transaction Log Backup ONLY. In Full Backup & differential back, it returns NULL value and which makes sense.

Let me create a sample database, a table and insert a record to demonstrate the behaviour of last_valid_restore_time as shown below.

Sample:

USE master
GO
  
CREATE DATABASE TESTDB;
GO
  
USE TESTDB
GO
  
CREATE TABLE Customers
(
 CustomerID   INT IDENTITY,
 CustomerName VARCHAR(100),
 CreatedAt    DATETIME,
 ModifiedAt   DATETIME
);
GO
  
INSERT INTO Customers(CustomerName, CreatedAt)
VALUES('Customer-1', GETDATE());
GO
 
SELECT * FROM Customers;
GO
--OUTPUT

Step 1: Full Backup

In this step, we will take full backup of the database.

--Taking full backup
BACKUP DATABASE TESTDB 
TO DISK ='D:\Backup\TESTDBfullbackup.BAK';
GO 
--OUTPUT

Step 2: Differential Backup

In this step, first we will insert a new record then will take differential backup.

USE TESTDB
GO

INSERT INTO Customers(CustomerName, CreatedAt)
VALUES('Customer-2', GETDATE());
GO
   
--Taking differential backup
BACKUP DATABASE TESTDB 
TO DISK ='D:\Backup\TESTDBdifferentialbackup.BAK'
WITH DIFFERENTIAL;
GO

SELECT * FROM Customers;
GO
--OUTPUT

Step 3: Log backup

In this step, we will insert and update few records and then take log backup.

USE TESTDB
GO
 
INSERT INTO Customers(CustomerName, CreatedAt)
VALUES('Customer-3', GETDATE());
GO
 
UPDATE Customers
SET    CustomerName = 'Customer22'
     , ModifiedAt   =  GETDATE()
FROM   Customers 
WHERE  CustomerID = 2;
GO
   
--Taking log backup
BACKUP LOG TESTDB 
TO DISK ='D:\Backup\TESTDBlogbackup1.TRN' ;
GO
 
SELECT * FROM Customers;
GO
--OUTPUT

Step 4: Last Valid Restore Time

Now, we have successfully created the sample along with backups. Let me run the query and add this new column namely last_valid_restore_time as shown below. As we can see, the last_valid_restore_time & the last record modified date & time is same which is 2022-12-03 18:37:18.

SELECT bs.database_name, backuptype = CASE
        WHEN bs.type = 'D' AND bs.is_copy_only = 0 THEN 'Full Database'
        WHEN bs.type = 'D' AND bs.is_copy_only = 1 THEN 'Full Copy-Only Database'
        WHEN bs.type = 'I' THEN 'Differential database backup'
        WHEN bs.type = 'L' THEN 'Transaction Log'
        WHEN bs.type = 'F' THEN 'File or filegroup'
        WHEN bs.type = 'G' THEN 'Differential file'
        WHEN bs.type = 'P' THEN 'Partial'
        WHEN bs.type = 'Q' THEN 'Differential partial'
        when bs.type = 'i' THEN 'last valid restore value' END + ' Backup',
    CASE bf.device_type
        WHEN 2 THEN 'Disk' WHEN 5 THEN 'Tape' WHEN 7 THEN 'Virtual device'
        WHEN 9 THEN 'Azure Storage' WHEN 105 THEN 'A permanent backup device'
        ELSE 'Other Device' END AS DeviceType,
    bms.software_name AS backup_software,
    /**New column addition in SQL Server 2022**/
    bs.last_valid_restore_time,
    /**************************************/
    BackupStartDate = bs.Backup_Start_Date,
    BackupFinishDate = bs.Backup_Finish_Date,
    LatestBackupLocation = bf.physical_device_name,
    backup_size_mb = CONVERT(DECIMAL(10, 2), bs.backup_size / 1024. / 1024.),
    compressed_backup_size_mb = CONVERT(DECIMAL(10, 2), bs.compressed_backup_size / 1024. / 1024.),
    database_backup_lsn, -- For tlog and differential backups, this is the checkpoint_lsn of the FULL backup it is based on.
    checkpoint_lsn,
    begins_log_chain,
    bms.is_password_protected
FROM msdb.dbo.backupset bs
LEFT JOIN msdb.dbo.backupmediafamily bf
    ON bs.[media_set_id] = bf.[media_set_id]
INNER JOIN msdb.dbo.backupmediaset bms
    ON bs.[media_set_id] = bms.[media_set_id]
WHERE bs.backup_start_date > DATEADD(MONTH, - 2, sysdatetime()) --only look at last two months
ORDER BY bs.database_name ASC,
    bs.Backup_Start_Date DESC;
--OUTPUT

Step 5: Restore

Now, in order to get data before the execution of update statement, we are going to check the last_valid_restore_time and restore the database before the last_valid_restore_time which will return the data before update of the table as shown below.

USE [master]
RESTORE DATABASE [TESTDB] 
FROM  DISK = N'D:\Backup\TESTDBfullbackup.BAK' 
WITH  FILE = 1,  NORECOVERY,  NOUNLOAD,  REPLACE,  STATS = 5
RESTORE DATABASE [TESTDB] 
FROM  DISK = N'D:\Backup\TESTDBdifferentialbackup.BAK' 
WITH  FILE = 1,  NORECOVERY,  NOUNLOAD,  STATS = 5
RESTORE LOG [TESTDB] 
FROM  DISK = N'D:\Backup\TESTDBlogbackup1.TRN' 
WITH  FILE = 1,  NOUNLOAD,  STATS = 5,  STOPAT = N'2022-12-03T18:37:15'
GO

--OUTPUT

Conclusion:

Last_valid_restore_time is very handy information when we want to know the last transaction date in the specified backup & would like to restore based on specific time. Do let me know, how were you tracking this time in earlier version of SQL Server 2022.

Read Full Post »

Taking backup is the core responsibility of Database Administrator, either he takes the backup manually or he automates it but it does not matter. What actually matters is the database size because if it is very big then obviously it will take too much time in taking backup & occupy lots of disk space as well.

In SQL Server 2022, two new database backup compression algorithms were introduced as follows:

  1. MS_XPRESS
  2. QAT_DEFLATE

In this article, we are going to discuss one of the compression algorithms namely QAT_DEFLATE, which compresses backup size & reduce backup time drastically. We can use this compression algorithm for any types of database backup which are Full, Differential & Log backup. This algorithm will take less disk space and will reduce the backup time as well.

Let me demonstrate, how to implement this algorithm step by step.

Step 1:

Let’s check the database file size by using sys.database_files and as you can see the database size is ~10 GB.

USE SampleDB;
GO

SELECT DB_NAME()  AS DatabaseName
     , name       AS FileName
	 , size/128.0 AS CurrentSizeInMBs
FROM sys.database_files; 
GO

Step 2:

Let’s take full backup of SampleDB to see how much disk space & time it takes:

BACKUP DATABASE [SampleDB] 
TO  DISK = 'D:\Backup\FullBackupSampleDB.BAK';
GO

Step 3:

Let’s check the backup details especially the backup size and time. As we can see below, it took ~50 seconds to take Full backup and a disk space of ~10 GB

SELECT bs.database_name,
    backuptype = CASE 
        WHEN bs.type = 'D' AND bs.is_copy_only = 0 THEN 'Full Database'
        WHEN bs.type = 'D' AND bs.is_copy_only = 1 THEN 'Full Copy-Only Database'
        WHEN bs.type = 'I' THEN 'Differential database backup'
        WHEN bs.type = 'L' THEN 'Transaction Log'
        WHEN bs.type = 'F' THEN 'File or filegroup'
        WHEN bs.type = 'G' THEN 'Differential file'
        WHEN bs.type = 'P' THEN 'Partial'
        WHEN bs.type = 'Q' THEN 'Differential partial'
        END + ' Backup',
	BS.compression_algorithm,
    backup_size_mb = CONVERT(DECIMAL(10, 2), bs.backup_size / 1024. / 1024.),
    compressed_backup_size_mb = CONVERT(DECIMAL(10, 2), bs.compressed_backup_size / 1024. / 1024.),
	bs.backup_start_date ,
	bs.backup_finish_date,
	DATEDIFF(second, backup_start_date, backup_finish_date) AS time_in_seconds
FROM msdb.dbo.backupset bs
LEFT JOIN msdb.dbo.backupmediafamily bf
    ON bs.[media_set_id] = bf.[media_set_id]
INNER JOIN msdb.dbo.backupmediaset bms
    ON bs.[media_set_id] = bms.[media_set_id]
WHERE bs.backup_start_date > DATEADD(MONTH, - 2, sysdatetime()) --only look at last two months
ORDER BY bs.database_name ASC,
    bs.Backup_Start_Date DESC;

Step 4:

We MUST install the Intel® QuickAssist Technology Driver in order to use QAT_DEFLATE algorithm. Recently I have written an article on Intel® QuickAssist Technology Driver installation that can be accessed from here.

Step 5:

Let’s configure QAT_DEFLATE compression algorithm as a default in SQL Server as shown below.

EXEC sp_configure 'backup compression algorithm', 2;   
RECONFIGURE; 
GO

Step 6:

Let’s check the configuration of backup compression by using sys.configuration. As we can see below, the value is 2 which means QAT_DEFLATE is successfully setup.

SELECT configuration_id
     , name
     , description
     , value   
FROM sys.configurations   
WHERE name = 'backup compression algorithm' ;  
GO

Step 7:

let’s configure the hardware_offload option which is also mandatory for QAT_DEFLATE algorithm as shown below.

EXEC sp_configure 'show advanced options', 1;
GO

RECONFIGURE
GO

EXEC sp_configure 'hardware offload enabled', 1;
GO

RECONFIGURE
GO

ALTER SERVER CONFIGURATION SET HARDWARE_OFFLOAD = ON(ACCELERATOR = QAT); 
GO

Step 8:

Please make SURE to RESTART the SQL Server in this step.

Step 9:

Let’s take the full backup of our database with compression but since we setup the default compression algorithm as QAT_DEFLATE in earlier step then by default it takes full back with QAT_DEFLATE backup compression algorithm, so NO need to write the name of the backup compression algorithm in the script as shown below.

BACKUP DATABASE [SampleDB] 
TO  DISK = 'D:\BackupFullBackupSampleDBWithCompression.BAK'
WITH COMPRESSION;
GO

Step 10:

Once the backup is taken, let’s check the backup details by using given below query. As we can see below, the backup compression algorithm is QAT_DEFLATE, the backup compression size is ~1.3 GB & it took 24 seconds to take back up. It is almost reducing the size by ~87% and time by ~52% as compared to original backup and which is a big achievement.

SELECT bs.database_name,
    backuptype = CASE 
        WHEN bs.type = 'D' AND bs.is_copy_only = 0 THEN 'Full Database'
        WHEN bs.type = 'D' AND bs.is_copy_only = 1 THEN 'Full Copy-Only Database'
        WHEN bs.type = 'I' THEN 'Differential database backup'
        WHEN bs.type = 'L' THEN 'Transaction Log'
        WHEN bs.type = 'F' THEN 'File or filegroup'
        WHEN bs.type = 'G' THEN 'Differential file'
        WHEN bs.type = 'P' THEN 'Partial'
        WHEN bs.type = 'Q' THEN 'Differential partial'
        END + ' Backup',
    CASE bf.device_type
        WHEN 2 THEN 'Disk'
        WHEN 5 THEN 'Tape'
        WHEN 7 THEN 'Virtual device'
        WHEN 9 THEN 'Azure Storage'
        WHEN 105 THEN 'A permanent backup device'
        ELSE 'Other Device'
        END AS DeviceType,

	BS.compression_algorithm,
    backup_size_mb = CONVERT(DECIMAL(10, 2), bs.backup_size / 1024. / 1024.),
    compressed_backup_size_mb = CONVERT(DECIMAL(10, 2), bs.compressed_backup_size / 1024. / 1024.),
	bs.backup_start_date ,
	bs.backup_finish_date
FROM msdb.dbo.backupset bs
LEFT JOIN msdb.dbo.backupmediafamily bf
    ON bs.[media_set_id] = bf.[media_set_id]
INNER JOIN msdb.dbo.backupmediaset bms
    ON bs.[media_set_id] = bms.[media_set_id]
WHERE bs.backup_start_date > DATEADD(MONTH, - 2, sysdatetime()) --only look at last two months
ORDER BY bs.database_name ASC,
    bs.Backup_Start_Date DESC;

Conclusion:

I used QAT_DEFLATE backup compression algorithm & its results are quite good. Do let me know, which backup compression algorithm are you using and what is the outcome.

Read Full Post »

Taking backup is the core responsibility of Database Administrator, either he takes the backup manually or he automates it but it does not matter. What actually matters is the database size because if it is very big then obviously it will take too much time in taking backup & occupy lot’s of disk space as well.

In SQL Server 2022, two new database backup compression algorithms were introduced as follows:

  1. MS_XPRESS
  2. QAT_DEFLATE

In this article, we are going to discuss one of the compression algorithms namely MS_XPRESS, which compresses backup size & reduce backup time drastically. We can use this compression algorithm for any types of database backup which are Full, Differential & Log backup. This algorithm will take less disk space and will reduce the backup time as well.

Let me demonstrate, how to implement this algorithm step by step.

Step 1:

Let’s check the database file size by using sys.database_files and as you can see the database size is ~10 GB.

USE SampleDB;
GO

SELECT DB_NAME()  AS DatabaseName
     , name       AS FileName
	 , size/128.0 AS CurrentSizeInMBs
FROM sys.database_files; 
GO

Step 2:

Let’s take full backup of SampleDB to see how much disk space & time it takes:

BACKUP DATABASE [SampleDB] 
TO  DISK = 'D:\Backup\FullBackupSampleDB.BAK';
GO

Step 3:

Let’s check the backup details especially the backup size and time. As we can see below, it took ~50 seconds to take Full backup and a disk space of ~10 GB.

SELECT bs.database_name,
    backuptype = CASE 
        WHEN bs.type = 'D' AND bs.is_copy_only = 0 THEN 'Full Database'
        WHEN bs.type = 'D' AND bs.is_copy_only = 1 THEN 'Full Copy-Only Database'
        WHEN bs.type = 'I' THEN 'Differential database backup'
        WHEN bs.type = 'L' THEN 'Transaction Log'
        WHEN bs.type = 'F' THEN 'File or filegroup'
        WHEN bs.type = 'G' THEN 'Differential file'
        WHEN bs.type = 'P' THEN 'Partial'
        WHEN bs.type = 'Q' THEN 'Differential partial'
        END + ' Backup',
	BS.compression_algorithm,
    backup_size_mb = CONVERT(DECIMAL(10, 2), bs.backup_size / 1024. / 1024.),
    compressed_backup_size_mb = CONVERT(DECIMAL(10, 2), bs.compressed_backup_size / 1024. / 1024.),
	bs.backup_start_date ,
	bs.backup_finish_date,
	DATEDIFF(second, backup_start_date, backup_finish_date) AS time_in_seconds
FROM msdb.dbo.backupset bs
LEFT JOIN msdb.dbo.backupmediafamily bf
    ON bs.[media_set_id] = bf.[media_set_id]
INNER JOIN msdb.dbo.backupmediaset bms
    ON bs.[media_set_id] = bms.[media_set_id]
WHERE bs.backup_start_date > DATEADD(MONTH, - 2, sysdatetime()) --only look at last two months
ORDER BY bs.database_name ASC,
    bs.Backup_Start_Date DESC;

Step 4:

Let’s configure MS_XPRESS compression algorithm as a default in SQL Server as shown below.

EXEC sp_configure 'backup compression algorithm', 1;   
RECONFIGURE; 
GO

Step 5:

Let’s check the configuration of backup compression by using sys.configuration. As we can see below, the value is 1 which means MS_XPRESS is successfully setup

SELECT configuration_id
     , name
     , description
     , value   
FROM sys.configurations   
WHERE name = 'backup compression algorithm' ;  
GO

Step 6:

Let’s take the full backup of our database with compression but since we setup the default compression algorithm as MS_XPRESS in earlier step then by default it takes full back with MS_XPRESS backup compression algorithm, so NO need to write the name of the backup compression algorithm in the script as shown below.


BACKUP DATABASE [SampleDB] 
TO  DISK = 'D:\Backup\FullBackupSampleDBWithCompression.BAK'
WITH COMPRESSION;
GO

Step 7:

Once the backup is taken, let’s check the backup details by using given below query. As we can see below, the backup compression algorithm is MS_XPRESS, the backup compression size is 1.3 GB & it took 27 seconds to take back up only. It is almost reducing the size by ~87% and time by ~46% as compared to original backup and which is a big achievement.

SELECT bs.database_name,
    backuptype = CASE 
        WHEN bs.type = 'D' AND bs.is_copy_only = 0 THEN 'Full Database'
        WHEN bs.type = 'D' AND bs.is_copy_only = 1 THEN 'Full Copy-Only Database'
        WHEN bs.type = 'I' THEN 'Differential database backup'
        WHEN bs.type = 'L' THEN 'Transaction Log'
        WHEN bs.type = 'F' THEN 'File or filegroup'
        WHEN bs.type = 'G' THEN 'Differential file'
        WHEN bs.type = 'P' THEN 'Partial'
        WHEN bs.type = 'Q' THEN 'Differential partial'
        END + ' Backup',
    CASE bf.device_type
        WHEN 2 THEN 'Disk'
        WHEN 5 THEN 'Tape'
        WHEN 7 THEN 'Virtual device'
        WHEN 9 THEN 'Azure Storage'
        WHEN 105 THEN 'A permanent backup device'
        ELSE 'Other Device'
        END AS DeviceType,

	BS.compression_algorithm,
    backup_size_mb = CONVERT(DECIMAL(10, 2), bs.backup_size / 1024. / 1024.),
    compressed_backup_size_mb = CONVERT(DECIMAL(10, 2), bs.compressed_backup_size / 1024. / 1024.),
	bs.backup_start_date ,
	bs.backup_finish_date
FROM msdb.dbo.backupset bs
LEFT JOIN msdb.dbo.backupmediafamily bf
    ON bs.[media_set_id] = bf.[media_set_id]
INNER JOIN msdb.dbo.backupmediaset bms
    ON bs.[media_set_id] = bms.[media_set_id]
WHERE bs.backup_start_date > DATEADD(MONTH, - 2, sysdatetime()) --only look at last two months
ORDER BY bs.database_name ASC,
    bs.Backup_Start_Date DESC;

Conclusion:

I used MS_XPRESS backup compression algorithm & its results are quite good. Do let me know, which backup compression algorithm are you using and what is the outcome.

Read Full Post »

In my earlier articles, I explained, how to RESTORE the backup from URL using T-SQL, SQL Server Management Studio (SSMS)  from windows Azure storage and it was quite simple & easy to understand. In this article, I will explain how to RESTORE the backup from URL using PowerShell.

Pre-Requisite :

  1. Microsoft Azure – How to create storage and container
  2. SQL SERVER 2014 – How to take backup to URL (Windows Azure Storage) – PowerShell

Let me now demonstrate in few easy steps how to RESTORE backup from URL using PowerShell.

Step 1 – Create Account, storage & container :
First of all, you need to create a windows Azure account, a storage and a container as explained in this article.

Step 2 – RESTORE backup to URL :
Once you created the the Azure account, a storage and container and made sure that your backup is available in the windows Azure storage, you can RESTORE the backup from URL using given below script. In this script, first of all I declared the variables , then created credentials. After that RESTORED the backup as shown below. Rest of the script is self explanatory. Make sure that you have downloaded PowerShell Extensions for SQL Server in case you are using Windows PowerShell ISE instead of Windows PowerShell.

#Import sql module
Import-Module sqlps

#Create & set variables
$serverPath = "SQLSERVER:\SQL\WIN-KK48BQM9IS0\DEFAULT"
$storageAccount = "raresql"
$storageKey = "/ByNUTZqJ6EcJR/VQcNmNj+zSu++iCfbcxlyWye6Ok9uhsd5jsd62sjhsd7ksdh7sksdsdlhsd4bsdhsd52ksd=="
$secureString = convertto-securestring $storageKey -asplaintext -force
$credentialName = "My_Credential"

# Create Credential
New-sqlcredential -Name $credentialName -Identity $storageAccount -Secret $secureString

# Set SQL Server instance Path
CD $serverPath

# Set the backup file name
$backupFile = "https://raresql.blob.core.windows.net/sql-backup/AdventureWorks2012_25_Dec_2014.bak"

# Restore Database and move files
$newDataFilePath = New-Object Microsoft.SqlServer.Management.Smo.RelocateFile ("AdventureWorks2012_Data","C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\DATA\AdventureWorks2012_Data.mdf")
$newLogFilePath = New-Object Microsoft.SqlServer.Management.Smo.RelocateFile("AdventureWorks2012_Log","C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\DATA\AdventureWorks2012_log.ldf")
Restore-SqlDatabase -Database "AdventureWorks2012" -SqlCredential $credentialName -BackupFile $backupFile -RelocateFile @($newDataFilePath,$newLogFilePath)

How to RESTORE backup from URL (Windows Azure Storage) - PowerShell.1.1

How to RESTORE backup from URL (Windows Azure Storage) - PowerShell1.2

How to RESTORE backup from URL (Windows Azure Storage) - PowerShell1.3

As you can see, the messages show that your backup has been restored successfully.

Read Full Post »