Database Options and sp_dboption

There are additional considerations when using the database options of sp_dboption.

  • The abort tran on log full option determines the fate of a transaction that is running when the last-chance threshold is crossed in the log segment of the specified database. The default value is false, meaning that the transaction is suspended and is awakened only when space has been freed. If you change the setting to true, all user queries that need to write to the transaction log are killed until space in the log has been freed.

  • Setting the allow nulls by default option to true changes the default value of a column from not null to null, in compliance with the SQL standards. The Transact-SQL default value for a column is not null, meaning that null values are not allowed in a column unless null is specified in the create table or alter table column definition. allow nulls by default true reverses this.

    You cannot use allow nulls by default to change the nullibility of a column during select into statements. Instead, use convert to specify the nullibility of the resulting columns.

  • While the auto identity option is set to true (on), a 10-digit IDENTITY column is defined in each new table that is created without specifying either a primary key, a unique constraint, or an IDENTITY column. The column is not visible when you select all columns with the select * statement. To retrieve it, you must explicitly mention the column name, SYB_IDENTITY_COL, in the select list.

    To set the precision of the automatic IDENTITY column, use the size of auto identity column configuration parameter.

    Though you can set auto identity to true in tempdb, it is not recognized or used, and temporary tables created there do not automatically include an IDENTITY column.

    For a report on indexes in a particular table that includes the IDENTITY column, execute sp_helpindex.

  • While the dbo use only option is set to true (on), only the database’s owner can use the database.

  • When the ddl in tran option is set to true (on), you can use certain data definition language commands in transactions. If ddl in tran is true in a particular database, commands such as create table, grant, and alter table are allowed inside transactions in that database. If ddl in tran is true in the model database, the commands are allowed inside transactions in all databases created after ddl in tran was set in model.

    Warning!   Data definition language (DDL) commands hold locks on system tables such as sysobjects. Avoid using them inside transactions; if you must use them, keep the transactions short.

    Using any DDL commands on tempdb within transactions may cause your system to grind to a halt. Always leave ddl in tran set to false in tempdb.

  • You can use these commands inside a user-defined transaction when the ddl in tran option is set to true:
    • alter table – clauses other than partition and unpartition are allowed

    • create default

    • create index

    • create procedure

    • create rule

    • create schema

    • create table

    • create trigger

    • create view

    • drop default

    • drop index

    • drop procedure

    • drop rule

    • drop table

    • drop trigger

    • drop view

    • grant

    • revoke

  • You can never use these commands inside a user-defined transaction:
    • alter table

    • alter table...lock

    • alter table...partition

    • alter table...unpartition

    • create database

    • disk init

    • dump database

    • dump transaction

    • drop database

    • load database

    • load transaction

    • select into

    • truncate table

    • update statistics

    In addition, system procedures that create temporary tables or change the master database cannot be used inside user-defined transactions.

  • You may enable deferred table allocation for the model database, but not for any other system databases, including master, sybsystemprocs, sybsystemdb, or for any temporary databases.

  • identity in nonunique index automatically includes an IDENTITY column in a table’s index keys, so that all indexes created on the table are unique. This database option makes logically nonunique indexes internally unique, and allows these indexes to be used to process updatable cursors and isolation level 0 reads.

    The table must already have an IDENTITY column for the identity in nonunique index option to work, either from a create table statement or by setting the auto identity database option to true before creating the table.

    Use identity in nonunique index if you plan to use cursors and isolation level 0 reads on tables with nonunique indexes. A unique index ensures that the cursor is positioned at the correct row the next time a fetch is performed on that cursor. If you plan to use cursors on tables with unique indexes and any isolation level, you may want to use the unique auto_identity index option.

    Do not confuse the identity in nonunique index option with unique auto_identity index, which is used to add an IDENTITY column with a unique, nonclustered index to new tables.

    For a report on indexes in a particular table that includes the IDENTITY column, execute sp_helpindex.

  • no free space acctg suppresses free-space accounting and execution of threshold actions for data segments. Setting no free space acctg to true speeds recovery time because speeds recovery time because the free-space counts are not recomputed for data segments.

  • The no chkpt on recovery option is set to true (on) when an up-to-date copy of a database is kept. In these situations, there is a “primary” and a “secondary” database. Initially, the primary database is dumped and loaded into the secondary database. Then, at intervals, the transaction log of the primary database is dumped and loaded into the secondary database.

    If this option is set to false (off), the default condition, a checkpoint record is added to a database after it is recovered when you restart the SAP ASE server. This checkpoint, which ensures that you need not re-run the recovery mechanism unnecessarily, changes the sequence number and causes a subsequent load of the transaction log from the primary database to fail.

    Setting this option to true (on) for the secondary database causes it not to get a checkpoint from the recovery process so that subsequent transaction log dumps from the primary database can be loaded into it.

  • The read only option means that users can retrieve data from the database, but cannot modify any data.

  • select into/bulkcopy/pllsort must be set to on to perform operations that do not keep a complete record of the transaction in the log, which include:
    • Using the writetext utility.

    • Doing a select into a permanent table.

    • Doing a “fast” bulk copy with bcp. By default, fast bcp is used on tables that do not have indexes.

    • Performing a parallel sort.

    A transaction log dump cannot recover these minimally logged operations, so dump transaction to a dump device is prohibited. However, you can still use dump transaction...with no_log and dump transaction...with truncate_onlyAfter non-logged operations are completed, set select into/bulk copy/pllsort to false (off) and issue dump database.

    Issuing the dump transaction statement after unlogged changes have been made to the database with select into, bulk copy, or parallel sort produces an error message instructing you to use dump database instead. The writetext command does not have this protection.

    You do not have to set the select into/bulkcopy/pllsort option to true in order to select into a temporary table, since tempdb is never recovered. The option need not be set to true in order to run bcp on a table that has indexes, because tables with indexes are always copied with the slower version of bulk copy and are logged.

    Setting select into/bulkcopy/pllsort does not block log dumping, but making minimally logged changes to data does block the use of a regular dump transaction. .

    By default, select into/bulkcopy/pllsort is turned off in newly created databases. To change the default, turn this option on in the model database.

  • When single user is set to true, only one user at a time can access the database (single-user mode).

    You cannot set single user to true in a user database from within a stored procedure or while users have the database open. You cannot set single user to true for tempdb.

  • The trunc log on chkpt option means that if the transaction log has more than 50 rows of committed transactions, the transaction log is truncated (the committed transactions are removed) every time the checkpoint checking process occurs (usually more than once per minute). When the database owner runs checkpoint manually, however, the log is not truncated. It may be useful to turn this option on while doing development work, to prevent the log from growing.

    While the trunc log on chkpt option is on, dump transaction to a dump device is prohibited, since dumps from the truncated transaction log cannot be used to recover from a media failure. Issuing the dump transaction statement produces an error message instructing you to use dump database instead.

    trunc log on chkpt is off in newly created databases. To change the default, turn this option on in the model database.

    Warning!   If you set trunc log on chkpt on in model, and you need to load a set of database and transaction logs into a newly created database, be sure to turn the option off in the new database.
  • The delayed commit option is disabled by default. When this is enabled, all local transactions use delayed commits. That is, at the time of commit, control returns to the client without waiting for the I/O on the log pages to complete, and the I/O is not issued on the last log buffer for delayed commit transactions. Delayed commits are not used when both delayed commit and ALS options are enabled for a database.

  • When the unique auto_identity index option is set to true, it adds an IDENTITY column with a unique, nonclustered index to new tables. By default, the IDENTITY column is a 10-digit numeric datatype, but you can change this default with the size of auto identity column configuration parameter. As with auto identity, the IDENTITY column is not visible when you select all columns with the select * statement. To retrieve it, you must explicitly mention the column name, SYB_IDENTITY_COL, in the select list.

    If you need to use cursors or isolation level 0 reads with nonunique indexes, use the identity in nonunique index option.

    Though you can set unique auto_identity index to true in tempdb, it is not recognized or used, and temporary tables created there do not automatically include an IDENTITY column with a unique index.

    The unique auto_identity index option provides a mechanism for creating tables that have an automatic IDENTITY column with a unique index that can be used with updatable cursors. The unique index on the table ensures that the cursor is positioned at the correct row after a fetch. (If you are using isolation level 0 reads and need to make logically nonunique indexes internally unique so that they can process updatable cursors, use the identity in nonunique index option.)

    In some cases, the unique auto_identity index option can avoid the Halloween problem for the following reasons:
    • Users cannot update an IDENTITY column; hence, it cannot be used in the cursor update.

    • The IDENTITY column is automatically created with a unique, nonclustered index so that it can be used for the updatable cursor scan.

    For more information about the Halloween problem, IDENTITY columns, and cursors, see Cursors: Accessing Data in the Transact-SQL Users Guide and Optimization for Cursors in Performance and Tuning Series: Query Processing and Abstract Plans.

    Do not confuse the unique auto_identity index option with the identity in nonunique index option, which is used to make all indexes in a table unique by including an IDENTITY column in the table’s index keys.