SET (session variable)

The SET statement can modify one of the session configuration variables. These can also be queried via SHOW.

Warning:
In some cases, client drivers can drop and restart the connection to the server. When this happens, any session configurations made with SET statements are lost. It is therefore more reliable to configure the session in the client's connection string. For examples in different languages, see the Build an App with CockroachDB tutorials.

Required privileges

No privileges are required to modify the session settings.

Synopsis

SETSESSIONvar_nameTO=var_value,

Note:
The SET statement for session settings is unrelated to the other SET TRANSACTION and SET CLUSTER SETTING statements.

Parameters

The SET <session variable> statement accepts two parameters: thevariable name and the value to use to modify the variable.

The variable name is case insensitive. The value can be a list of one or more items. For example, the variable search_path is multi-valued.

Supported variables

Variable nameDescriptionInitial valueModify with SET ?View with SHOW ?
application_name The current application name for statistics collection.Empty string, or cockroach for sessions from the built-in SQL client.YesYes
bytea_output The mode for conversions from STRING to BYTES.hexYesYes
database The current database.Database in connection string, or empty if not specified.YesYes
default_int_size The size, in bytes, of an INT type. 8 YesYes
default_transaction_isolation All transactions execute with SERIALIZABLE isolation. See Transactions: Isolation levels. SERIALIZABLE NoYes
default_transaction_read_only The default transaction access mode for the current session. If set to on, only read operations are allowed in transactions in the current session; if set to off, both read and write operations are allowed. See SET TRANSACTION for more details. off YesYes
distsql The query distribution mode for the session. By default, CockroachDB determines which queries are faster to execute if distributed across multiple nodes, and all other queries are run through the gateway node. auto YesYes
extra_float_digits The number of digits displayed for floating-point values. Only values between -15 and 3 are supported. 0 YesYes
experimental_reorder_joins_limit Maximum number of joins that the optimizer will attempt to reorder when searching for an optimal query execution plan. For more information, see Join reordering. 4 YesYes
force_savepoint_restartWhen set to true, allows the SAVEPOINT statement to accept any name for a savepoint. off YesYes
node_id The ID of the node currently connected to.This variable is particularly useful for verifying load balanced connections.Node-dependentNoYes
optimizer The mode in which a query execution plan is generated. If set to on, the cost-based optimizer is enabled by default and the heuristic planner will only be used if the query is not supported by the cost-based optimizer; if set to off, all queries are run through the legacy heuristic planner. on YesYes
results_buffer_size The default size of the buffer that accumulates results for a statement or a batch of statements before they are sent to the client. This can also be set for all connections using the 'sql.defaults.results_buffer_size' cluster setting. Note that auto-retries generally only happen while no results have been delivered to the client, so reducing this size can increase the number of retriable errors a client receives. On the other hand, increasing the buffer size can increase the delay until the client receives the first result row. Setting to 0 disables any buffering. 16384 YesYes
search_path A list of schemas that will be searched to resolve unqualified table or function names. For more details, see SQL name resolution. public YesYes
server_version The version of PostgreSQL that CockroachDB emulates.Version-dependentNoYes
server_version_num The version of PostgreSQL that CockroachDB emulates.Version-dependentYesYes
session_user The user connected for the current session.User in connection stringNoYes
sql_safe_updates If false, potentially unsafe SQL statements are allowed, including DROP of a non-empty database and all dependent objects, DELETE without a WHERE clause, UPDATE without a WHERE clause, and ALTER TABLE .. DROP COLUMN. See Allow Potentially Unsafe SQL Statements for more details. true for interactive sessions from the built-in SQL client,false for sessions from other clientsYesYes
statement_timeout The amount of time a statement can run before being stopped.This value can be an int (e.g., 10) and will be interpreted as milliseconds. It can also be an interval or string argument, where the string can be parsed as a valid interval (e.g., '4s'). A value of 0 turns it off. 0s YesYes
timezone The default time zone for the current session. This session variable was named "time zone" (with a space) in CockroachDB 1.x. It has been renamed for compatibility with PostgreSQL. UTC YesYes
tracing The trace recording state. off Yes
transaction_isolation All transactions execute with SERIALIZABLE isolation. See Transactions: Isolation levels. This session variable was called transaction isolation level (with spaces) in CockroachDB 1.x. It has been renamed for compatibility with PostgreSQL. SERIALIZABLE NoYes
transaction_priority The priority of the current transaction. See Transactions: Isolation levels for more details.This session variable was called transaction priority (with a space) in CockroachDB 1.x. It has been renamed for compatibility with PostgreSQL. NORMAL YesYes
transaction_read_only The access mode of the current transaction. See Set Transaction for more details. off YesYes
transaction_status The state of the current transaction. See Transactions for more details.This session variable was called transaction status (with a space) in CockroachDB 1.x. It has been renamed for compatibility with PostgreSQL. NoTxn NoYes
client_encoding (Reserved; exposed only for ORM compatibility.) UTF8 NoYes
client_min_messages (Reserved; exposed only for ORM compatibility.) notice NoYes
datestyle (Reserved; exposed only for ORM compatibility.) ISO NoYes
integer_datetimes (Reserved; exposed only for ORM compatibility.) on NoYes
intervalstyle (Reserved; exposed only for ORM compatibility.) postgres NoYes
max_index_keys (Reserved; exposed only for ORM compatibility.) 32 NoYes
standard_conforming_strings (Reserved; exposed only for ORM compatibility.) on NoYes
server_encoding (Reserved; exposed only for ORM compatibility.) UTF8 YesYes

Special syntax cases:

SyntaxEquivalent toNotes
USE …SET database = …This is provided as convenience for users with a MySQL/MSSQL background.
SET NAMES …SET client_encoding = …This is provided for compatibility with PostgreSQL clients.
SET SCHEMA <name>SET search_path = <name>This is provided for better compatibility with PostgreSQL.
SET SESSION CHARACTERISTICS AS TRANSACTION ISOLATION LEVEL …SET default_transaction_isolation = …This is provided for compatibility with standard SQL.
SET TIME ZONE …SET timezone = …This is provided for compatibility with PostgreSQL clients.

Examples

Set simple variables

The following demonstrates how SET can be used to configure thedefault database for the current session:

  1. > SET database = bank;
  1. > SHOW database;
  1. +----------+
  2. | database |
  3. +----------+
  4. | bank |
  5. +----------+
  6. (1 row)

Set variables to values containing spaces

The following demonstrates how to use quoting to use values containing spaces:

  1. > SET database = "database name with spaces";
  1. > SHOW database;
  1. +---------------------------+
  2. | database |
  3. +---------------------------+
  4. | database name with spaces |
  5. +---------------------------+
  6. (1 row)

Set variables to a list of values

The following demonstrates how to assign a list of values:

  1. > SET search_path = pg_catalog,public;
  1. > SHOW search_path;
  1. +---------------------------+
  2. | search_path |
  3. +---------------------------+
  4. | pg_catalog, public |
  5. +---------------------------+
  6. (1 row)

Reset a variable to its default value

Tip:
You can use RESET to reset a session variable as well.

  1. > SHOW search_path;
  1. +-------------+
  2. | search_path |
  3. +-------------+
  4. | public |
  5. +-------------+
  6. (1 row)
  1. > SET search_path = 'app';
  1. > SHOW search_path;
  1. +-------------+
  2. | search_path |
  3. +-------------+
  4. | app |
  5. +-------------+
  6. (1 row)
  1. > SET search_path = DEFAULT;
  1. > SHOW search_path;
  1. +-------------+
  2. | search_path |
  3. +-------------+
  4. | public |
  5. +-------------+
  6. (1 row)

SET TIME ZONE

Warning:
As a best practice, we recommend not using this setting and avoid setting a session time for your database. We instead recommend converting UTC values to the appropriate time zone on the client side.

You can control your client's default time zone for the current session with SET TIME ZONE. This will apply a session offset to all TIMESTAMP WITH TIME ZONE values.

Note:
With setting SET TIME ZONE, CockroachDB uses UTC as the default time zone.

Parameters

The time zone value indicates the time zone for the current session.

This value can be a string representation of a local system-definedtime zone (e.g., 'EST', 'America/New_York') or a positive ornegative numeric offset from UTC (e.g., -7, +7). Also, DEFAULT,LOCAL, or 0 sets the session time zone to UTC.

Example: Set the default time zone via SET TIME ZONE

  1. > SET TIME ZONE 'EST'; -- same as SET "timezone" = 'EST'
  1. > SHOW TIME ZONE;
  1. +-----------+
  2. | time zone |
  3. +-----------+
  4. | EST |
  5. +-----------+
  6. (1 row)
  1. > SET TIME ZONE DEFAULT; -- same as SET "timezone" = DEFAULT
  1. > SHOW TIME ZONE;
  1. +-----------+
  2. | time zone |
  3. +-----------+
  4. | UTC |
  5. +-----------+
  6. (1 row)

SET TRACING

SET TRACING changes the trace recording state of the current session. A trace recording can be inspected with the SHOW TRACE FOR SESSION statement.

ValueDescription
offTrace recording is disabled.
clusterTrace recording is enabled; distributed traces are collected.
onSame as cluster.
kvSame as cluster except that "kv messages" are collected instead of regular trace messages. See SHOW TRACE FOR SESSION.
localTrace recording is enabled; only trace messages issued by the local node are collected.
resultsResult rows and row counts are copied to the session trace. This must be specified to in order for the output of a query to be printed in the session trace.Example: SET tracing = kv, results;

See also

Was this page helpful?
YesNo