backupset (Transact-SQL)

backupset (Transact-SQL)

 

Updated: June 10, 2016

THIS TOPIC APPLIES TO:yesSQL Server (starting with 2008)noAzure SQL DatabasenoAzure SQL Data Warehouse yesParallel Data Warehouse

Contains a row for each backup set. A backup set contains the backup from a single, successful backup operation. RESTORE, RESTORE FILELISTONLY, RESTORE HEADERONLY, and RESTORE VERIFYONLY statements operate on a single backup set within the media set on the specified backup device or devices.

This table is stored in the msdb database.

Column nameData typeDescription
backup_set_idintUnique backup set identification number that identifies the backup set. Identity, primary key.
backup_set_uuiduniqueidentifierUnique backup set identification number that identifies the backup set.
media_set_idintUnique media set identification number that identifies the media set containing the backup set. References backupmediaset(media_set_id).
first_family_numbertinyintFamily number of the media where the backup set starts. Can be NULL.
first_media_numbersmallintMedia number of the media where the backup set starts. Can be NULL.
last_family_numbertinyintFamily number of the media where the backup set ends. Can be NULL.
last_media_numbersmallintMedia number of the media where the backup set ends. Can be NULL.
catalog_family_numbertinyintFamily number of the media containing the start of the backup set directory. Can be NULL.
catalog_media_numbersmallintMedia number of the media containing the start of the backup set directory. Can be NULL.
positionintBackup set position used in the restore operation to locate the appropriate backup set and files. Can be NULL. For more information, see FILE in BACKUP (Transact-SQL).
expiration_datedatetimeDate and time the backup set expires. Can be NULL.
software_vendor_idintIdentification number of the software vendor writing the backup media header. Can be NULL.
namenvarchar(128)Name of the backup set. Can be NULL.
descriptionnvarchar(255)Description of the backup set. Can be NULL.
user_namenvarchar(128)Name of the user performing the backup operation. Can be NULL.
software_major_versiontinyintMicrosoft SQL Server major version number. Can be NULL.
software_minor_versiontinyintSQL Server minor version number. Can be NULL.
software_build_versionsmallintSQL Server build number. Can be NULL.
time_zonesmallintDifference between local time (where the backup operation is taking place) and Coordinated Universal Time (UTC) in 15-minute intervals. Values can be -48 through +48, inclusive. A value of 127 indicates unknown. For example, -20 is Eastern Standard Time (EST) or five hours after UTC. Can be NULL.
mtf_minor_versiontinyintMicrosoft Tape Format minor version number. Can be NULL.
first_lsnnumeric(25,0)Log sequence number of the first or oldest log record in the backup set. Can be NULL.
last_lsnnumeric(25,0)Log sequence number of the next log record after the backup set. Can be NULL.
checkpoint_lsnnumeric(25,0)Log sequence number of the log record where redo must start. Can be NULL.
database_backup_lsnnumeric(25,0)Log sequence number of the most recent full database backup. Can be NULL.

 database_backup_lsn is the “begin of checkpoint” that is triggered when the backup starts. This LSN will coincide with first_lsn if the backup is taken when the database is idle and no replication is configured.
database_creation_datedatetimeDate and time the database was originally created. Can be NULL.
backup_start_datedatetimeDate and time the backup operation started. Can be NULL.
backup_finish_datedatetimeDate and time the backup operation finished. Can be NULL.
typechar(1)Backup type. Can be:

D = Database

I = Differential database

L = Log

F = File or filegroup

G =Differential file

P = Partial

Q = Differential partial

Can be NULL.
sort_ordersmallintSort order of the server performing the backup operation. Can be NULL. For more information about sort orders and collations, see Collation and Unicode Support.
code_pagesmallintCode page of the server performing the backup operation. Can be NULL. For more information about code pages, see Collation and Unicode Support.
compatibility_leveltinyintCompatibility level setting for the database. Can be:

90 = SQL Server 2005

100 = SQL Server 2008

110 = SQL Server 2012

120 = SQL Server 2014

Can be NULL.

For more information about compatibility levels, see ALTER DATABASE Compatibility Level (Transact-SQL).
database_versionintDatabase version number. Can be NULL.
backup_sizenumeric(20,0)Size of the backup set, in bytes. Can be NULL. For VSS backups, backup_size is an estimated value.
database_namenvarchar(128)Name of the database involved in the backup operation. Can be NULL.
server_namenvarchar(128)Name of the server running the SQL Server backup operation. Can be NULL.
machine_namenvarchar(128)Name of the computer running SQL Server. Can be NULL.
flagsintIn SQL Server, the flags column has been deprecated and is being replaced with the following bit columns:

 has_bulk_logged_data 
 is_snapshot 
 is_readonly 
 is_single_user 
 has_backup_checksums 
 is_damaged 
 begins_log_chain 
 has_incomplete_metadata 
 is_force_offline 
 is_copy_only

Can be NULL.

In backup sets from earlier versions of SQL Server, flag bits:
1 = Backup contains minimally logged data.
2 = WITH SNAPSHOT was used.
4 = Database was read-only at the time of backup.
8 = Database was in single-user mode at the time of backup.
unicode_localeintUnicode locale. Can be NULL.
unicode_compare_styleintUnicode compare style. Can be NULL.
collation_namenvarchar(128)Collation name. Can be NULL.
Is_password_protectedbitIs the backup set

password protected:

0 = Not protected

1 = Protected
recovery_modelnvarchar(60)Recovery model for the database:

FULL

BULK-LOGGED

SIMPLE
has_bulk_logged_databit1 = Backup contains bulk-logged data.
is_snapshotbit1 = Backup was taken using the SNAPSHOT option.
is_readonlybit1 = Database was read-only at the time of backup.
is_single_userbit1 = Database was single-user at the time of backup.
has_backup_checksumsbit1 = Backup contains backup checksums.
is_damagedbit1 = Damage to the database was detected when this backup was created. The backup operation was requested to continue despite errors.
begins_log_chainbit1 = This is the first in a continuous chain of log backups. A log chain begins with the first log backup taken after the database is created or when it is switched from the simple to the full or bulk-logged recovery model.
has_incomplete_metadatabit1 = A tail log backup with incomplete metadata. For more information, see Tail-Log Backups (SQL Server).
is_force_offlinebit1 = Database was taken offline using the NORECOVERY option when the backup was taken.
is_copy_onlybit1 = A copy-only backup. For more information, see Copy-Only Backups (SQL Server).
first_recovery_fork_guiduniqueidentifierID of the starting recovery fork. This corresponds to FirstRecoveryForkID of RESTORE HEADERONLY.

For data backups, first_recovery_fork_guid equals last_recovery_fork_guid.
last_recovery_fork_guiduniqueidentifierID of the ending recovery fork. This corresponds to RecoveryForkID of RESTORE HEADERONLY.

For data backups, first_recovery_fork_guid equals last_recovery_fork_guid.
fork_point_lsnnumeric(25,0)If first_recovery_fork_guid is not equal to last_recovery_fork_guid, this is the log sequence number of the fork point. Otherwise, the value is NULL.
database_guiduniqueidentifierUnique ID for the database. This corresponds to BindingID of RESTORE HEADERONLY. When the database is restored, a new value is assigned.
family_guiduniqueidentifierUnique ID of the original database at creation. This value remains the same when the database is restored, even to a different name.
differential_base_lsnnumeric(25,0)Base LSN for differential backups. For a single-based differential backup; changes with LSNs greater than or equal to differential_base_lsn are included in the differential backup.

For a multibased differential, the value is NULL, and the base LSN must be determined at the file level (see backupfile (Transact-SQL)).

For nondifferential backup types, the value is always NULL.
differential_base_guiduniqueidentifierFor a single-based differential backup, the value is the unique identifier of the differential base.

For multibased differentials, the value is NULL, and the differential base must be determined at the file level.

For nondifferential backup types, the value is NULL.
compressed_backup_sizeNumeric(20,0)Total Byte count of the backup stored on disk.

To calculate the compression ratio, use compressed_backup_size and backup_size.

During an msdb upgrade, this value is set to NULL. which indicates an uncompressed backup.
key_algorithmnvarchar(32)The encryption algorithm used to encrypt the backup. NO_Encryption value indicated that the backup was not encrypted.
encryptor_thumbprintvarbinary(20)The thumbprint of the encryptor which can be used to find certificate or the asymmetric key in the database. In the case where the backup was not encrypted, this value is NULL.
encryptor_typenvarchar(32)The type of encryptor used: Certificate or Asymmetric Key. . In the case where the backup was not encrypted, this value is NULL.

RESTORE VERIFYONLY FROM backup_device WITH LOADHISTORY populates the column of the backupmediaset table with the appropriate values from the media-set header.

To reduce the number of rows in this table and in other backup and history tables, execute the sp_delete_backuphistory stored procedure.

Backup and Restore Tables (Transact-SQL)
backupfile (Transact-SQL)
backupfilegroup (Transact-SQL)
backupmediafamily (Transact-SQL)
backupmediaset (Transact-SQL)
Possible Media Errors During Backup and Restore (SQL Server)
Media Sets, Media Families, and Backup Sets (SQL Server)
Recovery Models (SQL Server)
RESTORE HEADERONLY (Transact-SQL)
Backup and Restore Tables (Transact-SQL)

Community Additions

ADD
Show:
© 2016 Microsoft