On this page
Use the SHOW
statement to display the value of one or all of the session variables. You configure session variables using SET
.
Required privileges
No privileges are required to display the session variables.
Synopsis
Note:
The SHOW
statement for session variables is unrelated to the other SHOW
statements like SHOW CLUSTER SETTING
, SHOW CREATE
, and SHOW DATABASES
.
Parameters
Parameter | Description |
---|---|
var_name |
The session variable name to show. The variable name is case-insensitive and can be enclosed in double quotes. |
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 |
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
|
New in v21.2:
The input string format for DATE and TIMESTAMP values.
Accepted values include ISO,MDY , ISO,DMY , and ISO,YMD .
To set datestyle to a value other than the default (ISO,MDY ), you must first set the datestyle_enabled session variable to true . |
The value set by the sql.defaults.datestyle cluster setting (ISO,MDY , by default). |
Yes | Yes |
datestyle_enabled
|
New in v21.2:
Enables setting the datestyle session variable to a supported format. |
The value set by the sql.defaults.datestyle.enabled cluster setting (false , 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_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 , all queries that have planned a full table or full secondary index scan 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_drop_enum_value
|
Indicates whether DROP VALUE clauses are enabled for ALTER TYPE statements. |
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_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 |
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 |
intervalstyle
|
New in v21.2:
The input string format for INTERVAL values.
Accepted values include postgres , iso_8601 , and sql_standard .
To set intervalstyle to a value other than the default (postgres ), you must first set the intervalstyle_enabled session variable to true . |
The value set by the sql.defaults.intervalstyle cluster setting (postgres , by default). |
Yes | Yes |
intervalstyle_enabled
|
New in v21.2:
Enables setting the intervalstyle session variable to a supported format. |
The value set by the sql.defaults.intervalstyle.enabled cluster setting (false , by default). |
Yes | Yes |
is_superuser
|
New in v21.2:
If on or true , the current user is a member of the `admin` role. |
User-dependent | No | Yes |
large_full_scan_rows
|
New in v21.2:
Determines which tables are considered "large" such that disallow_full_table_scans rejects full table or index scans of "large" tables. The default value is 1000 . To reject 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
|
New in v21.2:
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 |
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 |
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 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
|
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 |
serial_normalization
|
Specifies the default handling of SERIAL in table definitions. Valid options include 'rowid' , 'virtual_sequence' , sql_sequence , and sql_sequence_cached .
If set to 'virtual_sequence' , the SERIAL type auto-creates a sequence for better compatibility with Hibernate sequences.
If set to sql_sequence_cached , the sql.defaults.serial_sequences_cache_size cluster setting can be used to control the number of values to cache in a user's session, with a default of 256. |
'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
|
New in v21.2:
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
|
New in v21.2:
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
|
New in v21.2:
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
|
New in v21.2:
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 |
vectorize
|
The vectorized execution engine mode.
Options include on and off .
For more details, see Configure vectorized execution for CockroachDB. |
on
|
Yes | Yes |
backslash_quote
|
(Reserved; exposed only for ORM compatibility.) |
safe_encoding
|
No | Yes |
client_encoding
|
(Reserved; exposed only for ORM compatibility.) |
UTF8
|
No | Yes |
default_tablespace
|
(Reserved; exposed only for ORM compatibility.) |
|
No | Yes |
enable_seqscan
|
(Reserved; exposed only for ORM compatibility.) |
on
|
Yes | Yes |
escape_string_warning
|
(Reserved; exposed only for ORM compatibility.) |
on
|
No | Yes |
integer_datetimes
|
(Reserved; exposed only for ORM compatibility.) |
on
|
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 |
synchronous_commit
|
(Reserved; exposed only for ORM compatibility.) |
on
|
Yes | 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 |
For session variables on experimental features, see Experimental Features.
Special syntax cases supported for compatibility:
Syntax | Equivalent to |
---|---|
SHOW TRANSACTION PRIORITY |
SHOW "transaction priority" |
SHOW TRANSACTION ISOLATION LEVEL |
SHOW "transaction isolation level" |
SHOW TIME ZONE |
SHOW "timezone" |
SHOW TRANSACTION STATUS |
SHOW "transaction status" |
Examples
Showing the value of a single session variable
> SHOW DATABASE;
database
------------
movr
(1 row)
Showing the value of all session variables
> SHOW ALL;
variable | value
----------------------+-------------------
application_name | $ cockroach demo
bytea_output | hex
client_encoding | UTF8
client_min_messages | notice
...