Chatee ahora con Soporte
Chat con el soporte

LiteSpeed for SQL Server 8.9.8 - Integration with TSM Guide

xp_restore_database

Restores LiteSpeed full and partial backups created with LiteSpeed. Files and filegroups may also be restored either from a file or filegroup LiteSpeed backup operation, or from a full database backup operation using xp_backup_database. When restoring files or filegroups, you must apply a transaction log using xp_restore_log. In addition, file differential backups can be restored after a full file restore using LiteSpeed.

NOTE: A database cannot be restored unless the restore process has exclusive access to the database. No user connections can exist when performing a database restore.

This topic covers:

Syntax

xp_restore_database (disk)

EXEC master.dbo.xp_restore_database

@database = 'database_name'

(, @filename = 'backup_file_name') [,...n]

[, ( @encryptionkey = 'encryption_key' | @jobp = 'encrypted_key' ) ]

[, @file = 'logical_file_name'] [,...n]

[, @filenumber = n]

[, @filegroup = 'logical_filegroup_name'] [,...n]

[, @with = 'additional_with_parameters'] [,...n]

[, @logging = 0 | 1 | 2 ]

[, @affinity = 0..2147483648]

[, @throttle = 1..100]

[, @ioflag = 'DISK_RETRY_COUNT=n']

[, @ioflag = 'DISK_RETRY_WAIT=n']

[, @restoreasreadonly = 0 | 1 ]

[, @buffercount = 'buffer_count']

[, @maxtransfersize = 'maximum_transfer_size']

[, @attachedfile = 'pathname'] [,..n]

[, @returndetails = 0 | 1]

[, @restoreasreadonly = 0 | 1]

[, @restoreascompressed = 0 | 1]

xp_restore_database (TSM)

EXEC master.dbo.xp_restore_database

@database = 'database_name'

, @tsmobject = 'TSM_object' [,...n]

, @tsmconfigfile = 'TSM_configuration_file'

[, ( @encryptionkey = 'encryption_key' | @jobp = 'encrypted_key' ) ]

[, @file = 'logical_file_name'] [,...n]

[, @filenumber = n]

[, @filegroup = 'logical_filegroup_name'] [,...n]

[, @with = 'additional_with_parameters'] [,...n]

[, @logging = 0 | 1 | 2 ]

[, @affinity = 0..2147483648]

[, @throttle = 1..100]

[, @ioflag = 'DISK_RETRY_COUNT=n']

[, @ioflag = 'DISK_RETRY_WAIT=n']

[, @restoreasreadonly = 0 | 1 ]

[, @buffercount = 'buffer_count']

[, @maxtransfersize = 'maximum_transfer_size']

[, @attachedfile = 'pathname'] [,..n]

[, @tsmclientnode = 'TSM_client_node']

[, @tsmclientownerpwd = 'TSM_client_owner_password']

[, @tsmpointintime = 'date_time']

[, @tsmarchive = 0 | 1 ]

[, @returndetails = 0 | 1]

[, @restoreasreadonly = 0 | 1]

[, @restoreascompressed = 0 | 1]

xp_restore_database (tape)

EXEC master.dbo.xp_restore_database
@database = 'database_name'
(, @filename = 'backup_file_name') [,...n]
[, @filenumber = n]
[, @rewind = 0 | 1 ]
[, @unload = 0 | 1 ]
[, @encryptionkey = 'encryption_key']
[, @file = 'logical_file_name'] [,...n]
[, @filegroup = 'logical_filegroup_name'] [,...n]
[, @with = 'additional_with_parameters'] [,...n] 
[, @restoreasreadonly = 0 | 1 ]
[, @logging = 0 | 1 | 2 ]
[, @affinity = 0..2147483648]
[, @throttle = 1..100]
[, @buffercount = 'buffer_count']
[, @maxtransfersize = 'maximum_transfer_size']
[, @attachedfile = 'pathname'] [,..n]
[, @returndetails = 0 | 1]

xp_restore_database (Amazon S3)

EXEC master.dbo.xp_restore_database
@CloudVendor = N'AmazonS3'
, @Database = N'AA_5_restored88'
[, @FileName = N'AA_5_1.bak']
[, @FileNumber = 1]
[, @CloudBucketName = N'aabucket1']
[, @CloudAccessKey = N'***']
[, @CloudSecretKey = N'***']
[, @CloudRegionName = N'us-west-2']
[, @With = N'MOVE ''AA_5'' TO ''F:\Databases.SQL2005\QQ_3_restored88.mdf'', MOVE ''AA_3_log'' TO ''F:\Databases.SQL2005\AA_5_restored88_log.ldf'', REPLACE']
[, @ProxyHost = N'proxy.sitelocal']
[, @ProxyPort = 8080]
[, @ProxyLogin = N'DOMAIN\temp-xyz-MYtester']
[, @ProxyPassword = N'***']

xp_restore_database (Microsoft Azure)

EXEC master.dbo.xp_restore_database

@database = N'model' ,

@filename = N'test\test.bak',

@filenumber = 1,

@CloudVendor = N'AzureBlob',

@CloudBucketName = N'test',

@CloudAccessKeyEnc = N'*******',

@CloudSecretKeyEnc = N'******',

@UseSSL = 1,

@with = N'REPLACE',

@with = N'STATS = 10',

@affinity = 0,

@logging = 0

xp_restore_database (Google Cloud Storage)

exec xp_restore_database

@Database = N'db-1'

, @FileName = N'db.bak'

, @FileNumber = 1

, @With = N'MOVE ''db'' TO ''path\to\db_1.mdf'', MOVE ''db_log'' TO ''path\to\db_1_log.ldf'''

, @CloudVendor = N'GoogleStorage'

, @CloudBucketName = N'bucketname'

, @CloudAccessKey = N'***' -- my key'

, @CloudSecretKey = N'***' -- my key

xp_restore_database (S3 Compatible Storage)

exec xp_restore_database

@Database = N'db-1'

, @FileName = N'db.bak'

, @FileNumber = 1

, @With = N'MOVE ''db'' TO ''path\to\db_1.mdf'', MOVE ''db_log'' TO ''path\to\db_1_log.ldf'''

, @CloudVendor = N'S3Compatible'

, @CloudEndpoint = N'storageserver:port'

, @CloudBucketName = N'bucketname'

, @CloudAccessKey = N'***' -- my key'

, @CloudSecretKey = N'***' -- my key

xp_restore_database (restore partial backup - filegroup offline)

NOTE: The following example shows the syntax for performing partial restores using the “read_write_filegroups” parameter. The database used in the example below, FGBackups_PROD, contains the following filegroups: Primary, FG1. FG2, and FG3).

Tip: The read only filegroup FG3 is offline after the restore is complete as indicated in the following example.

EXEC master.dbo.xp_restore_database

@database = 'Prod_test' ,

@read_write_filegroups = 1,

@filename = N'I:\FGBackups_FULL.bkp',

@with = N'REPLACE'

xp_restore_database (restore partial backup - filegroup online)

Tip: To restore the read only filegroup FG3 and bring it online after the partial restore above has completed, a full backup containing the filegroup must be used for the restore as indicated in the following example.

EXEC master.dbo.xp_restore_database

@database = 'Prod_test'

, @filegroup = 'FG3'

, @filename = N'I:\FGBackups_FULL_keep.bak',

@with = N'REPLACE'

xp_restore_database (restore fast compression partial backup - offline)

NOTE: The read only file group, FG3, is offline after the restore is complete.

EXEC master.dbo.xp_restore_database

@database = 'Prod_test',

@read_write_filegroups = 1,

@filename = 'I:\SQLbackups\FGBackups_PROD.litespeed.f0.bkp' ,

@with = N'REPLACE'

xp_restore_database (restore fast compression partial backup - online)

Tip: To restore the read only file group, FG3, and bring it online after the partial restore above has completed, a full backup containing the filegroup must be used for the restore.

EXEC master.dbo.xp_restore_database

@database = 'Prod_test'

, @filegroup = 'FG3'

, @filename = N'I:\FGBackups_FULL.bak',

@with = N'REPLACE'

xp_restore_database (restore partial differential backup)

NOTE: The read only file group FG3 is offline after the restore is complete.

It is a two-step process to restore a LiteSpeed partial full backup followed by a restore of a LiteSpeed partial differential backup. Both steps are needed in order to restore a partial differential backup and bring the database online.

Step 1 - restore the LiteSpeed partial full backup

EXEC.master.dbo.xp_restore_database

@database = 'FGBackups_PROD' ,

@read_write_filegroups = 1,

@WITH = 'PARTIAL' ,

@filename = N'I:\FGBackups_FULL.bkp',

@with = N'REPLACE',

@with = N'NORECOVERY'

Step 2 -restore the LiteSpeed partial differential backup

EXEC master.dbo.xp_restore_database

@database = 'FGBackups_PROD' ,

@read_write_filegroups = 1,

@filename = N'I:\FGBackups_FULL_diff.bkp',

Tip: To restore the read only file group FG3 and bring it online after the partial restore above is completed, a full backup containing the file group must be used for the restore.

EXEC.master.dbo.xp_restore_database

@database = 'FGBackups_PROD'

, @filegroup = 'FG3'

, @filename = N'I:\FGBackups_FULL_keep.bak',

@with = N'REPLACE'

Arguments

Tips:

  • To see the list of accepted arguments and data types for arguments, execute the following:
    exec master.dbo.<procedure_name> show_help

  • To convert the script for use with the command-line utilities, execute the following:
    exec master.dbo.<procedure_name> show_cmd, <xp_arguments>

@affinity

Processor affinity designates specific processors to run LiteSpeed, while not allowing LiteSpeed to run on the remaining processors.

This argument accepts decimal values and hexadecimal values. If a value begins with "0x" it is interpreted as hexadecimal. A positive 64-bit integer value translates to a binary mask where a value of 1 designates the corresponding processor to be able to run the LiteSpeed process.

NOTE: 32-bit Windows is internally limited to a 32-bit mask.

For example, you need to select processors 2, 3, and 6 for use with LiteSpeed. Number the bits from the right to left. The rightmost bit represents the first processor. Set the second, third, and sixth bits to 1 and all other bits to 0. The result is binary 100110, which is decimal 38 or hexadecimal 0x26. Review the following for additional information:

Decimal Value

Binary Bit Mask

Allow LiteSpeed Threads on Processors

0 0 All (default)

1

1

1

3

11

1 and 2

7 111 1, 2 and 3

38

100110

2, 3, and 6

205 11001101 1, 3, 4, 7, and 8

Tip: Before you start tuning the CPU Throttle or Affinity parameters to adjust backup performance, try limiting the number of threads. If you decide to use an affinity value other than default, it is recommended that you limit the threading as well. You may also want to consider using Adaptive Compression to maintain backup performance. For more information, see Adaptive Compression.

@attachedfile

Specifies filepaths to include in both backup and restore operations. The filepath can be either a single file or a directory. If it is a directory, then LiteSpeed recursively includes all files and subdirectories. All attached files are encrypted and compressed, with all pertinent backup parameters supported. This feature works for disk, tape, TSM, and Double Click Restore as well. You can supply multiple instances of this argument.

When used within the context of a restore operation, the path parameter can be expanded to include a new destination. This form will take the syntax of <file_path> to <new_file_path>. The new filepath can be used to specify a new location but cannot rename a file.

This argument only restores the attached files. It does not restore the database, just the files that were attached to that backup.

NOTES:

  • The original entire directory path need not be supplied (e.g. c: to c:\testadSattsm is allowed).
  • c:\testad to testadr would restore all files in directory c:\testad to c:\testadr.

@AWSUseReducedRedundancy

The @AWSUseReducedRedundancy argument specifies the use of reduced redundancy storage in Amazon S3. This argument accepts one of the following values:

  • 0—Do not use reduced redundancy storage
  • 1—Use reduced redundancy storage

Note: This @AWSUseReducedRedundancy argument is replaced with the @CloudStorageClass = 'rrs' argument.

@AWSUseServerSideEncryption

The @AWSUseServerSideEncryption argument enables the encryption of data stored at rest in Amazon S3. This argument accepts one of the following values:

  • 0—Do not use Server Side Encryption
  • 1—Use Server Side Encryption

@buffercount

Specifies the number of SQL Server buffers available for a LiteSpeed operation. The default value is set by SQL Server.

@buffercount

Specifies the number of SQL Server buffers available for a LiteSpeed operation. The default value is set by SQL Server.

@CloudAccessKey

The @CloudAccessKey argument specifies the name of the unique Cloud Web Service alphanumeric access key that identifies each user. The selections include Amazon Access Key, Azure Account Name, Google e-mail styled account, S3 Compatible Storage Access Key.

@CloudAccessKeyEnc

The @CloudAccessKeyEnc argument specifies the name of the encrypted unique Cloud Web Service alphanumeric access key that identifies each user.

@CloudBucketName

The @CloudBucketName argument specifies the name of the container for cloud objects. Bucket names must be at least 3 and no more than 63 characters long. The selections are Amazon Bucket Name, Azure Container Name, Google Bucket Name, Google Bucket Name requirements are described at https://cloud.google.com/storage/docs/naming, S3 Compatible Storage Bucket Name,

@CloudGovRegion

The @CloudGovRegion argument enables a special restricted region for the US Government use in Amazon S3 and Azure Clouds. This argument accepts one of the following values:

  • 0—Do not use government cloud (default)
  • 1—Use government cloud

@CloudRegionName

The @CloudRegionName argument specifies the name of the Cloud Web Service region to use for a bucket. Example values are but not limited to: us-east-1, us-east-2, us-west-1, us-west-2, ca-central-1, eu-central-1, eu-west-1, eu-west-2, ap-south-1, ap-southeast-1, ap-southeast-2, ap-northeast-1, ap-northeast-2, sa-east-1, N'Germany' and N'China'.

@CloudSecretKey

The @CloudSecretKey argument specifies the name of the Cloud Web Service secret key that is assigned when you initially get a Cloud account.

@CloudSecretKeyEnc

The @CloudSecretKeyEnc argument specifies the name of the encrypted Cloud Web Service secret key that is assigned when you initially get a Cloud account.

@CloudVendor

The @CloudVendor argument specifies the name of the cloud service provider. The argument accepts one of the following values: "AmazonS3", "AzureBlob", "GoogleStorage" or "S3Compatible".

@CloudEndpoint

The @CloudEndpoint argument specifies the endpoint for S3 Compatible Storage and custom endpoint for Amazon S3 service (in case of VPC). Format: servername:port .Example values: "servername", "servername:port", "ip:port", "10.0.0.200:9021".

@CloudAcceptAllCertificates

The @CloudAcceptAllCertificates argument instructs LiteSpeed accept self-signed certificates for S3 Compatible Storage. This argument accepts one of the following values:

  • 0—Accept verified certificates only (default)
  • 1—Accept self-signed certificates

Note: Delete backups is not supported in Maintenance Plans with this option.

@database

Name of database to be backed up or restored.

This parameter specifies a database:

  • to be backed up (xp_backup_database and xp_slsFastCompression)

  • containing the transaction log to be backed up (xp_backup_log)

  • to be restored (xp_restore_database and xp_restore_log)

  • on which you wish to check the progress of an activity (xp_slsReadProgress)

  • for which you want to delete old backups (xp_slsSmartCleanup)

If supplied as a variable (@database), this name can be specified either as a string constant (@database = database name) or as a variable of character string data type, except for the ntext or text data types.

@DisconnectUsers

Disconnect users on executing restore (in standby mode only). This argument accepts one of the following values:

  • 0—Do not disconnect users (default).
  • 1—Disconnect users.

@encryptionkey

Value used to generate the encryption key for the encryption algorithm. If you do not supply encryption key, then the program will not encrypt the backup. If you use the wrong encryption key, the restore will fail.

Caution: When encrypting data, take care not to lose the encryption key; a backup cannot be restored or recovered without the original encryption key.

Example of key: 'Mypassword'

@file

Specifies a logical database file used for file or filegroup backups. You can supply multiple instances of this argument.

@filegroup

Specifies a database filegroup to include in the backup or restore. You can supply multiple instances of this argument.

A filegroup backup is a single backup of all files in the filegroup and is equivalent to explicitly listing all files in the filegroup when creating the backup. Files in a filegroup backup can be restored individually or as a group.

@filename

Specifies a backup location (e.g. C:\backups\AdventureWorks.bak). This argument accepts network destinations. You can supply multiple instances of this argument to use stripe backups.

@filenumber

Disk restores:

Specifies the particular backup to use when recasting, restoring, extracting or reading from files with multiple appended backups. You can run xp_restore_headeronly to query the files contained within the backup set given by backup_file_name.

Tape restores:

Identifies the backup set to be restored. For example, a file number of 1 indicates the first backup set on the backup medium, and a file number of 2 indicates the second backup set.

@ioflag

Specifies if LiteSpeed should wait and retry the read or write operation on failure. You can define retry options using the following parameters:

  • DISK_RETRY_COUNT—Specifies the number of times that a specific operation will be retried on failure. The default is 4 retries, the maximum allowed setting is 1000.
  • DISK_RETRY_WAIT—Specifies the number of seconds to wait immediately following a failure before retrying. The default is 15 seconds, the maximum allowed setting is 300.

NOTE: This functionality is only available for disk and cloud operations.

For example, to specify a database backup where each failure can be retried once after a 30-second wait:

EXEC master.dbo.xp_backup_database
@filename='c:\test.bkp'
, @database='test'
, @ioflag='DISK_RETRY_COUNT=1'
, @ioflag='DISK_RETRY_WAIT=30'

Network Resilience

@jobp

Specifies an encrypted key. (Similar to @EncryptionKey).

You can use xp_encrypt_backup_key to convert the password (encryption_key) for use with @jobp. The original password (or encrypted key generated by xp_encrypt_restore_key) must be used to restore a backup.

@logging

Writes a log file for the operation. This argument accepts one of the following values:

  • 0—Logging off.

  • 1 or any odd value—Logging on. Log file is removed on success.

  • 2 or any even value—Logging on.

The default output directory is C:\Documents and Settings\All Users\Application Data\Quest Software\LiteSpeed\SQL Server\Logs (or C:\ProgramData\Quest Software\LiteSpeed\SQL Server\Logs) (or C:\ProgramData\Quest Software\LiteSpeed\SQL Server\Logs). To log to a different directory add @Trace='logpath=path'.

See Configure Logging in LiteSpeed for information about LiteSpeed logging.

@maxtransfersize

Specifies the largest unit of transfer in bytes to be used between SQL Server and LiteSpeed. The possible values are multiples of 65536 bytes (64 KB) ranging up to 4,194,304 bytes (4 MB). The default is 1048576 (1 MB).

@Page

The @Page argument allows you to restore one or more damaged pages without the need to restore the whole database. Restoring and recovering a few individual pages might be faster than a file restore by reducing the amount of data that is offline during a restore operation. However, if you have to restore more than a few pages in a file, it may be more efficient to restore the whole file. For example, if lots of pages on a device indicate a pending device failure, consider restoring the file, possibly to another location, and repairing the device. Please refer to the Microsoft SQL Server documentation on Restore Pages for additional information and guidelines on page restores.

@ProxyHost

The @ProxyHost argument is optional and specifies the name of the proxy host name that is running the proxy server.

note: If the @ProxyHost argument is not defined, then the LiteSpeed core engine checks the local .ini files for the proxy parameters. If the proxy parameters are not detected, then the LiteSpeed core engine connects directly to the proxy servers.

@ProxyLogin

The @ProxyLogin argument is optional and specifies the proxy server login credential.

note: If not defined, then the LiteSpeed core engine checks the local .ini files for the proxy parameters. If the proxy parameters are not detected, then the LiteSpeed core engine connects directly to the proxy servers.

@ProxyPassword

The @ProxyPassword argument is optional and specifies the proxy server password credential.

note: If the @ProxyPassword argument is not defined, then the LiteSpeed core engine checks the local .ini files for the proxy parameters. If the proxy parameters are not detected, then the LiteSpeed core engine connects directly to the proxy servers.

@ProxyPasswordEnc

The @ProxyPasswordEnc argument is optional and specifies the encrypted proxy server password credential.

note: If the @ProxyPasswordEnc argument is not defined, then the LiteSpeed core engine checks the local .ini files for the proxy parameters. If the proxy parameters are not detected, then the LiteSpeed core engine connects directly to the proxy servers.

@ProxyPort

The @ProxyPort argument is optional and contains the port number of the proxy server. The TCP/IP port values can be 1-65535.

note: If the @ProxyPort argument is not defined, then the LiteSpeed core engine checks the local .ini files for the proxy parameters. If the proxy parameters are not detected, then the LiteSpeed core engine connects directly to the proxy servers.

@read_write_filegroup

Specifies a partial backup, which includes all the read/write files in a database: the primary filegroup, any read/write secondary filegroups, and any specified read-only files or filegroups. If the database is read-only, @read_write_filegroups includes only the primary filegroup.

@restoreascompressed

Works in conjunction with @restoreasreadonly, creates a folder if it does not exist, and then compresses it. This argument accepts one of the following values:

  • 0—False (default)
  • 1—True

@restoreasreadonly

Instructs the restore operation to leave the database in read-only mode. This argument accepts one of the following values:

  • 0—False (default)
  • 1—True

Using this option, you can restore a user database into an NTFS compressed folder or restore a tlog to a read-only database in a compressed folder.

NOTES:

  • When using an NTFS-compressed folder for a database, it can only be restored as read-only.
  • You can only use this feature on Windows NTFS file systems.

@returndetails

Generates a single-row result set.

  • 0—False (default)
  • 1—True

The result set contains the following details:

Column Name Data Type Description
Database nvarchar (128) Database name.
Operation nvarchar (30) Operation type: Backup or Restore.
Threads tinyint The number of threads used for a LiteSpeed backup.
CompressionLevel tinyint Compression level used for compressing the backup. The compression level can be NULL, if backed up with Adaptive Compression.
AdaptiveCompression nvarchar (max)

Adaptive Compression option used for compressing the backup: 'speed' or 'size'.

MaxTransferSize int Specifies the largest unit of transfer in bytes to be used between SQL Server and LiteSpeed. The possible values are multiples of 65536 bytes (64 KB) ranging up to 4,194,304 bytes (4 MB). The default is 1048576 (1 MB) .
BaseSize int The smallest chunk of memory LiteSpeed attempts to write to disk at any given time.
BufferCount smallint The number of SQL Server buffers available for a LiteSpeed operation.
StripeCount smallint Number of backup files in the stripe set.
OverlappedBuffers tinyint The number of buffers that any single VDI thread can use at a time.
CPUSeconds numeric (18, 3) Processor time used by the LiteSpeed operation.
ElapsedSeconds

numeric (18, 3)

Duration of the operation.
NativeSize bigint Backup size (in bytes) without LiteSpeed compression.
BackupSize bigint Size of the backup (in bytes).

Tip: In Toad, you can use Group Execute to produce a single result set for several server instances.

@rewind

Applies only to backing up and restoring tape. This argument accepts one of the following values:

  • 0—Leave the tape unwound (default)

  • 1—Rewind the tape after writing/reading

@throttle

Specifies the maximum CPU usage allowed. The argument accepts an integer value between 1 and 100. The default value is 100. This is the percentage of the total amount of CPU usage (across all enabled processors) available.

TIP: Before you start tuning the CPU Throttle or Affinity parameters to adjust backup performance, try limiting the number of threads. If you decide to use an affinity value other than default, it is recommended that you limit the threading as well. You may also want to consider using Adaptive Compression to maintain backup performance. For more information, see Adaptive Compression.

@tsmarchive

Specifies to store the backup as a TSM archive. This argument accepts one of the following values:

  • 0—False (default)
  • 1—True

@tsmclientnode

Specifies the TSM server LiteSpeed connects to during backups and restores. Not required, if specified in the options file or if backing up with the Passwordaccess Generate option.

@tsmclientownerpwd

Specifies the TSM client owner user password. Not required, if specified in the options file or if backing up with the Passwordaccess Generate option.

@tsmconfigfile

Specifies the TSM configuration file.

@tsmobject

Defines the TSM filespace, high level and low level. This argument accepts the following format:

tsm_filespace\tsm_high_level\tsm_low_level

where:

  • tsm_filespace is the logical space on the TSM server that contains a group of files. It can be the drive label name or UNC name.

  • tsm_high_level specifies the directory path in which the file belongs.

  • tsm_low_level specifies actual name of the file.

NOTE: You may only store one item the location specified by this argument. It is not possible to append an object to this location. You can use the -I command-line argument or @init to back up to a non-unique location.

@tsmpointintime

Specifies the date for restore/to filter results. If it is not passed, LiteSpeed will choose the most recent archived backup. The format is yyyy-mm-dd hh:mm:ss.

NOTE: If the backup was a striped backup and the point-in-times of the various striped files are different (rare but can be different a second or so), then the most recent of the times must be chosen.

@unload

Applies to tape backups and restores. This argument accepts one of the following values:

  • 0—Keep tape loaded (default)

  • 1—Unload and eject tape from the drive after operation

@UseSSL

The @UseSSL argument specifies that the connection uses SSL security. This argument accepts one of the following values:

  • 0—Do not use SSL
  • 1—Use SSL (default)

@with

Each @with argument should be a syntactically complete and correct statement. Please refer to the SQL Server Transact-SQL backup and restore documentation for the syntax and usage.

The supported formats are:

  • @with='PARAMETER'
  • @with='PARAMETER=''accepted_value'''

NOTES:

  • Extended stored procedure arguments are limited to 255 characters. If you need more than 255 characters, use multiple @with arguments.
  • Do not supply the @with parameter if no additional features are required.

This extended stored procedure accepts the following @with parameters:

Parameter

Description

KEEP_REPLICATION

Instructs the restore operation to keep the replication settings when restoring a published database to a server other than that on which it was created (used when setting up replication with log shipping). You cannot specify this parameter with NORECOVERY.

MOVE

MOVE = ''logical_file_name'' TO ''operating_system_file_name''

Specifies that the given logical_file_name should be moved to operating_system_file_name. By default, the logical_file_name is restored to its original location.

If you use xp_restore_database to copy a database to the same or different server, the MOVE parameter may be needed to relocate the database files and to avoid collisions with existing files. Each logical file in the database can be specified in different MOVE statements.

Example:

EXEC master.dbo.xp_restore_database @database = 'MyDB'

, @filename = 'C:\MSSQL\Backup\MyDB_Backup.BAK'

, @with = 'MOVE ''MyDB_Data'' TO ''C:\MSSQL\Data\MyDB_data.MDF'''

, @with = 'MOVE ''MyDB_Data2'' TO ''C:\MSSQL\Data\MyDB_data2.NDF'''

, @with = 'MOVE ''MyDB_Log'' TO ''C:\MSSQL\Data\MyDB_log.LDF'''

NOTE: Use xp_restore_filelistonly to obtain a list of the logical files from the backup set. xp_restore_filelistonly

NORECOVERY

Instructs the restore operation to not roll back any uncommitted transactions. Either the NORECOVERY or STANDBY option must be specified if another transaction log has to be applied. If NORECOVERY, RECOVERY, or STANDBY is not specified, RECOVERY is the default.

SQL Server requires that the WITH NORECOVERY option is used on all but the final xp_restore_log statement when restoring a database backup and multiple transaction logs using LiteSpeed, or when multiple xp_restore_database or xp_restore_log statements are needed (for example, a full database backup followed by a differential database backup).

NOTE: When specifying the NORECOVERY option, the database is not usable in this intermediate, non-recovered state.

When used with a file or filegroup restore operation, NORECOVERY forces the database to remain in the restoring state after the restore operation. This is useful in either of these situations:

  • a restore script is being run and the log is always being applied.

  • a sequence of file restores is used and the database is not intended to be usable between two of the restore operations.

PARTIAL

Specifies a partial restore operation.

The granularity of the partial restore operation is the database filegroup. The primary file and filegroup are always restored, along with the files that you specify and their corresponding filegroups. The result is a subset of the database. Filegroups that are not restored are marked as offline and are not accessible.

RECOVERY

Instructs the restore operation to roll back any uncommitted transactions. After the recovery process, the database is ready for use.

If subsequent LiteSpeed restore operations (xp_restore_log or xp_restore_database from differential) are planned, NORECOVERY or STANDBY should be specified instead.

If NORECOVERY, RECOVERY, or STANDBY is not specified, RECOVERY is the default.

When restoring backup sets from an earlier version of SQL Server, a database upgrade may be required. This upgrade is performed automatically when WITH RECOVERY is specified.

REPLACE

Instructs LiteSpeed to create the specified database and its related files even if another database already exists with the same name. The existing database is deleted.

When the this option is not specified, LiteSpeed performs a check to ensure that the database is not restored to the current server if:

  • the database named in the xp_restore_database statement already exists on the current server, and

  • the database name is different from the database name recorded in the LiteSpeed backup set.

LiteSpeed will overwrite an existing file which cannot be verified as belonging to the database being restored. Normally, LiteSpeed will refuse to overwrite pre-existing files.

RESTRICTED_USER

When used in conjunction with recovery (another with param and the default) leaving a usable database, this restricts access for the restored database to members of the db_owner, dbcreator, or sysadmin roles.

STANDBY

STANDBY = ''undo_file_name''

Specifies the undo file name so the recovery effects can be undone. The size required for the undo file depends on the volume of undo actions resulting from uncommitted transactions. If you do not specify NORECOVERY, RECOVERY, or STANDBY, LiteSpeed defaults to RECOVERY.

STANDBY allows a database to be brought up for read-only access between transaction log restores and can be used with either warm standby server situations or special recovery situations in which it is useful to inspect the database between log restores.

If the specified undo file name does not exist, LiteSpeed creates it. If the file does exist, LiteSpeed overwrites it.

The same undo file can be used for consecutive LiteSpeed restores of the same database.

NOTE: If free disk space is exhausted on the drive containing the specified undo file name, the LiteSpeed restore operation stops.

STATS

Displays a message each time a percentage of the activity completes. The default is 10%.
CHECKSUM

Causes checksums to be verified when a LiteSpeed backup is created.

NOTE: When you restore a backup containing checksum, it is automatically checked. If you do not want to check the checksums during a restore, supply 'NO_CHECKSUM' .

PASSWORD Specifies the password for the backup set.

@NoOutput

Disable output information for the procedure

  1. 0 - Output information enabled (default).
  2. 1 - Output information disabled

Examples

Standard Database Restore

EXEC master.dbo.xp_restore_database
@database = 'MyDB'
, @filename= 'C:\MSSQL\Backup\MyDB_Backup.BAK'

Restore Database with NoRecovery

EXEC master.dbo.xp_restore_database
@database='MyDB'
, @filename='C:\MSSQL\Backup\MyDB_Backup.BAK'
, @with='NORECOVERY'

Restore an Encrypted Backup

EXEC master.dbo.xp_restore_database
@database='MyDB'
, @filename='C:\MSSQL\Backup\MyDB_Backup.BAK'
, @encryptionkey='Password'

Restore Files

exec master.dbo.xp_restore_database
@database = 'MyDB'
, @filename = 'C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\Backup\MyDB_200909111303_file.bak'
, @filenumber = 1
, @file = 'file1'
, @file = 'file2'

Restore a Filegroup and a File

exec master.dbo.xp_restore_database
@database = 'MyDB'
, @filegroup = 'PRIMARY'
, @file = 'file1'
, @filename = 'C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\Backup\MyDB_200909111243_filegroup.bak'

Restore Database with Move

EXEC master.dbo.xp_restore_database 
@database='MyDB'
, @filename = 'C:\MSSQL\Backup\MyDB_Backup.BAK'
, @with = 'MOVE ''MyDB_Data'' TO ''C:\MSSQL\Data\MyDB_Data.MDF'''
, @with = 'MOVE ''MyDB_log'' TO ''C:\MSSQL\Data\MyDB_Log.LDF'''

Restore Database from Tape

EXEC master.dbo.xp_restore_database
@database = 'MyDB'
, @filename='\\.\TAPE0'
, @filenumber = 2
, @rewind = 1
, @unload = 0

Restore a TSM archive

EXEC master.dbo.xp_restore_database
@database= 'Prod'
, @tsmclientnode = 'ClusterGroup'
, @tsmclientownerpwd= 'test16'
, @tsmobject= 'SLS_Mar\Prod\(16)Thursday_14:14'
, @tsmconfigfile= 'C:\Program Files\Tivoli\tsm\baclient\dsm.opt'
, @tsmpointintime='2006-03-16 14:49:35'
, @tsmarchive=1

Restore Database from Amazon S3

EXEC master.dbo.xp_restore_database
@CloudVendor = N'AmazonS3'
, @Database = N'AA_3_restored33'
, @FileName = N'AA_3_1.bak'
, @FileNumber = 1
, @CloudBucketName = N'aabucket1'
, @CloudAccessKey = N'***' -- my key
, @CloudSecretKey = N'***' -- my key
, @CloudRegionName = N'us-west-2' -- us-east-1, us-west-2, us-west-1, eu-west-1, ap-southeast-1, ap-southeast-2, ap-northeast-1, sa-east-1
, @With = N'MOVE ''AA_3'' TO ''E:\Databases.SQL2005\AA_3_restored11.mdf'', MOVE ''AA_3_log'' TO ''E:\Databases.SQL2005\AA_3_restored11_log.ldf'', REPLACE'
, @ProxyHost = N'proxy.sitelocal'
, @ProxyPort = 8080
, @ProxyLogin = N'DOMAIN\temp-xyz-MYtester'
, @ProxyPassword = N'***'

Returns

0 (success) or non-zero (failure). Return codes represent the native error number returned from SQL Server for any errors encountered during the operation.

To capture the output message, run the following:

declare @rmsg varchar(999)
exec master..<procedure_name> <arguments>, @resultmsg=@rmsg output
select @rmsg

To capture the output message and the result code, run the following:

declare @rc int
declare @rmsg varchar(999)
exec master..<procedure_name> <arguments>, @resultmsg=@rmsg output, @resultcode=@rc output
select @rc, @rmsg

 

Related Topic

Documentos relacionados

The document was helpful.

Seleccionar calificación

I easily found the information I needed.

Seleccionar calificación