sp_configure

Description

Displays configuration parameters by group, their current values, their non-default value settings, the value to which they have most recently been set, and the amount of memory used by this setting. Displays only the parameters whose display level is the same as or below that of the user.

Syntax

sp_configure [configname [, configvalue] | group_name | 
	non_unique_parameter_fragment] 'drop instance' 
	[, instance_name] [display_nondefault_settings]
sp_configure "configuration file", 0, {"write" | "read" | "verify" | "restore"} 
	"file_name"

Parameters

configname

displays the current value, default value, most recently changed value, and amount of memory used by the setting for all parameters matching parameter.

configvalue

resets configname to configvalue and displays the current value, default value, configured value, and amount of memory used by configname.

sp_configure configname, 0, “default” resets configname to its default value and displays current value, default value, configured value, and amount of memory used by configname.

group_name

displays all configuration parameters in group_name, their current values, their default values, the value (if applicable) to which they have most recently been set, and the amount of memory used by this setting.

non_unique_parameter_fragment

displays all parameter names that match non_unique_parameter_fragment, their current values, default values, configured values, and the amount of memory used.

drop instance

allows you to drop an instance-specific configuration setting

instance_name

in cluster environments – indicates the instance for which you are setting the instance-specific options.

display_nondefault_settings

displays configuration options for which the configuration or run value is different from the default value.

write

creates file_name from the current configuration. If file_name already exists, a message is written to the error log and the existing file is renamed using the convention file_name.001, file_name.002, and so on. If you have changed a static parameter but have not restarted your server, “write” gives you the currently running value for that parameter.

read

performs validation checking on values contained in file_name and reads those values that pass validation into the server. If any parameters are missing from file_name, the current running values for those parameters are used.

verify

performs validation checking on the values in file_name.

restore

creates file_name with the values in sysconfigures. This is useful if all copies of the configuration file have been lost and you need to generate a new copy.

file_name

is the name of the file you want to use sp_configure on.

Examples

Example 1

Displays all configuration parameters by group, their current values, their default values, the value (if applicable) to which they have most recently been set, and the amount of memory used by this setting:

sp_configure

Example 2

Displays all configuration parameters that include the word “identity”:

sp_configure "identity"
Configuration option is not unique.

Parameter Name     Default Memory Used Config Value Run Value Unit Type
--------------     ------- ----------- ------------ --------- ------ ----
identity burning set     1         0           1        1     id    static
identity grab size       0         0           0        0     id    dyna
size of auto identit    10         0          10       10     bytes dyna
. . . 

Example 3

Sets the system recovery interval in minutes to 3 minutes:

sp_configure "recovery interval in minutes", 3
Parameter Name      Default Memory Used Config Value Run Value Unit Type
--------------       ------- ----------- ------------ --------- ------ ----
recovery interval   5        0          3            3         min   dyn

Configuration option changed. The SQL Server need not be rebooted since the option is dynamic.

Example 4

Resets the value for number of devices to the Adaptive Server default:

sp_configure "number of device", 0, "default"

Example 5

Configures four databases to be recovered concurrently, enter:

sp_configure "max concurrently recovered db", 4

Example 6

Starts four checkpoint tasks, enter:

sp_configure "number of checkpoint tasks", 4

Example 7

Captures Query Processing metrics (qp metrics) at the server level:

sp_configure "enable metrics capture", 1 

Example 8

Performs validation checking on the values in the file srv.config and reads the parameters that pass validation into the server. Current run values are substituted for values that do not pass validation checking:

sp_configure "configuration file", 0, "read",
    "srv.config"

Example 9

Runs validation checking on the values in the file restore.config:

sp_configure "configuration file", 0, "restore", 
    "generic.config"

Example 10

Creates the file my_server.config and writes the current configuration values the server is using to that file:

sp_configure "configuration file", 0, "write", 
    "my_server.config"

Example 11

Performs a validation check on the values in $SYBASE/backup_config.cfg:

sp_configure "configuration file", 0, "verify", 
    "$SYBASE/backup_config.cfg"

Usage


Setting configuration parameters for clusters


max concurrently recovered db

This parameter determines the degree of parallelism during database recovery:


number of checkpoint tasks

This parameter configures parallel checkpoints:

Permissions

Any user can execute sp_configure to display information about parameters and their current values.

Only System Administrators can execute sp_configure to modify values for:

Only System Administrators and System Security Officers can execute sp_configure to modify configuration parameters.

Only System Security Officers can execute sp_configure to modify values for:

allow procedure grouping

allow select on syscomments.text

allow updates

auditing

current audit table

enable encrypted columns

remote access

restricted decrypt permission

suspend auditing when full

systemwide password expiration

System Administrators can modify all other parameters.

Auditing

Values in event and extrainfo columns from the sysaudits table are:

Event

Audit option

Command or access audited

Information in extrainfo

38

exec_procedure

Execution of a procedure

  • Roles – Current active roles

  • Keywords or options – NULL

  • Previous value – NULL

  • Current value – NULL

  • Other information – All input parameters

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

73

Automatically audited event nto controlled by an option.

Turning the auditing parameter on with sp_configure

  • 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 in effect

74

Automatically audited event nto controlled by an option.

Turning the auditing parameter off with sp_configure

  • 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 in effect

82

security

sp_configure

  • Roles – Current active roles

  • Keywords or options – Name of the configuration parameter

  • Previous value – Old parameter value if command is setting a new value

  • Current value – New parameter value if command is setting a new value

  • Other information – Number of configuration parameter, if a parameter is being set; name of configuration file, if a configuration file is being used to set parameters

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

See also

For more information on max concurrently recovered db and number of checkpoint tasks, see Chapter 27, “Backing up and Restoring User Databases,” in the System Administration Guide.

Commands set

System procedures sp_dboption, sp_displaylevel, sp_helpconfig, sp_monitorconfig, set