The SET
statement can modify one of the session configuration variables. These can also be queried via SHOW
. By default, session variable values are set for the duration of the current session.
CockroachDB supports setting session variables for the duration of a single transaction, using the LOCAL
keyword.
The SET
statement for session variables is unrelated to the other SET TRANSACTION
and SET CLUSTER SETTING
statements.
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
To set the role
session variable, the current user must be a member of the admin
role, or a member of the target role.
All other session variables do not require privileges to modify.
Synopsis
The SET
statement can set a session variable for the duration of the current session (SET {variable}
/SET SESSION {variable}
), or for the duration of a single transaction (SET LOCAL {variable}
).
SET SESSION
By default, session variables are set for the duration of the current session. As a result, SET {variable}
and SET SESSION {variable}
are equivalent.
SET LOCAL
SET LOCAL
is compatible with savepoints. Executing a ROLLBACK
, ROLLBACK TO SAVEPOINT
, or RELEASE TO SAVEPOINT
statement rolls back any variables set by SET LOCAL
.
Parameters
Parameter | Description |
---|---|
var_name |
The name of the session variable to set. The variable name is case-insensitive. |
var_value |
The value, or list of values, to assign to the session variable. |
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 |
client_min_messages |
The severity level of notices displayed in the SQL shell. Accepted values include debug5 , debug4 , debug3 , debug2 , debug1 , log , notice , warning , and error . |
notice |
Yes | Yes |
copy_from_atomic_enabled |
New in v22.2: If set to on , COPY FROM statements are committed atomically, matching PostgreSQL behavior. If set to off , COPY FROM statements are segmented into batches of 100 rows unless issued within an explicit transaction, matching the CockroachDB behavior in versions prior to v22.2. |
on |
Yes | Yes |
cost_scans_with_default_col_size |
Whether to prevent the optimizer from considering column size when costing plans. | false |
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 |
datestyle |
The input string format for DATE and TIMESTAMP values. Accepted values include ISO,MDY , ISO,DMY , and ISO,YMD . |
The value set by the sql.defaults.datestyle cluster setting (ISO,MDY , by default). |
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_priority |
The default transaction priority for the current session. The supported options are low , normal , and high . |
normal |
Yes | Yes |
default_transaction_quality_of_service |
The default transaction quality of service for the current session. The supported options are regular , critical , and background . See Set quality of service level. |
regular |
Yes | 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 |
default_transaction_use_follower_reads |
If set to on, all read-only transactions use AS OF SYSTEM TIME follower_read_timestamp() to allow the transaction to use follower reads. If set to off , read-only transactions will only use follower reads if an AS OF SYSTEM TIME clause is specified in the statement, with an interval of at least 4.8 seconds. |
off |
Yes | Yes |
disallow_full_table_scans |
If set to on , queries on "large" tables with a row count greater than large_full_scan_rows will not use full table or index scans. If no other query plan is possible, queries will return an error message. This setting does not apply to internal queries, which may plan full table or index scans without checking the session variable. |
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_auto_rehoming |
When enabled, the home regions of rows in REGIONAL BY ROW tables are automatically set to the region of the gateway node from which any UPDATE or UPSERT statements that operate on those rows originate. |
off |
Yes | Yes |
enable_experimental_alter_column_type_general |
If on , it is possible to alter column data types. |
off |
Yes | Yes |
enable_implicit_select_for_update |
Indicates whether UPDATE and UPSERT 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_implicit_transaction_for_batch_statements |
Indicates whether multiple statements in a single query (a "batch statement") will all run in the same implicit transaction, which matches the PostgreSQL wire protocol. | 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 |
enforce_home_region |
New in v22.2: If set to on , queries return an error and in some cases a suggested resolution if they cannot run entirely in their home region. This can occur if a query has no home region (for example, if it reads from different home regions in a regional by row table) or a query's home region differs from the gateway region. Note that only tables with ZONE survivability can be scanned without error when this is enabled. For more information about home regions, see Table localities.This feature is in preview. It is subject to change. |
off |
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 |
force_savepoint_restart |
When set to true , allows the SAVEPOINT statement to accept any name for a savepoint. |
off |
Yes | Yes |
foreign_key_cascades_limit |
Limits the number of cascading operations that run as part of a single query. | 10000 |
Yes | Yes |
idle_in_session_timeout |
Automatically terminates sessions that idle past the specified threshold. When set to 0 , the session will not timeout. |
The value set by the sql.defaults.idle_in_session_timeout cluster setting (0s , by default). |
Yes | Yes |
idle_in_transaction_session_timeout |
Automatically terminates sessions that are idle in a transaction past the specified threshold. When set to 0 , the session will not timeout. |
The value set by the sql.defaults.idle_in_transaction_session_timeout cluster setting (0s, by default). |
Yes | Yes |
index_recommendations_enabled |
If true , display recommendations to create indexes required to eliminate full table scans. For more details, see Default statement plans. |
true |
Yes | Yes |
inject_retry_errors_enabled |
If true , any statement executed inside of an explicit transaction (with the exception of SET statements) will return a transaction retry error. If the client retries the transaction using the special cockroach_restart SAVEPOINT name, after the 3rd retry error, the transaction will proceed as normal. Otherwise, the errors will continue until inject_retry_errors_enabled is set to false . For more details, see Testing transaction retry logic. |
false |
Yes | Yes |
intervalstyle |
The input string format for INTERVAL values. Accepted values include postgres , iso_8601 , and sql_standard . |
The value set by the sql.defaults.intervalstyle cluster setting (postgres , by default). |
Yes | Yes |
is_superuser |
If on or true , the current user is a member of the admin role. |
User-dependent | No | Yes |
large_full_scan_rows |
Determines which tables are considered "large" such that disallow_full_table_scans prevents queries from performing full table or index scans on those tables. The default value is 1000 . To prevent all full table or index scans, set to 0 . |
User-dependent | No | Yes |
locality |
The location of the node. For more information, see Locality. |
Node-dependent | No | Yes |
lock_timeout |
The amount of time a query can spend acquiring or waiting for a single row-level lock. In CockroachDB, unlike in PostgreSQL, non-locking reads wait for conflicting locks to be released. As a result, the lock_timeout configuration applies to writes, and to locking and non-locking reads in read-write and read-only transactions. If lock_timeout = 0 , queries do not timeout due to lock acquisitions. |
The value set by the sql.defaults.lock_timeout cluster setting (0 , by default) |
Yes | 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 |
null_ordered_last |
Set the default ordering of NULL s. The default order is NULL s first for ascending order and NULL s last for descending order. |
false |
Yes | Yes |
optimizer_use_forecasts |
If on , the optimizer uses forecasted statistics for query planning. |
on |
Yes | Yes |
optimizer_use_histograms |
If on , the optimizer uses collected histograms for cardinality estimation. |
on |
No | Yes |
optimizer_use_multicol_stats |
If on , the optimizer uses collected multi-column statistics for cardinality estimation. |
on |
No | Yes |
optimizer_use_not_visible_indexes |
If on , the optimizer uses not visible indexes for planning. |
off |
No | Yes |
pg_trgm.similarity_threshold |
The threshold above which a % string comparison returns true . The value must be between 0 and 1 . For more information, see Trigram Indexes. |
0.3 |
Yes | Yes |
prefer_lookup_joins_for_fks |
If on , the optimizer prefers lookup joins to merge joins when performing foreign key checks. |
off |
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. |
8 |
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 retryable 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 |
If on , CockroachDB throws an 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 |
serial_normalization |
Specifies the default handling of SERIAL in table definitions. Valid options include 'rowid' , 'virtual_sequence' , sql_sequence , sql_sequence_cached , and unordered_rowid . If set to 'virtual_sequence' , the SERIAL type auto-creates a sequence for better compatibility with Hibernate sequences. If set to sql_sequence_cached , you can use the sql.defaults.serial_sequences_cache_size cluster setting to control the number of values to cache in a user's session, with a default of 256. If set to unordered_rowid , the SERIAL type generates a globally unique 64-bit integer (a combination of the insert timestamp and the ID of the node executing the statement) that does not have unique ordering. |
'rowid' |
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. |
The value set by the sql.defaults.statement_timeout cluster setting (0s , by default). |
Yes | Yes |
stub_catalog_tables |
If off , querying an unimplemented, empty pg_catalog table will result in an error, as is the case in v20.2 and earlier. If on , querying an unimplemented, empty pg_catalog table simply returns no rows. |
on |
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_rows_read_err |
The limit for the number of rows read by a SQL transaction. If this value is exceeded the transaction will fail (or the event will be logged to SQL_INTERNAL_PERF for internal transactions). |
0 |
Yes | Yes |
transaction_rows_read_log |
The threshold for the number of rows read by a SQL transaction. If this value is exceeded, the event will be logged to SQL_PERF (or SQL_INTERNAL_PERF for internal transactions). |
0 |
Yes | Yes |
transaction_rows_written_err |
The limit for the number of rows written by a SQL transaction. If this value is exceeded the transaction will fail (or the event will be logged to SQL_INTERNAL_PERF for internal transactions). |
0 |
Yes | Yes |
transaction_rows_written_log |
The threshold for the number of rows written by a SQL transaction. If this value is exceeded, the event will be logged to SQL_PERF (or SQL_INTERNAL_PERF for internal transactions). |
0 |
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 |
troubleshooting_mode_enabled |
When enabled, avoid performing additional work on queries, such as collecting and emitting telemetry data. This session variable is particularly useful when the cluster is experiencing issues, unavailability, or failure. | off |
Yes | Yes |
use_declarative_schema_changer |
Whether to use the declarative schema changer for supported statements. See Declarative schema changer for more details. | on |
Yes | Yes |
vectorize |
The vectorized execution engine mode. Options include on and off . For more details, see Configure vectorized execution for CockroachDB. |
on |
Yes | Yes |
The following session variables are exposed only for backwards compatibility with earlier CockroachDB releases and have no impact on how CockroachDB runs:
Variable name | Initial value | Modify with SET ? |
View with SHOW ? |
---|---|---|---|
backslash_quote |
safe_encoding |
No | Yes |
client_encoding |
UTF8 |
No | Yes |
default_tablespace |
No | Yes | |
enable_drop_enum_value |
off |
Yes | Yes |
enable_seqscan |
on |
Yes | Yes |
escape_string_warning |
on |
No | Yes |
experimental_enable_hash_sharded_indexes |
off |
Yes | Yes |
integer_datetimes |
on |
No | Yes |
max_identifier_length |
128 |
No | Yes |
max_index_keys |
32 |
No | Yes |
row_security |
off |
No | Yes |
standard_conforming_strings |
on |
No | Yes |
server_encoding |
UTF8 |
Yes | Yes |
synchronize_seqscans |
on |
No | Yes |
synchronous_commit |
on |
Yes | Yes |
Special syntax cases
CockroachDB supports the following syntax cases, for compatibility with common SQL syntax patterns:
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 ROLE <role> |
SET role = <role> |
This is provided for compatibility with PostgreSQL clients. |
RESET ROLE |
SET role = 'none' /SET role = current_user() |
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 examples demonstrate how to use SET
to configure the default database for the current session:
SET application_name = movr_app;
SHOW application_name;
application_name
--------------------
movr_app
(1 row)
Set variables to values containing spaces
The following demonstrates how to use quoting to use values containing spaces:
SET application_name = "movr app";
SHOW application_name;
application_name
--------------------
movr app
(1 row)
Set variables to a list of values
The following demonstrates how to assign a list of values:
SET search_path = pg_catalog,public;
SHOW search_path;
search_path
----------------------
pg_catalog, public
(1 row)
Reset a variable to its default value
You can use RESET
to reset a session variable as well.
SHOW search_path;
search_path
----------------------
pg_catalog, public
(1 row)
SET search_path = DEFAULT;
SHOW search_path;
search_path
-------------------
"$user", public
(1 row)
Set a variable for the duration of a single transaction
To set a variable for the duration of a single transaction, use the SET LOCAL
statement.
SHOW application_name;
application_name
--------------------
movr app
(1 row)
BEGIN;
SET LOCAL application_name = demo;
SHOW application_name;
application_name
--------------------
demo
(1 row)
COMMIT;
SHOW application_name;
application_name
--------------------
movr app
(1 row)
Roll back session variables set for a transaction
You can roll back session variable settings to savepoints.
SHOW timezone;
timezone
------------
UTC
(1 row)
BEGIN;
SET timezone = '+3';
SAVEPOINT s1;
SHOW timezone;
timezone
------------
+3
(1 row)
SET LOCAL timezone = '+1';
SHOW timezone;
timezone
------------
+1
(1 row)
ROLLBACK TO SAVEPOINT s1;
SHOW timezone;
timezone
------------
+3
(1 row)
COMMIT;
SHOW timezone;
timezone
------------
+3
(1 row)
Assume another role
To assume another role for the duration of a session, use SET ROLE <role>
. SET ROLE <role>
is equivalent to SET role = <role>
.
To assume a new role, the current user must be a member of the admin
role, or a member of the target role.
SHOW role;
role
--------
root
(1 row)
CREATE ROLE new_role;
SHOW ROLES;
username | options | member_of
-----------+---------+------------
admin | | {}
new_role | NOLOGIN | {}
root | | {admin}
(3 rows)
SET ROLE new_role;
SHOW role;
role
------------
new_role
(1 row)
To reset the role of the current user, use a RESET
statement. RESET ROLE
is equivalent to SET role = 'none'
and SET role = current_user()
.
RESET ROLE;
SHOW role;
role
--------
root
(1 row)
To assume a role for the duration of a single transaction, use SET LOCAL ROLE
.
BEGIN;
SET LOCAL ROLE new_role;
SHOW role;
role
------------
new_role
(1 row)
COMMIT;
SHOW role;
role
--------
root
(1 row)
SET TIME ZONE
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
).
When setting a time zone, note the following:
Timezone abbreviations are case-insensitive.
To see a list of supported timezones, their nicknames, and their offsets, run the following query:
SELECT * FROM pg_timezone_names;
DEFAULT
,LOCAL
, or0
sets the session time zone toUTC
.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 specifyUTC
orGMT
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 instead (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 specifyingGMT+7
(i.e., 7 west of UTC).
Example: Set the default time zone via SET TIME ZONE
> SET TIME ZONE 'EST'; -- same as SET "timezone" = 'EST'
> SHOW TIME ZONE;
timezone
+----------+
EST
(1 row)
> SET TIME ZONE DEFAULT; -- same as SET "timezone" = DEFAULT
> 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 . |
results |
Result rows and row counts are copied to the session trace. This must be specified in order for the output of a query to be printed in the session trace. Example: SET tracing = kv, results; |
Known Limitations
SET
does not properly apply ROLLBACK
within a transaction. For example, in the following transaction, showing the TIME ZONE
variable does not return 2
as expected after the rollback:
SET TIME ZONE +2;
BEGIN;
SET TIME ZONE +3;
ROLLBACK;
SHOW TIME ZONE;
timezone
------------
3