SET (session variable)

On this page Carat arrow pointing down
Warning:
As of November 12, 2021, CockroachDB v20.1 is no longer supported. For more details, refer to the Release Support Policy.

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

SET SESSION var_name TO = 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: the variable 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 name Description Initial value Modify 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. Yes Yes
bytea_output The mode for conversions from STRING to BYTES. hex Yes Yes
crdb_version The version of CockroachDB. `CockroachDB OSS version` No Yes
database The current database. Database in connection string, or empty if not specified. Yes Yes
default_int_size The size, in bytes, of an INT type. 8 Yes Yes
default_transaction_isolation All transactions execute with SERIALIZABLE isolation. See Transactions: Isolation levels. SERIALIZABLE No Yes
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 Yes Yes
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 Yes Yes
enable_implicit_select_for_update New in v20.1: Indicates whether UPDATE statements acquire locks using the FOR UPDATE locking mode during their initial row scan, which improves performance for contended workloads. For more information about how FOR UPDATE locking works, see the documentation for SELECT FOR UPDATE. on Yes Yes
enable_insert_fast_path Indicates whether CockroachDB will use a specialized execution operator for inserting into a table. We recommend leaving this setting on. on Yes Yes
enable_zigzag_join Indicates whether the cost-based optimizer will plan certain queries using a zig-zag merge join algorithm, which searches for the desired intersection by jumping back and forth between the indexes based on the fact that after constraining indexes, they share an ordering. on Yes Yes
extra_float_digits The number of digits displayed for floating-point values. Only values between -15 and 3 are supported. 0 Yes Yes
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 Yes Yes
force_savepoint_restart When set to true, allows the SAVEPOINT statement to accept any name for a savepoint. off Yes Yes
locality The location of the node. For more information, see Locality. Node-dependent No Yes
node_id The ID of the node currently connected to.

This variable is particularly useful for verifying load balanced connections.
Node-dependent No Yes
optimizer_foreign_keys New in v20.1: If off, disables optimizer-driven foreign key checks. on Yes Yes
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 Yes Yes
require_explicit_primary_keys New in v20.1: If on, CockroachDB throws on error for all tables created without an explicit primary key defined. off Yes Yes
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 Yes Yes
server_version The version of PostgreSQL that CockroachDB emulates. Version-dependent No Yes
server_version_num The version of PostgreSQL that CockroachDB emulates. Version-dependent Yes Yes
session_id The ID of the current session. Session-dependent No Yes
session_user The user connected for the current session. User in connection string No Yes
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 clients
Yes Yes
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 Yes Yes
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 Yes Yes
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 No Yes
transaction_priority The priority of the current transaction. See Transactions: Transaction priorities 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 Yes Yes
transaction_read_only The access mode of the current transaction. See Set Transaction for more details. off Yes Yes
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 No Yes
vectorize The vectorized execution engine mode. Options include auto, on, and off. For more details, see Configuring vectorized execution for CockroachDB. auto Yes Yes
vectorize_row_count_threshold The minimum number of rows required to use the vectorized engine to execute a query plan. 1000 Yes Yes
client_encoding (Reserved; exposed only for ORM compatibility.) UTF8 No Yes
client_min_messages (Reserved; exposed only for ORM compatibility.) notice No Yes
datestyle (Reserved; exposed only for ORM compatibility.) ISO No Yes
default_tablespace (Reserved; exposed only for ORM compatibility.) No Yes
idle_in_transaction_session_timeout (Reserved; exposed only for ORM compatibility.) 0 No Yes
integer_datetimes (Reserved; exposed only for ORM compatibility.) on No Yes
intervalstyle (Reserved; exposed only for ORM compatibility.) postgres No Yes
lock_timeout (Reserved; exposed only for ORM compatibility.) 0 No Yes
max_identifier_length (Reserved; exposed only for ORM compatibility.) 128 No Yes
max_index_keys (Reserved; exposed only for ORM compatibility.) 32 No Yes
row_security (Reserved; exposed only for ORM compatibility.) off No Yes
standard_conforming_strings (Reserved; exposed only for ORM compatibility.) on No Yes
server_encoding (Reserved; exposed only for ORM compatibility.) UTF8 Yes Yes
synchronize_seqscans (Reserved; exposed only for ORM compatibility.) on No Yes

Special syntax cases:

Syntax Equivalent to Notes
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 the default database for the current session:

icon/buttons/copy
> SET database = movr;
icon/buttons/copy
> SHOW database;
  database
+----------+
  movr
(1 row)

Set variables to values containing spaces

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

icon/buttons/copy
> SET database = "database name with spaces";
icon/buttons/copy
> SHOW database;
  database
+----------+
  database name with spaces
(1 row)

Set variables to a list of values

The following demonstrates how to assign a list of values:

icon/buttons/copy
> SET search_path = pg_catalog,public;
icon/buttons/copy
> SHOW search_path;
     search_path
+--------------------+
  pg_catalog, public
(1 row)

Reset a variable to its default value

Tip:
You can use RESET to reset a session variable as well.
icon/buttons/copy
> SHOW search_path;
  search_path
+-------------+
  public
(1 row)
icon/buttons/copy
> SET search_path = 'app';
icon/buttons/copy
> SHOW search_path;
  search_path
+-------------+
  app
(1 row)
icon/buttons/copy
> SET search_path = DEFAULT;
icon/buttons/copy
> SHOW search_path;
  search_path
+-------------+
  public
(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 the default time zone for a session with SET TIME ZONE. This will apply an offset to all TIMESTAMPTZ/TIMESTAMP WITH TIME ZONE and TIMETZ/TIME WITH TIME ZONE values in the session. By default, CockroachDB uses UTC as the time zone for SET TIME ZONE offsets.

Parameters

The input passed to SET TIME ZONE indicates the time zone for the current session. This value can be a string representation of a local system-defined time zone (e.g., 'EST', 'America/New_York') or a positive or negative numeric offset from UTC (e.g., -7, +7, or UTC-7, UTC+7) or GMT (e.g., GMT-7, GMT+7). The numeric offset input can also be colon-delimited (e.g., -7:00, GMT+7:00).

Note:

Only offsets specified by integers (e.g., -7, 7) use the ISO 8601 time offset (i.e., the offset input is parsed as hours east of UTC). If you explicitly specify UTC or GMT for the time zone offset (e.g., UTC-7,GMT+7), or if the numeric input is colon-delimited (e.g., -7:00, GMT+7:00), CockroachDB uses the POSIX time offset (i.e., hours west of the specified time zone). This means that specifying an offset of -7 (i.e., -7 east of UTC) is equivalent to specifying GMT+7 (i.e., 7 west of UTC).

All timezone abbreviations are case-sensitive and must be uppercase, with the exception of UTC, for which utc is an alias.

DEFAULT, LOCAL, or 0 sets the session time zone to UTC.

Example: Set the default time zone via SET TIME ZONE

icon/buttons/copy
> SET TIME ZONE 'EST'; -- same as SET "timezone" = 'EST'
icon/buttons/copy
> SHOW TIME ZONE;
  timezone
+----------+
  EST
(1 row)
icon/buttons/copy
> SET TIME ZONE DEFAULT; -- same as SET "timezone" = DEFAULT
icon/buttons/copy
> SHOW TIME ZONE;
  timezone
+----------+
  UTC
(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.

Value Description
off Trace recording is disabled.
cluster Trace recording is enabled; distributed traces are collected.
on Same as cluster.
kv Same as cluster except that "kv messages" are collected instead of regular trace messages. See SHOW TRACE FOR SESSION.
local Trace recording is enabled; only trace messages issued by the local node are collected.
results Result 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


Yes No
On this page

Yes No