Skip to main content

What’s in a Full Backup?

I got asked a question today that I though was quite interesting. If my backup starts at 6pm and it runs for say 30 minutes what happens to the transactions that occur during the 30 minutes that the backup is running?

The short answer:

All committed transactions that run during the duration of the backup will be included in the full backup, open transactions will not be included.

The proof:

Please note, that your database will get around 784MB in size and the backup created will be roughly the same size, so before running these scripts, make sure you have enough space on the box you testing it on.

I will create a dummy database called buptest for the purpose of this test

USE master
go
CREATE DATABASE buptest
GO
ALTER DATABASE buptest SET RECOVERY SIMPLE





I have put the database into simple recovery mode just to keep the log manageable, I am not worried about point in time recovery for this demo.


Next we will create two tables to hold some test data

USE buptest
go

CREATE TABLE t1 (id INT, val CHAR(8000))
go

CREATE TABLE t2 (id INT, val CHAR(8000))
go



Next we will populate our table t1 with some data, 100,000 rows. I’m doing this so the backup will run for long enough to allow me to execute some transactions against the database whilst the backup is running. I don’t know of another way of doing this…If you do, please leave me a note in the comments.

DECLARE @i INT
SET @i = 0
WHILE @i < 100000
BEGIN

INSERT INTO t1
VALUES (@i, REPLICATE('a',8000))
SET @i=@i+1
END



The next step has two parts, I want to kick off a full backup in one query window and then in a second query window I want to run two transactions that each insert a row into the t2 table. The first transaction will be committed before the backup completes the second transaction will be committed after backup has finished. So I suggest if you are following along, you open two query windows, paste the backup code below into the first window, paste the insert transaction into the second window (You will see that the second commit statement in commented out), switch to the first window, start the backup, quickly switch to the second window, fire the script making sure that the commit statement is commented out. Wait for the backup to complete. When the backup has completed uncommented the commit transaction statement and commit the currently open transaction.


The script to run the backup

--We then take a backup of the database
--While this is running fire the second script below
BACKUP DATABASE buptest TO DISK = 'c:\Backup\buptest.bak'



While the backup script above is running (it took about a minute on my laptop to complete) run this:

USE buptest
GO

--Run in a new query window
BEGIN TRANSACTION
INSERT INTO t2
VALUES (1, 'gethyn')
COMMIT TRANSACTION


BEGIN TRANSACTION
INSERT INTO t2
VALUES (2,'Ian')





When the backup completes run the final commit transaction in the second window. This ensures that the second transaction was not committed prior to the backup completing.

COMMIT TRANSACTION



If you run

SELECT * FROM t2



We get two rows returned.









1Gethyn
2Ian

Next we run a restore of our database from the backup taken

USE master
go
ALTER DATABASE buptest SET SINGLE_USER WITH ROLLBACK IMMEDIATE

RESTORE DATABASE buptest FROM DISK = 'c:\Backup\buptest.bak' WITH replace



Then re-run the same select

SELECT * FROM t2



We see that only the first inserted record is present.






1Gethyn

Hence only committed transaction are included in a full database backup

 

Comments

Popular posts from this blog

SQL Server 2012 and Virtual Service Accounts

This post is written by David Postlethwaite
If you are using SQL Server 2012 you will probably have noticed that the default account for the SQL services has changed from that used in previous versions. With SQL 2005 and 2008 the default account for SQL service and SQL Agent service was “NT Authority\System”. This is one the built in accounts on a Windows machine, managed by the machine and selectable from a dedicated dropdown list

The Network Service account was introduced in Windows 2003 as an alternative to using the LocalSystem account, which has full local system privileges on the local machine, a major security concern.
The Network Service has limited local privileges easing these security concerns but when many services on a machine use the Network Service account it becomes harder to track which service is actually accessing resources and performing actions, because all the services are using the one Network Service account.
Also, this account, by default, has sysadmin per…

Always Encrypted

By David Postlethwaite

Always Encrypted is new features in SQL Server 2016 and it is also available in Azure SQL Database. Here you can encrypt columns in a table with a master key and a certificate so that they will appear as encrypted strings to those who don’t have the required certificate installed on their pc.
Once the certificate is installed on the computer then the unencrypted data can then be seen as normal.

The data passes from database to your application as the encrypted value, only the application with the correct certificate can unencrypt the data so it is secure across the wire. This will go some way to resolving the concern of people worried about putting their sensitive data on a shared server in the cloud such as Microsoft Azure and accessing the data across the Internet.

At the time of writing Always Encrypted is only supported with ADO.NET 4.6, JDBC 6.0 and ODBC 13.1 but expect other driver to become available.

The calling application (including SSMS) must also hav…

New in SQL Server 2017: Graph Databases

David has recorded and published a video of his presentation on SQL Server Graph Database. In his video which you can watch below, David provides an excellent introduction into SQL Server 2017 Graph Databases. In his presentation he looks at Tennis results at tournaments for  his favourite player "The Fed"  Rodger Federer.

David  shows how to set up graph database and work with them in SQL Server 2017.

Graph Database is not new. Other vendors have had graph database capabilities for some time so Microsoft are quite late to the market. In David presentation it appears that Microsoft have done a reasonable job of implementing some of the graph database features but he does point some of the limitations of the Microsoft product too and suggests that it is not ready for production yet but Microsoft seem serious about this feature.

Please watch the video and feel free to leave a comment or feedback - David is delivering a version of this talk on Graph databases in SQL Saturday Ka…