立即与支持人员聊天
与支持团队交流

LiteSpeed for SQL Server 8.9.8 - Integration with TSM Guide

xp_objectrecovery_executeselect

Execute SELECT statement queries against the backup files, which you can use for row-level restores. The SELECT results can be a table in a database, ship directory, or a .csv file.

This topic covers:

Syntax

View the SELECT query results

EXEC master.dbo.xp_objectrecovery_executeselect
(@filename = 'backup_file_name') [,...n]
[, @filenumber = n]
[, @encryptionkey = 'encryption_key']
[( , @logfilename = 'log_file_name'
[, @stripedlogfilename = 'striped_log_file_name'] [,...n]
[, @logencryptionkey = 'log_encryption_key']
[, @logfilenumber = n ] ) [,...n]]
[, @difffilename = 'diff_file_name'] [,...n]
[, @difffilenumber = n]
[, @diffencryptionkey= 'diff_encrypt_key']
[, @LSM = 'option' ]
{, @scripttext = 'script_text' |
, @scriptfilename = 'script_file_name'}
[, @destinationserver = 'dest_server_name']
[, @tempdirectory = 'recovery_temp_dir']
[, @disablelogprocessing = 0 | 1 ]

Restore the SELECT query results into a database

EXEC master.dbo.xp_objectrecovery_executeselect
(@filename = 'backup_file_name') [,...n]
[, @filenumber = n]
[, @encryptionkey = 'encryption_key']
[( , @logfilename = 'log_file_name'
[, @stripedlogfilename = 'striped_log_file_name'] [,...n]
[, @logencryptionkey = 'log_encryption_key']
[, @logfilenumber = n ] ) [,...n]]
[, @difffilename = 'diff_file_name'] [,...n]
[, @difffilenumber = n]
[, @diffencryptionkey= 'diff_encrypt_key']
[, @LSM = 'option' ]
{, @scripttext = 'script_text' |
, @scriptfilename = 'script_file_name'}
, @destinationtable = 'dest_table_name' 
[, @prefixtableobjects = N'prefix']
[, @suffixtableobjects = N'suffix']
, @destinationdatabase = 'database_name'
[, @destinationserver = 'dest_server_name']
[, @tempdirectory = 'recovery_temp_dir']
[, @onfilegroup = 'table_filegroup_name']
[, @textimageonfilegroup = 'blob_filegroup_name']
[, @disablelogprocessing = 0 | 1 ]

Recover the SELECT query results into a ship directory

EXEC master.dbo.xp_objectrecovery_executeselect
(@filename = 'backup_file_name') [,...n]
[, @filenumber = n]
[, @encryptionkey = 'encryption_key']
[( , @logfilename = 'log_file_name'
[, @stripedlogfilename = 'striped_log_file_name'] [,...n]
[, @logencryptionkey = 'log_encryption_key']
[, @logfilenumber = n ] ) [,...n]]
[, @difffilename = 'diff_file_name'] [,...n]
[, @difffilenumber = n]
[, @diffencryptionkey= 'diff_encrypt_key']
[, @LSM = 'option' ]
{, @scripttext = 'script_text' |
, @scriptfilename = 'script_file_name'}
, @destinationtable = 'dest_table_name' 
[, @prefixtableobjects = N'prefix']
[, @suffixtableobjects = N'suffix']
, @shipdirectory = 'recovery_ship_dir'
[, @onfilegroup = 'table_filegroup_name']
[, @textimageonfilegroup = 'blob_filegroup_name']
[, @disablelogprocessing = 0 | 1 ]

Recover the SELECT query results into a .csv file

EXEC master.dbo.xp_objectrecovery_executeselect
(@filename = 'backup_file_name') [,...n]
[, @filenumber = n]
[, @encryptionkey = 'encryption_key']
[( , @logfilename = 'log_file_name'
[, @stripedlogfilename = 'striped_log_file_name'] [,...n]
[, @logencryptionkey = 'log_encryption_key']
[, @logfilenumber = n ] ) [,...n]]
[, @difffilename = 'diff_file_name'] [,...n]
[, @difffilenumber = n]
[, @diffencryptionkey = 'diff_encrypt_key']
[, @LSM = 'option' ]
{, @scripttext = 'script_text' |
, @scriptfilename = 'script_file_name'}
, @destinationfilename = 'csv_file_name'
[, @disablelogprocessing = 0 | 1 ]

If the backup is stored in the cloud (Amazon S3) these parameters help us with access

[, @CloudBucketName = N'aabucket1']
[, @CloudAccessKey = N'***']
[, @CloudSecretKey = N'***']
[, @CloudRegionName = N'us-west-2']
[, @ProxyHost = N'proxy.sitelocal']
[, @ProxyPort = 8080]
[, @ProxyLogin = N'DOMAIN\temp-xyz-MYtester']
[, @ProxyPassword = N'***']

If the backup is stored in the cloud (Microsoft Azure) these parameters help us with access

@CloudVendor = N'AzureBlob',
@CloudBucketName = N'test',
@CloudAccessKeyEnc = N'*******',
@CloudSecretKeyEnc = N'******',
@UseSSL = 1,
@affinity = 0,
@logging = 0

If the backup is stored in the cloud (Google Storage) these parameters help us with access

@CloudVendor = N'GoogleStorage',
@CloudBucketName = N'test',
@CloudAccessKeyEnc = N'*******',
@CloudSecretKeyEnc = N'******',
@UseSSL = 1,
@affinity = 0,
@logging = 0

If the backup is stored in the cloud (S3 Compatible Storage) these parameters help us with access

@CloudVendor = N'S3Compatible',
@CloudBucketName = N'test',
@CloudAccessKeyEnc = N'*******',
@CloudSecretKeyEnc = N'******',
@CloudEndpoint = N'storageserver:port',
@UseSSL = 1,
@affinity = 0,
@logging = 0

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>

@backend

Object Level Recovery can restore tables using two different internal techniques to handle the record inserts.

The first and default method uses BCP files and a TSQL BULK INSERT statement. Object Level Recovery will write a BCP format file and an accompanying binary data file to the local file system. These files may become very large depending on the table size and will require permissions to write to a temporary directory. The default TEMP location can be set by using the @TempDirectory parameter or by setting a permanent temp location in the LiteSpeed configuration file.

An alternate insertion method can be specified to use Sql Server’s Sql Native Client capabilities. This method inserts row-data directly into the destination database bypassing any storage on the local file-system. To enable this method, use the parameter @backend='SQLNativeClient' (or -b 1 from the command line). To make this the default method set the value “BackEnd=SQLNativeClient” in the Object Level Recovery section of the LiteSpeed configuration file.

Regardless of the insertion method used, the batch size can be globally managed by setting the value “BulkImportBatchSize=<N>”. This will set the number of row inserts for each batched transaction.

@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.

@destinationdatabase

Specifies the destination database.

@destinationfilename

Name of comma separated file (.csv) that is generated instead restoring into a database. This is an ad hoc solution for users want to see the restored data in Excel. You can only use this argument for text data.

@destinationserver

Name of the destination server.

@destinationtable

Specifies the name of the destination table. LiteSpeed will not overwrite an existing table. If you select the same server instance and database as the original table, you must use a different table name.

NOTE: For Execute-Select operations, LiteSpeed will attempt to insert (append) all selected records into existing table.

@diffencryptionkey

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'

Equivalent to @encryptionkey, but used for differential backups instead of full backup files.

@difffilename

Name of backup file to restore. Used for differential backups instead of full backup files. You can supply multiple instances of this argument.

@difffilenumber

Identifies the backup file within the backup set. Equivalent to @filenumber, but used for differential backups instead of full backup files.

@disablelogprocessing

Instructs LiteSpeed to skip all transaction log backups and tail log processing. This may improve read and recovery times. This argument accepts one of the following values:

  • 0—False (Default).
  • 1—True. LiteSpeed will entirely ignore any transaction log backups specified and will not process the tail log.

@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'

@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

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.

@KeepComputedColumns

Instructs LiteSpeed to keep the computed columns with the object restore. This argument accepts one of the following values:

  • 0—False
  • 1—True

@logencryptionkey

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'

Equivalent to @encryptionkey, but used for transaction log backups.

@logfilename

Specifies location and name of the log backup file. You can supply multiple instances of this argument.

Syntax

@logfilenumber

Identifies the log backup file within the backup set. Equivalent to @filenumber, but used for log backups.

@LSM

Specifies handling for OLR LSM mapfile(s).

  • Create—Reads backup and creates a new mapfile. It will ignore attached LSM.
  • Keep—Does not delete mapfile(s) when complete.
  • Delete—Always deletes mapfile(s) when complete.

@OLRUDT

Create table script:

  • 0—Off. Create table with native types, if possible; othervise (CLR UDT) create with UDT.
  • 1—On. Create table with UDT (Default).

@onfilegroup

Filegroup with the object to restore.

@PersistLogProcessing

Instructs LiteSpeed to persist log processing, so the same database backup does not have to be processed for each Object Level Recovery operation. This argument accepts one of the following values:

  • 0—False (Default).
  • 1—True. LiteSpeed will persist transaction log backups specified and the tail log for future use. This option can offer a huge performance gain for working with databases with large tail logs that could possibly take a long time to process.

@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.

@scriptfilename

Name of the SELECT script file to be executed.

@scripttext

The text of the SELECT script to be executed. The SELECT statement is imbedded in a single-quoted string literal, and all single-quoted string literals in the SELECT statement need to be double single-quoted.  For example:

@scripttext = 'SELECT * FROM dbo.Customers WHERE City=''London'''

The single quoted string literal 'London' is double single-quoted.

You can also use SET QUOTED_IDENTIFIER OFF to allow double quotes. For example:

SET QUOTED_IDENTIFIER OFF
EXEC xp_objectrecovery_executeselect
@filename = 'C:\MSSQL\Backup\MyDB_Backup.BAK'
, @scripttext = "SELECT * FROM dbo.Customers WHERE City='London'"
, @destinationtable = 'dbo.CustomersInLondon'
, @destinationdatabase = 'MyDB'

@shipdirectory

Name of the ship directory. Use this argument when you want to restore the object later or at a different physical location.  This argument creates the following files in the ship directory:

  • CREATE <object_name>.sql

  • BULK INSERT <object_name>.sql

  • <object_name>.fmt

  • <object_name>.bcp

To restore the object, run the CREATE file first, and then run the BULK INSERT file. You will need to slightly modify the BULK INSERT file because of the .fmt and .bcp file path names.

Tip: You can zip the files and send them to someone else.

@stripedlogfilename

Specifies the striped log file name.

NOTE: The striped files for a given log backup must be specified before the next log backup set is specified.

@tempdirectory

Specifies a temporary directory for use with Object Level Recovery. Use this argument when the default Windows temp directory does not have enough free disk space for the restore process.

NOTE: You can specify the default temp directory using the TempPath parameter in the [LiteSpeed] section of the LiteSpeedSettings.ini file. (Usually, C:\Documents and Settings\All Users\Application Data\Quest Software\LiteSpeed\SQL Server\LiteSpeedSettings.ini.)

@textimageonfilegroup

Destination TEXTIMAGE_ON filegroup name. Used to restore a BLOB (binary large object).

@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.

Examples

View the SELECT query results

xp_objectrecovery_executeselect
@filename = 'D:\temp\LiteSpeedLocal.bak'
, @scripttext = 'select top (4)* from dbo.LiteSpeedActivity'

Restore the SELECT query results into a database using inline script

EXEC master.dbo.xp_objectrecovery_executeselect
@filename = 'C:\MSSQL\Backup\MyDB_Backup.BAK'
, @scripttext = 'SELECT * FROM dbo.Customers WHERE City=''London'''
, @destinationtable = 'dbo.CustomersInLondon'
, @destinationdatabase = 'MyDB'

Restore the SELECT query results into a database using script file

EXEC master.dbo.xp_objectrecovery_executeselect
@filename = 'C:\MSSQL\Backup\MyDB_Backup.BAK'
, @scriptfilename = 'C:\temp\SelectCustomerFromLondon.sql'
, @destinationtable = 'dbo.CustomersInLondon'
, @destinationdatabase = 'MyDB'
, @destinationserver = 'MyMachine\SQL2000'
, @tempdirectory = 'D:\temp'
, @onfilegroup = 'Secondary'
, @textimageonfilegroup = 'Secondary'

Restore the SELECT query results into ship directory

EXEC master.dbo.xp_objectrecovery_executeselect
@filename = 'C:\MSSQL\Backup\MyDB_Backup.BAK'
, @scriptfilename = 'C:\temp\SelectCustomerFromLondon.sql'
, @destinationtable = 'dbo.CustomersInLondon'
, @shipdirectory = 'C:\temp\London'

Restore the SELECT query results into a .csv file

EXEC master.dbo.xp_objectrecovery_executeselect
@filename = 'C:\MSSQL\Backup\MyDB_Backup.BAK'
, @scriptfilename = 'C:\temp\SelectCustomerFromLondon.sql'
, @destinationfilename = 'C:\temp\LondonCustomer.csv'

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 Topics

相关文档

The document was helpful.

选择评级

I easily found the information I needed.

选择评级