The SHOW statement can display the value of either one or all of
the session setting variables. Some of these can also be configured via SET.
Required privileges
No privileges are required to display the session settings.
Synopsis
SHOW statement for session settings is unrelated to the other SHOW statements: SHOW CLUSTER SETTING, SHOW CREATE, SHOW USERS, SHOW DATABASES, SHOW COLUMNS, SHOW GRANTS, and SHOW CONSTRAINTS.Parameters
The SHOW <session variable> statement accepts a single parameter: the variable name.
The variable name is case insensitive. It may be enclosed in double quotes; this is useful if the variable name itself contains spaces.
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 cockroachfor sessions from the built-in SQL client. | Yes | Yes | 
| bytea_output | The mode for conversions from STRINGtoBYTES. | 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, anderror. | 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 | 
| default_int_size | The size, in bytes, of an INTtype. | 8 | Yes | Yes | 
| default_transaction_isolation | All transactions execute with SERIALIZABLEisolation. See Transactions: Isolation levels. | SERIALIZABLE | No | Yes | 
| default_transaction_priority | The default transaction priority for the current session. The supported options include LOW,NORMAL, andHIGH. | 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 tooff, both read and write operations are allowed. SeeSET TRANSACTIONfor more details. | off | Yes | Yes | 
| default_transaction_use_follower_reads | New in v21.1:
 If set to on, all read-only transactions useAS 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 anAS OF SYSTEM TIMEclause 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 VALUEclauses are enabled forALTER TYPEstatements. | off | Yes | Yes | 
| enable_implicit_select_for_update | Indicates whether UPDATEandUPSERTstatements acquire locks using theFOR UPDATElocking mode during their initial row scan, which improves performance for contended workloads.For more information about how FOR UPDATElocking works, see the documentation forSELECT 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 -15and3are supported. | 0 | Yes | Yes | 
| force_savepoint_restart | When set to true, allows theSAVEPOINTstatement 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_timeoutcluster 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_timeoutcluster setting (0s, by default). | Yes | Yes | 
| large_full_scan_rows | Determines which tables are considered "large" such that disallow_full_table_scansrejects full table or index scans of "large" tables. The default value is1000. To reject all full table or index scans, set to0. | User-dependent | No | 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_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 preferslookup joinstomerge joinswhen performingforeign keychecks. | 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. | 4 | 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_sizecluster 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 SERIALin table definitions. Valid options include'rowid','virtual_sequence',sql_sequence, andsql_sequence_cached.If set to 'virtual_sequence', theSERIALtype auto-creates a sequence for better compatibility with Hibernate sequences.If set to sql_sequence_cached, thesql.defaults.serial_sequences_cache_sizecluster 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, includingDROPof a non-empty database and all dependent objects,DELETEwithout aWHEREclause,UPDATEwithout aWHEREclause, andALTER TABLE .. DROP COLUMN.See Allow Potentially Unsafe SQL Statements for more details. | truefor interactive sessions from the built-in SQL client,falsefor 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 0turns it off. | The value set by the sql.defaults.statement_timeoutcluster setting (0s, by default). | Yes | Yes | 
| stub_catalog_tables | New in v21.1:
 If off, querying an unimplemented, emptypg_catalogtable will result in an error, as is the case in v20.2 and earlier.If on, querying an unimplemented, emptypg_catalogtable 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 SERIALIZABLEisolation.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_PERFfor 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(orSQL_INTERNAL_PERFfor 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_PERFfor 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(orSQL_INTERNAL_PERFfor 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 onandoff.For more details, see Configuring vectorized execution for CockroachDB. | on | 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 | 
| datestyle | (Reserved; exposed only for ORM compatibility.) | ISO | 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 | 
| 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 | 
| synchronous_commit | (Reserved; exposed only for ORM compatibility.) | on | 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
...