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.
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}]
dump tran[saction] database_name with truncate_only
dump tran[saction] database_name with no_log
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}}]
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] } ]
dump transaction database_name using config = configuration_name [with { verify [= header | full] }]
Any other parameters are explicitly specified in the command override the values specified by the dump configuration.
You cannot specify a stripe directory as a parameter for the command if you use a dump configuration. The SAP ASE server creates the dump files in the stripe directory specified by the dump configuration. Dump file names use this convention:
Database_Name.Dump_Type.Date-Timestamp.StripeID
is a number between 0 and 9, 100, or 101. For single-digit compression levels, 0 indicates no compression, and 9 provides the highest level of compression. Compression levels of 100 and 101 provide a faster, more efficient compression mode, with 100 providing faster compression and 101 providing better compression. If you do not specify compression_level, the SAP ASE server does not compress the dump.
For more information about the compress option, see Backing Up and Restoring User Databases in the System Administration Guide.
A general rule for calculating capacity is to use 70 percent of the manufacturer’s maximum capacity for the device, leaving 30 percent for overhead, such as record gaps and tape marks. This rule works in most cases, but may not work in all cases because of differences in overhead across vendors and devices.
On UNIX platforms that cannot reliably detect the end-of-tape marker, you must indicate how many kilobytes can be dumped to the tape. You must supply a capacity for dump devices specified as a physical path name. If a dump device is specified as a logical device name, the Backup Server uses the size parameter stored in the sysdevices system table, unless you specify a capacity.
The number_days must be a positive integer or 0, for dumps you can overwrite immediately. If you do not specify a retaindays value, Backup Server uses the server-wide tape retention in days value, set by sp_configure.
Use init when you want Backup Server to store or update tape device characteristics in the tape configuration file. See the System Administration Guide.
If you use dump tran with no_truncate you must follow it with dump database, not with another dump tran. If you load a dump generated using the no_truncate option, the SAP ASE server prevents you from loading any subsequent dump.
On operating systems that offer an operator terminal feature, volume change messages are always sent to the operator terminal on the machine on which the Backup Server is running. Use client to route other Backup Server messages to the terminal session that initiated the dump database.
On operating systems (such as UNIX) that do not offer an operator terminal feature, messages are sent to the client that initiated the dump database. Use operator_console to route messages to the terminal on which the Backup Server is running.
If other parameters are explicitly specified in the command, they override the parameter values specified by the dump configuration.
You cannot specify a stripe directory as a parameter for the command if you use a dump configuration. The SAP ASE server creates the dump files in the stripe directory specified by the dump configuration. The dump files are named using this convention:
Database Name.Dump Type.Date-Timestamp.StripeID
dump transaction pubs2 to "/dev/nrmt0"
dump transaction mydb to "/dev/nrmt4" at REMOTE_BKP_SERVER stripe on "/dev/nrmt5" at REMOTE_BKP_SERVER with init, retaindays = 14
dump tran inventory_db to dev1 with standby_access
dump transaction pubs2 to "syb_tsm::demo2.2" with compression = 100
dump transaction testdb using config = 'dmp_cfg2' with passwd = 'my_pass01' go
dump transaction testdb using config = 'dmp_cfg2' with compression = 6 go
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 |
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.
ANSI SQL – Compliance level: Transact-SQL extension.
The permission checks for dump transaction differ based on your granular permissions settings.
Setting | Description |
---|---|
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:
|
Values in event and extrainfo columns of sysaudits are:
Information | Values |
---|---|
Event | 35 |
Audit option | dump |
Command or access audited | dump transaction |
Information in extrainfo |
|