dump transaction

Makes a copy of a transaction log, and removes the inactive portion of the log, if the dump transaction command is not running concurrently with another dump database.

See the Tivoli Storage Manager (TSM) syntax for dump tranaction syntax when Tivoli is licensed at your site.

Syntax

To make a routine log dump:
dump tran[saction] database_name 
	to [compress::[compression_level::]]stripe_device
		[at backup_server_name]
		[density = density_value, 
		blocksize = number_bytes,
		capacity = number_kilobytes, 
		dumpvolume = volume_name,
		file = file_name]
	[stripe on [compress::[compression_level::]]stripe_device
		[at backup_server_name]
		[density = density_value, 
		blocksize = number_bytes,
		capacity = number_kilobytes, 
		dumpvolume = volume_name,
		file = file_name]]
	[[stripe on [compress::[compression_level::]]stripe_device 
		[at backup_server_name]
		[density = density_value, 
		blocksize = number_bytes,
		capacity = number_kilobytes, 
		dumpvolume = volume_name,
		file = file_name]]...]
	[with {
		density = density_value, 
		blocksize = number_bytes,
		capacity = number_kilobytes, 
		compression = compress_level,
		dumpvolume = volume_name,
		file = file_name,
		[dismount | nodismount],
		[nounload | unload],
		retaindays = number_days,
		[noinit | init],
		notify = {client | operator_console}, 
		standby_access}]
To truncate the log without making a backup copy:
dump tran[saction] database_name 
	with truncate_only
To truncate a log that is filled to capacity. Use only as a last resort, as you will lose the contents of your log:
dump tran[saction] database_name 
	with no_log 
To back up the log after a database device fails:
dump tran[saction] database_name 
	to [compress::[compression_level::]]stripe_device
		[at backup_server_name]
		[density = density_value, 
		blocksize = number_bytes,
		capacity = number_kilobytes, 
		dumpvolume = volume_name,
		file = file_name]
	[stripe on [compress::[compression_level::]]stripe_device 
		[at backup_server_name]
		[density = density_value, 
		blocksize = number_bytes,
		capacity = number_kilobytes, 
		dumpvolume = volume_name,
		file = file_name]]
	[[stripe on [compress::[compression_level::]]stripe_device
		[at backup_server_name]
		[density = density_value, 
		blocksize = number_bytes,
		capacity = number_kilobytes, 
		dumpvolume = volume_name,
		file = file_name]]...]
	[with {
		density = density_value, 
		blocksize = number_bytes,
		capacity = number_kilobytes, 
		compression = compress_level
		dumpvolume = volume_name,
		file = file_name,
		[dismount | nodismount],
		[nounload | unload],
		retaindays = number_days,
		[noinit | init],
		no_truncate, 
		notify = {client | operator_console}}]
To copy the transaction log when the Tivoli Storage Manager provides backup services:
dump transaction database_name 
	to "syb_tsm::object_name"
		[blocksize = number_bytes]
	[stripe on "[syb_tsm::]object_name"
		[blocksize = number_bytes]]...]
	[with {
		blocksize = number_bytes,
		compression = compress_level,
		passwd = password,
		[noinit | init],
		notify = {client | operator_console},
		verify[ = header | full]
		} ]
To dump a transaction based on the settings specified in a configuration file:
dump transaction database_name
	using config = configuration_name
	[with {
		verify [= header | full]
		}] 

Parameters

Examples

Usage

If you use sp_hidetext followed by a cross-platform dump and load, you must manually drop and re-create all hidden objects.

The dump transaction command takes into account when a device is mirrored and will store the path to mirror devices along with regular devices in the dump header. The sybdumptran utility first attempts to open the primary device, and in the event the primary device cannot be opened, the mirrored device is opened, if one exists.     

The commands and system procedures used to back up databases and logs are:

To

Use

Make routine dumps of the entire database, including the transaction log.

dump database

Make routine dumps of the transaction log, then truncate the inactive portion. The inactive portion of the log is not truncated if dump transaction is running concurrently with dump database.

dump transaction

Dump the transaction log after failure of a database device.

dump transaction with no_truncate

Truncate the log without making a backup.

Then copy the entire database.

dump transaction with truncate_only

dump database

Truncate the log after your usual method fails due to insufficient log space.

Then copy the entire database.

dump transaction with no_log

dump database

Respond to the Backup Server volume change messages.

sp_volchanged

See also:
  • Backing Up and Restoring User Databases in the System Administration Guide.

  • sp_addumpdevice, sp_dboption, sp_dropdevice, sp_helpdevice, sp_hidetext, sp_logdevice, sp_volchanged in Reference Manual: Procedures

  • User documentation for Tivoli Storage Manager for more information about creating back-ups when TSM is supported at your site.

Standards

ANSI SQL – Compliance level: Transact-SQL extension.

Permissions

The permission checks for dump transaction differ based on your granular permissions settings.

SettingDescription
Enabled

With granular permissions enabled, you must be the database owner, or a user with dump database privilege or own database privilege on the database.

Disabled
With granular permissions disabled, you must be the database owner or a user with any of these roles:
  • sa_role, or,

  • replication_role, or,

  • oper_role

Auditing

Values in event and extrainfo columns of sysaudits are:

InformationValues
Event

35

Audit option

dump

Command or access audited

dump transaction

Information in extrainfo
  • Roles – current active roles

  • Keywords or options – NULL

  • Previous value – NULL

  • Current value – NULL

  • Other information – NULL

  • Proxy information – original login name, if set proxy is in effect

Related reference
dump database
load database
load transaction
online database