sa_server_option System Procedure

Overrides a server option while the server is running..

Syntax

sa_server_option( opt , val )

Arguments

  • opt – Use this CHAR(128) parameter to specify a server option name.
  • val – Use this CHAR(128) parameter to specify the new value for the server option.

Remarks

Option Name Values Additional information
AutoMultiProgrammingLevel YES, NO

Default is YES.

When set to YES, the database server automatically adjusts its multiprogramming level, which controls the maximum number of tasks that can be active at a time. If you choose to control the multiprogramming level manually by setting this option to NO, you can still set the initial, minimum, and maximum values for the multiprogramming level.

AutoMultiProgrammingLevelStatistics YES, NO

Default is NO.

When set to YES, statistics for automatic multiprogramming level adjustments appear in the database server message log.

CacheSizingStatistics YES, NO

Default is NO.

When set to YES, display cache information in the database server messages window whenever the cache size changes.

CollectStatistics YES, NO

Default is YES.

When set to YES, the database server collects Performance Monitor statistics.

ConnsDisabled YES, NO

Default is NO.

When set to YES, no other connections are allowed to any databases on the database server.

ConnsDisabledForDB YES, NO

Default is NO.

When set to YES, no other connections are allowed to the current database.

ConsoleLogFile filename

The name of the file used to record database server message log information. Specifying an empty string stops logging to the file. Double any backslash characters in the path because this value is a SQL string.

ConsoleLogMaxSize file-size (bytes)

The maximum size, in bytes, of the file used to record database server message log information. When the database server message log file reaches the size specified by either this property or the -on server option, the file is renamed with the extension .old appended (replacing an existing file with the same name if one exists). The database server message log file is then restarted.

CurrentMultiProgrammingLevel integer

Default is 20.

Sets the multiprogramming level of the database server.

DatabaseCleaner ON, OFF

Default is ON.

Do not change the setting of this option except on the recommendation of Technical Support.

DeadlockLogging ON, OFF, RESET, CLEAR

Default is OFF.

Controls deadlock logging. The value deadlock_logging is also supported. The following values are supported:
  • ON – Enables deadlock logging.
  • OFF – Disables deadlock logging and leaves the deadlock data available for viewing.
  • RESET – Clears the logged deadlock data, if any exists, and then enables deadlock logging.
  • CLEAR – Clears the logged deadlock data, if any exists, and then disables deadlock logging.
Once deadlock logging is enabled, you can use the sa_report_deadlocks system procedure to retrieve deadlock information from the database.
DebuggingInformation YES, NO

Default is NO.

Displays diagnostic messages and other messages for troubleshooting purposes. The messages appear in the database server messages window.

DiskSandbox ON, OFF

Default is OFF.

Sets the default disk sandbox settings for all databases started on the database server that do not have explicit disk sandbox settings. Changing the disk sandbox settings by using the sa_server_option system procedure does not affect databases already running on the database server. To use the sa_server_option system procedure to change disk sandbox settings, you must provide the secure feature key for the manage_disk_sandbox secure feature.

DropBadStatistics YES, NO

Default is YES.

Allows automatic statistics management to drop statistics that return bad estimates from the database.

DropUnusedStatistics YES, NO

Default is YES.

Allows automatic statistics management to drop statistics that have not been used for 90 consecutive days from the database.

IdleTimeout Integer (minutes)

Default is 240.

Disconnects TCP/IP connections that have not submitted a request for the specified number of minutes. This prevents inactive connections from holding locks indefinitely

IPAddressMonitorPeriod Integer (seconds)

The minimum value is 10 and the default is 0. For portable devices, the default value is 120.

Sets the time to check for new IP addresses in seconds.

LivenessTimeout Integer (seconds)

Default is 120.

A liveness packet is sent periodically across a client/server TCP/IP network to confirm that a connection is intact. If the network server runs for a LivenessTimeout period without detecting a liveness packet, the communication is severed.

MaxMultiProgrammingLevel Integer

Default is four times the value for CurrentMultiProgrammingLevel.

Sets the maximum database server multiprogramming level.

MessageCategoryLimit Integer

Default is 400.

Sets the minimum number of messages of each severity and category that can be retrieved using the sa_server_messages system procedure.

MinMultiProgrammingLevel Integer

Default is the minimum of the value of the -gtc server option and the number of logical CPUs on the computer.

OptionWatchAction MESSAGE, ERROR

Default is MESSAGE.

Specifies the action that the database server takes when an attempt is made to set an option in the list. When OptionWatchAction is set to MESSAGE, and an option specified by OptionWatchList is set, a message appears in the database server messages window indicating that the option being set is on the options watch list.When OptionWatchAction is set to ERROR, an error is returned indicating that the option cannot be set because it is on the options watch list.

You can view the current setting for this property by executing
SELECT DB_PROPERTY( 'OptionWatchAction' );
OptionWatchList Comma-separated list of database options
Specifies a comma-separated list of database options that you want to be notified about, or have the database server return an error for, when they are set. The string length is limited to 128 bytes. By default, it is an empty string. For example, the following command adds the automatic_timestamp, float_as_double, and tsql_hex_constant option to the list of options being watched:
CALL sa_server_option( 'OptionWatchList','automatic_timestamp,
float_as_double,tsql_hex_constant' );
You can view the current setting for this property by executing:
SELECT DB_PROPERTY( 'OptionWatchList' );
ProcedureProfiling YES, NO, RESET, CLEAR

Default is NO.

ProfileFilterConn connection-id

Instructs the database server to capture profiling information for a specific connection ID, without preventing other connections from using the database. When connection filtering is enabled, the value returned for SELECT PROPERTY( 'ProfileFilterConn' ) is the connection ID of the connection being monitored. If no ID has been specified, or if connection filtering is disabled, the value returned is -1.

ProcessorAffinity Comma-delimited list of processor numbers and/or ranges. The default is that all processors are used or the setting of the -gta option.

Instructs the database server which logical processors to use on Windows or Linux. Specify a comma-delimited list of processor numbers and/or ranges. If the lower endpoint of a range is omitted, then it is assumed to be zero. If the upper endpoint of a range is omitted, then it is assumed to be the highest CPU known to the operating system. The in_use column returned by the sa_cpu_topology system procedure contains the current processor affinity of the database server, and the in_use column indicates whether the database server is using a processor. Alternatively, you can query the value of the ProcessorAffinity database server property.

The database server might not use all of the specified logical processors in the following cases:
  • If one or more of the specified logical processors does not exist, or is offline.
  • If the license does not allow it.
If you specify an invalid processor ID, sa_server_option returns an error.
ProfileFilterUser user-id

Instructs the database server to capture profiling information for a specific user ID.

QuittingTime Valid date and time

Instructs the database server to shut down at the specified time.

RememberLastPlan YES, NO

Default is NO.

Instructs the database server to capture the long text plan of the last query executed on the connection. This setting is also controlled by the -zp server option.When RememberLastPlan is turned on, obtain the textual representation of the plan of the last query executed on the connection by querying the value of the LastPlanText connection property:
SELECT CONNECTION_PROPERTY( 'LastPlanText' );
RememberLastStatement YES, NO

Default is NO.

Instructs the database server to capture the most recently prepared SQL statement for each database running on the server. For stored procedure calls, only the outermost procedure call appears, not the statements within the procedure.When RememberLastStatement is turned on, you can obtain the current value of the LastStatement for a connection by querying the value of the LastStatement connection property:

SELECT CONNECTION_PROPERTY( 'LastStatement' ); 

When client statement caching is enabled, and a cached statement is reused, this property returns an empty string. When RememberLastStatement is turned on, the following statement returns the most recently-prepared statement for the specified connection:

SELECT CONNECTION_PROPERTY( 'LastStatement', connection-id ); 

The sa_conn_activity system procedure returns this same information for all connections.

Note: When -zl is specified, or when the RememberLastStatement server setting is turned on, any user can call the sa_conn_activity system procedure or obtain the value of the LastStatement connection property to find out the most recently-prepared SQL statement for any other user. Use this option with caution and turn it off when it is not required.
RequestFilterConn connection-id, -1

Filter the request logging information so that only information for a particular connection is logged. This filtering can reduce the size of the request log file when monitoring a database server with many active connections or multiple databases. You can obtain the connection ID by executing the following:

CALL sa_conn_info( );

To log a specific connection once you have obtained the connection ID, execute the following statement:

CALL sa_server_option( 'RequestFilterConn', connection-id );

Filtering remains in effect until it is explicitly reset, or until the database server is shut down. To reset filtering, use the following statement:

CALL sa_server_option( 'RequestFilterConn', -1 );
RequestFilterDB database-id, -1

Filter the request logging information so that only information for a particular database is logged. This can help reduce the size of the request log file when monitoring a server with multiple databases. You can obtain the database ID by executing the following statement when you are connected to the desired database:

SELECT CONNECTION_PROPERTY( 'DBNumber' );

To log only information for a particular database, execute the following statement:

CALL sa_server_option( 'RequestFilterDB', database-id );

Filtering remains in effect until it is explicitly reset, or until the database server is shut down. To reset filtering, use the following statement:

CALL sa_server_option( 'RequestFilterDB', -1 );
RequestLogFile filename

The name of the file used to record request information. Specifying an empty string stops logging to the request log file. If request logging is enabled, but the request log file was not specified or has been set to an empty string, the server logs requests to the database server messages window. Double any backslash characters in the path because this value is a SQL string.

When client statement caching is enabled, set the max_client_statements_cached option to 0 to disable client statement caching while the request log is captured, if the log will be analyzed using the tracetime.pl Perl script.

RequestLogging SQL, HOSTVARS, PLAN, PROCEDURES, TRIGGERS, OTHER, BLOCKS, REPLACE, ALL, YES, NONE, NO

Default is NONE.

This call turns on logging of individual SQL statements sent to the database server for use in troubleshooting with the database server -zr and -zo options. Values can be combinations of the following, separated by either a plus sign (+), or a comma:
  • PLAN – enables logging of execution plans (short form). If logging of procedures (PROCEDURES) is enabled, execution plans for procedures are also recorded.
  • HOSTVARS – enables logging of host variable values. If you specify HOSTVARS, the information listed for SQL is also logged.
  • PROCEDURES – enables logging of statements executed from within procedures.
  • TRIGGERS – enables logging of statements executed from within triggers.
  • OTHER – enables logging of additional request types not included by SQL, such as FETCH and PREFETCH. However, if you specify OTHER but do not specify SQL, it is the equivalent of specifying SQL+OTHER. Including OTHER can cause the log file to grow rapidly and could negatively impact server performance.
  • BLOCKS – enables logging of details showing when a connection is blocked and unblocked on another connection.
  • REPLACE – at the start of logging, the existing request log is replaced with a new (empty) one of the same name. Otherwise, the existing request log is opened and new entries are appended to the end of the file.
  • ALL – logs all supported information. This value is equivalent to specifying SQL+PLAN+HOSTVARS+PROCEDURES+TRIGGERS+OTHER+BLOCKS. This setting can cause the log file to grow rapidly and could negatively impact server performance.
  • NO or NONE – turns off logging to the request log.
You can view the current setting for this property by executing:
SELECT PROPERTY( 'RequestLogging' );
RequestLogMaxSize file-size (bytes)

The maximum size of the file used to record request logging information, in bytes. If you specify 0, then there is no maximum size for the request logging file, and the file is never renamed. This value is the default. When the request log file reaches the size specified by either the sa_server_option system procedure or the -zs server option, the file is renamed with the extension .old appended (replacing an existing file with the same name if one exists). The request log file is then restarted.

RequestLogNumFiles Integer

The number of request log file copies to retain.If request logging is enabled over a long period, the request log file can become large. The -zn option allows you to specify the number of request log file copies to retain

RequestTiming YES, NO

Default is NO.

Instructs the database server to maintain timing information for each new connection. This feature is turned off by default. When it is turned on, the database server maintains cumulative timers for all new connections that indicate how much time the connection spent in the server in each of several states. The change is only effective for new connections, and lasts for the duration each connection.You can use the sa_performance_diagnostics system procedure to obtain a summary of this timing information, or you can retrieve individual values by inspecting the following connection properties:
  • ReqCountUnscheduled
  • ReqTimeUnscheduled
  • ReqCountActive
  • ReqTimeActive
  • ReqCountBlockIO
  • ReqTimeBlockIO
  • ReqCountBlockLock
  • ReqTimeBlockLock
  • ReqCountBlockContention
  • ReqTimeBlockContention
When the RequestTiming server property is on, there is a small overhead for each request to maintain the additional counters.
rlv_auto_merge ON, OFF

The default is ON.

Enables or disables automatic merges of the RLV store into the IQ main store for row-level versioning-enabled tables.

If rlv_auto_merge is OFF, no automated merges of the RLV and IQ main stores occur. This implies that you assume responsibility to manually merge data so that the RLV store gets synced to the IQ main store before the upper rlv_memory_mb threshold is reached.

rlv_memory_mb The minimum value is 1 MB. The maximum value is 2048. Any other value will set the amount of memory to 2048 MB.

Specifies the maximum amount of memory (the RLV store), in MB, to reserve for row-level versioning . The default value is 2048 MB.

SecureFeatures feature-list

Allows you to manage secure features for a database server that is already running. The feature-list is a comma-separated list of feature names or feature sets. By adding a feature to the list, you limit its availability. To remove items from the list of secure features, specify a minus sign (-) before the secure feature name.

To call sa_server_option('SecureFeatures',...), the connection must have the ManageFeatures secure feature enabled on the connection. The -sf key (the system secure feature key) enables ManageFeatures, as well as all of the other features. So if you used the system secure feature key, then changing the set of SecureFeatures will not have any effect on the connection. But if you used another key (for example a key that had been created using the create_secure_feature_key system procedure) then your connection may be immediately affected by the change, depending on what other features are included in the key.

Any changes you make to allow or prevent access to features take effect immediately for the database server. The connection that executes the sa_server_option system procedure may or may not be affected, depending on the secure feature key the connection is using and whether or not it allows the connection access to the specified features.

For example, to secure two features, use the following syntax:

CALL sa_server_option('SecureFeatures', 'CONSOLE_LOG,WEBCLIENT_LOG' );

After executing this statement, the list of secure features is set according to what has been changed.

StatisticsCleaner ON, OFF

Default is ON.

The statistics cleaner fixes statistics that give bad estimates by performing scans on tables. By default the statistics cleaner runs in the background and has a minimal impact on performance.

Turning off the statistics cleaner does not disable the statistic governor, but when the statistics cleaner is turned off, statistics are only created or fixed when a query is run.

WebClientLogFile filename

The name of the web service client log file. The web service client log file is truncated each time you use the -zoc server option or the WebClientLogFile property to set or reset the file name. Double any backslash characters in the path because this value is a string.

WebClientLogging ON, OFF

Default is OFF.

This option enables and disables logging of web service clients. The information that is logged includes HTTP requests and response data. Specify ON to start logging to the web service client log file, and specify OFF to stop logging to the file.

Privileges

You must have the MANAGE PROFILING system privilege to use the following options, which are related to application profiling or request logging:

For all other options, your must have the SERVER OPERATOR system privilege.

Side effects

None.

Example

The following statement causes cache information to be displayed in the database server messages window whenever the cache size changes:

CALL sa_server_option( 'CacheSizingStatistics', 'YES' );

The following statement disallows new connections to the current database:

CALL sa_server_option( 'ConnsDisabledForDB', 'YES' );

The following statement enables logging of all SQL statements, procedure calls, plans, blocking and unblocking events, and starts a new request log:

CALL sa_server_option( 'RequestLogging', 'SQL+PROCEDURES+BLOCKS+PLAN+REPLACE' );